SQL Zone is brought to you in partnership with:

I was born in Bulgaria. My immediate family and I relocated to Syracuse, NY in 1995. I completed high school in Syracuse, and then continued my education at Alfred University. My major at Alfred University was Computer Science. I also obtained a minor in Management Information Systems (MIS) to bridge the gap between technology and the business world. One of my future goals is to extend that bridge by obtaining a Master's degree in Business Administration. Boyan is a DZone MVB and is not an employee of DZone and has posted 27 posts at DZone. You can read more from them at their website. View Full User Profile

Querying Active Directory Through SQL Server

02.11.2008
| 79342 views |
  • submit to reddit
Integrating 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:
  1. Open SQL Server Enterprise Manager
  2. Go to the database server to which you will be adding the linked server
  3. Expend "Security"
  4. Right-click on "Linked Servers" and click on "New Linked Server..."
  5. Fill in the following:
    1. Under the General tab:
      1. Linked Server: adsi (or whatever you want to call it)
      2. Server type: select Other Data Source
      3. Provider name:select OLE DB Provider for Microsoft Directory Services
      4. Under Provider Options: check that Allow InProcess is checked
      5. Leave the rest of the fields blank
    2. Under the Security tab:
      1. Local Login: sqlServerUser
      2. Remote User: ntaccount@domain.com (such as bkostadinov@ica.com or ica.com\bkostadinov)
      3. Remote Password: userPassword for the above domain account
Through Query Analyzer:
  1. Change the "AllowInProcess" registry key under HKEY_LOCAL_MACHINE\SOFTWARE\Microsoft\MSSQLServer\Providers\ADSDSOObject to "dword:00000001"
    1. 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
      						
  2. Open Query Analyzer (or your choice of query tool)
  3. Connect to the server to which you will be adding the linked server
  4. 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.

References
Published at DZone with permission of Boyan Kostadinov, author and DZone MVB. (source)

(Note: Opinions expressed in this article and its replies are the opinions of their respective authors and not those of DZone, Inc.)

Comments

John Lee replied on Wed, 2014/07/02 - 10:23am

 Kinda tricky when integrating it but this one resolves the complicating part. Im running a IBM-Power  730-8231 ( http://www.spectra.com/ibm/ibm-product/16/252/Used-IBM-Power-730-8231-E2B7.htm  ) I can say processing is indeed superb.

Comment viewing options

Select your preferred way to display the comments and click "Save settings" to activate your changes.