Querying Active Directory Through SQL Server
Set up and use LDAP queries through SQL Server 2000 with Active Directory as the LDAP controller.
Join the DZone community and get the full member experience.
Join For FreeIntegrating your application with Active Directory (or another LDAP based directory) is a common requirement in many business applications. Almost every language has a way to query LDAP but little known is the approach of integrating SQL Server with your LDAP controller. This quick article will guide you through setting up and using LDAP queries through SQL Server 2000 with Active Directory as the LDAP controller.
First, you need to create a SQL Server linked server. Set it up through SQL Server Enterprise Manager:
- Open SQL Server Enterprise Manager
- Go to the database server to which you will be adding the linked server
- Expend "Security"
- Right-click on "Linked Servers" and click on "New Linked Server..."
- Fill in the following:
- Under the General tab:
- Linked Server: adsi (or whatever you want to call it)
- Server type: select Other Data Source
- Provider name:select OLE DB Provider for Microsoft Directory Services
- Under Provider Options: check that Allow InProcess is checked
- Leave the rest of the fields blank
- Under the Security tab:
- Local Login: sqlServerUser
- Remote User: ntaccount@domain.com (such as bkostadinov@ica.com or ica.com\bkostadinov)
- Remote Password: userPassword for the above domain account
- Under the General tab:
Through Query Analyzer:
- Change the "AllowInProcess" registry key under HKEY_LOCAL_MACHINE\SOFTWARE\Microsoft\MSSQLServer\Providers\ADSDSOObject to "dword:00000001"
- Edit the registry manually or put the following in a .reg file and execute it:
Windows Registry Editor Version 5.00 [HKEY_LOCAL_MACHINE\SOFTWARE\Microsoft\MSSQLServer\Providers\ADSDSOObject] "AllowInProcess"=dword:00000001
- Edit the registry manually or put the following in a .reg file and execute it:
- Open Query Analyzer (or your choice of query tool)
- Connect to the server to which you will be adding the linked server
- Change the provided values and execute the following code:
-- Change 'adsi' to the desired name of the linked server
exec sp_addlinkedserver
'adsi',
'',
'ADSDSOObject',
''
go
-- Change 'adsi' to the desired name of the linked server
-- Change 'sqlUser' to the username of local sql server user
-- Change 'domainName\userName' to a domain account
-- (the format can be 'domainName\userName' or 'userName@domainName')
-- Change 'domainUserPassword' to the password of the domain account
exec sp_addlinkedsrvlogin
'adsi',
false,
'sqlServerUser',
'domainName\userName',
'domainUserPassword'
go
Or you can just fill in the values on top of the following script and run that:
declare @linkedServerSql nvarchar(4000),
@linkedServerName varchar(100),
@localSqlUsername varchar(100),
@domainUsername varchar(100),
@domainUserPassword varchar(100)
-- Set the local sql server user
set @localSqlUsername = 'sqlUser'
-- format can be 'domainName\userName' or 'userName@domainName'
set @domainUsername = 'domainName\userName'
set @domainUserPassword = 'domainUserPassword'
set @linkedServerName = 'adsi'
set @linkedServerSql = '
exec sp_addlinkedserver
''' + @linkedServerName + ''',
'''',
''ADSDSOObject'',
''''
exec sp_addlinkedsrvlogin
''' + @linkedServerName + ''',
false,
''' + @localSqlUsername + ''',
''' + @domainUsername + ''',
''' + @domainUserPassword + ''''
exec sp_executesql @linkedServerSql
Run a query to verify that the linked server works. The query below will give you all the users in the dc=ica,dc=com (change that to match your own domain):
select *
from openquery(adsi, '
select givenName,
sn,
sAMAccountName,
displayName,
mail,
telephoneNumber,
mobile,
physicalDeliveryOfficeName,
department,
division
from ''LDAP://dc=ica,dc=com''
where objectCategory = ''Person''
and
objectClass = ''user''
')
Below, is an alternate syntax which you can use to apply ldap filters with almost universal syntax. The following will get all the users in LDAP but limit the result set to those users who's "given" & "sn" names are not empty. It will also apply a filter to the "division" attribute and exclude any records that match "system" and "generic".
declare @ldapFilter nvarchar(1000), @ldapSQL nvarchar(4000)
-- Set the filter to exlude objects that have a division of "System" and "Generic"
set @ldapFilter = '(!division=System*)(!division=Generic)'
-- Create an ldap query to get all users under dc=ica,dc=com
set @ldapSQL = '
select givenName as firstName,
sn as lastName,
displayName,
lower(sAMAccountName) as accountName,
telephoneNumber as phoneNumber,
mobile as cellPhoneNumber,
mail as emailAddress,
department,
physicalDeliveryOfficeName as siteName
from openquery(adsi, ''<LDAP://dc=ica,dc=com>
(&(objectCategory=Person)(objectClass=user)'+ @ldapFilter + ');
givenName,
sn,
sAMAccountName,
displayName,
mail,
telephoneNumber,
mobile,
physicalDeliveryOfficeName,
department,
division;
subtree'')
where givenName is not null
and
sn is not null'
exec sp_executesql @ldapSQL
Some things to note:
"LDAP" is case sensitive, if you try using "ldap", the query will throw an error.
Querying the Active Directory server will work fine from Query Analyzer even if you do not run sp_addlinkedserverlogin. However, if you try to execute the query from the web (with something like ColdFusion, you will get an error similar to:
[Macromedia][SQLServer JDBC Driver][SQLServer]OLE DB provider 'ADSDSOObject' reported an error. The provider indicates that the user did not have the permission to perform the operation.
Published at DZone with permission of Boyan Kostadinov, DZone MVB. See the original article here.
Opinions expressed by DZone contributors are their own.
Comments