DZone
Thanks for visiting DZone today,
Edit Profile
  • Manage Email Subscriptions
  • How to Post to DZone
  • Article Submission Guidelines
Sign Out View Profile
  • Post an Article
  • Manage My Drafts
Over 2 million developers have joined DZone.
Log In / Join
Refcards Trend Reports
Events Video Library
Over 2 million developers have joined DZone. Join Today! Thanks for visiting DZone today,
Edit Profile Manage Email Subscriptions Moderation Admin Console How to Post to DZone Article Submission Guidelines
View Profile
Sign Out
Refcards
Trend Reports
Events
View Events Video Library
Zones
Culture and Methodologies Agile Career Development Methodologies Team Management
Data Engineering AI/ML Big Data Data Databases IoT
Software Design and Architecture Cloud Architecture Containers Integration Microservices Performance Security
Coding Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
Culture and Methodologies
Agile Career Development Methodologies Team Management
Data Engineering
AI/ML Big Data Data Databases IoT
Software Design and Architecture
Cloud Architecture Containers Integration Microservices Performance Security
Coding
Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance
Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks

Integrating PostgreSQL Databases with ANF: Join this workshop to learn how to create a PostgreSQL server using Instaclustr’s managed service

Mobile Database Essentials: Assess data needs, storage requirements, and more when leveraging databases for cloud and edge applications.

Monitoring and Observability for LLMs: Datadog and Google Cloud discuss how to achieve optimal AI model performance.

Automated Testing: The latest on architecture, TDD, and the benefits of AI and low-code tools.

Related

  • CICD Doesn’t Have To Be a Four Letter Word for Oracle Database Developers
  • NULL in Oracle
  • SQL Query Performance Tuning in MySQL
  • SQL Server to Postgres Database Migration

Trending

  • The Ultimate Guide to API vs. SDK: What’s the Difference and How To Use Them
  • Continuous Integration vs. Continuous Deployment
  • Development of Custom Web Applications Within SAP Business Technology Platform
  • Beyond the Prompt: Unmasking Prompt Injections in Large Language Models
  1. DZone
  2. Data Engineering
  3. Databases
  4. Querying Active Directory Through SQL Server

Querying Active Directory Through SQL Server

Set up and use LDAP queries through SQL Server 2000 with Active Directory as the LDAP controller.

Boyan Kostadinov user avatar by
Boyan Kostadinov
·
Feb. 11, 08 · Tutorial
Like (1)
Save
Tweet
Share
139.46K Views

Join the DZone community and get the full member experience.

Join For Free

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.

Directory sql Database

Published at DZone with permission of Boyan Kostadinov, DZone MVB. See the original article here.

Opinions expressed by DZone contributors are their own.

Related

  • CICD Doesn’t Have To Be a Four Letter Word for Oracle Database Developers
  • NULL in Oracle
  • SQL Query Performance Tuning in MySQL
  • SQL Server to Postgres Database Migration

Comments

Partner Resources

X

ABOUT US

  • About DZone
  • Send feedback
  • Careers
  • Sitemap

ADVERTISE

  • Advertise with DZone

CONTRIBUTE ON DZONE

  • Article Submission Guidelines
  • Become a Contributor
  • Visit the Writers' Zone

LEGAL

  • Terms of Service
  • Privacy Policy

CONTACT US

  • 3343 Perimeter Hill Drive
  • Suite 100
  • Nashville, TN 37211
  • support@dzone.com

Let's be friends: