How to avoid 1000 rows limitation when querying active directory (AD) from SQL 2005 with using custom code.

As all of you know it is possible to query active directory from SQL Server with using ADSI provider as linked server. This solution works fine until you will have a lot of users in active directory. According to best practice guide windows system engineers always configured AD to return no more then 1000 rows per one query. Of course you can avoid this limitation too (with using range keyword or some other ways, as for me require deep AD knowledge). Some other extremily complicated T-SQL scripts can be found in internet. My current post's goal is to show two main things:

1. how to register a couple of assemblies (your own and related system assemblies) in SQL Server with UNSAFE permission WITHOUT setting TRUSTWORTHY ON for your database according to best practice security guide. Security check will passed in this way according to certificate permissions.

2. how to create a simple CLR procedures for quirying AD as any other SQL datasource without creating linked server.

You can find MSADHelper2.rar project attached. It contains project files; you can extract MSADHelper.dll assembly from here, or build a new one by yourself (in that case please generate a new strong key, my is not included in project files).

P.S. I am not an expert in C#, so you can improve this source as you wish to add some dispose or other required methods.

Here is installation script:

SET NOCOUNT ON
GO
USE Master
GO

--sp_configure 'clr enabled', 1
--reconfigure with override

--ALTER DATABASE <your_database_name> SET TRUSTWORTHY OFF
--GO

-- create keys from assembly 

CREATE ASYMMETRIC KEY MSADHelperAsKey FROM EXECUTABLE FILE = 'C:\distrib\ADSI\MSADHelper2.dll' -- specify correct path here.
GO
CREATE ASYMMETRIC KEY SystemDirectoryServicesKey FROM EXECUTABLE FILE = 'C:\WINDOWS\Microsoft.NET\Framework\v2.0.50727\System.DirectoryServices.dll'
GO
--SELECT * FROM sys.asymmetric_keys
--GO

-- create logins for special goals
CREATE LOGIN SQLCLRHelperLogin FROM ASYMMETRIC KEY MSADHelperAsKey
GO
CREATE LOGIN SQLCLRSysDirServLogin FROM ASYMMETRIC KEY SystemDirectoryServicesKey
GO

-- grant necessary (UNSAFE) permissions
GRANT UNSAFE ASSEMBLY TO SQLCLRHelperLogin
GO
GRANT UNSAFE ASSEMBLY TO SQLCLRSysDirServLogin
GO

-----------------------------------------------------------------------
---
--- **************************************************************
---
-----------------------------------------------------------------------

USE <your_database_name>
GO

CREATE ASSEMBLY [System.DirectoryServices]
FROM 'C:\WINDOWS\Microsoft.NET\Framework\v2.0.50727\System.DirectoryServices.dll'
WITH PERMISSION_SET = UNSAFE
GO
CREATE ASSEMBLY [MsForClient.SqlServer.SqlClrToolkit.MSADHelper]
FROM 'C:\distrib\ADSI\MSADHelper2.dll' -- please specify correct path here
WITH PERMISSION_SET = UNSAFE
GO

--Have a look at the assembly within the database
--SELECT * FROM sys.assemblies
--SELECT * FROM sys.assembly_files
GO

--Create procedures from the assembly

-- return list of registered providers (from registry)
CREATE PROCEDURE dbo.usp_GetListOfRegisteredDirectoryProviders
AS EXTERNAL NAME [MsForClient.SqlServer.SqlClrToolkit.MSADHelper].[MsForClient.SqlServer.SqlClrToolkit.MSADHelper].usp_GetListOfRegisteredDirectoryProviders
GO

-- test methods - is it possible to create AD object? 

CREATE PROCEDURE dbo.usp_TryAuthenticate(@pAdsiPath nvarchar(4000), @pSecure int)
AS EXTERNAL NAME [MsForClient.SqlServer.SqlClrToolkit.MSADHelper].[MsForClient.SqlServer.SqlClrToolkit.MSADHelper].usp_TryAuthenticate
GO

-- by default any method will execute under SQL Server Service account. If this account don't have enought privileges - please specify another one as @pUserName and

-- @pPassword to access AD

CREATE PROCEDURE dbo.usp_TryAuthenticateAsUser(@pAdsiPath nvarchar(4000), @pUserName sysname, @pPassword nvarchar(100), @pSecure int)
AS EXTERNAL NAME [MsForClient.SqlServer.SqlClrToolkit.MSADHelper].[MsForClient.SqlServer.SqlClrToolkit.MSADHelper].usp_TryAuthenticateAsUser
GO

-- enum AD structure - be carefull, to much info!

CREATE PROCEDURE dbo.usp_FillInfoByPath(@pAdsiPath nvarchar(4000), @pUserName sysname, @pPassword nvarchar(100), @pSecure int)
AS EXTERNAL NAME [MsForClient.SqlServer.SqlClrToolkit.MSADHelper].[MsForClient.SqlServer.SqlClrToolkit.MSADHelper].usp_FillInfoByPath
GO

-- get AD object properties

CREATE PROCEDURE dbo.usp_GetNodeProperties(@pAdsiPath nvarchar(4000), @pUserName sysname, @pPassword nvarchar(100), @pSecure int)
AS EXTERNAL NAME [MsForClient.SqlServer.SqlClrToolkit.MSADHelper].[MsForClient.SqlServer.SqlClrToolkit.MSADHelper].usp_GetNodeProperties
GO

-- extract user list

CREATE PROCEDURE dbo.usp_GetUserList(@pAdsiPath nvarchar(4000), @pOutputFieldList NVarChar(2000), @pUserName sysname, @pPassword nvarchar(100), @pSecure int, @pScope nvarchar(10))
AS EXTERNAL NAME [MsForClient.SqlServer.SqlClrToolkit.MSADHelper].[MsForClient.SqlServer.SqlClrToolkit.MSADHelper].usp_GetUserList
GO

-- extract group list

CREATE PROCEDURE dbo.usp_GetGroupList(@pAdsiPath nvarchar(4000), @pOutputFieldList NVarChar(2000), @pUserName sysname, @pPassword nvarchar(100), @pSecure int, @pScope nvarchar(10))
AS EXTERNAL NAME [MsForClient.SqlServer.SqlClrToolkit.MSADHelper].[MsForClient.SqlServer.SqlClrToolkit.MSADHelper].usp_GetGroupList
GO

-- extract list of computers

CREATE PROCEDURE dbo.usp_GetComputerList(@pAdsiPath nvarchar(4000), @pOutputFieldList NVarChar(2000), @pUserName sysname, @pPassword nvarchar(100), @pSecure int, @pScope nvarchar(10))
AS EXTERNAL NAME [MsForClient.SqlServer.SqlClrToolkit.MSADHelper].[MsForClient.SqlServer.SqlClrToolkit.MSADHelper].usp_GetComputerList
GO

-- extract members of AD group

CREATE PROCEDURE dbo.usp_GetGroupMembers(@pAdsiPath nvarchar(4000), @pOutputFieldList NVarChar(2000), @pUserName sysname, @pPassword nvarchar(100), @pSecure int)
AS EXTERNAL NAME [MsForClient.SqlServer.SqlClrToolkit.MSADHelper].[MsForClient.SqlServer.SqlClrToolkit.MSADHelper].usp_GetGroupMembers
GO

-- enum user membership

CREATE PROCEDURE dbo.usp_GetUserMembership(@pAdsiPath nvarchar(4000), @pOutputFieldList NVarChar(2000), @pUserName sysname, @pPassword nvarchar(100), @pSecure int)
AS EXTERNAL NAME [MsForClient.SqlServer.SqlClrToolkit.MSADHelper].[MsForClient.SqlServer.SqlClrToolkit.MSADHelper].usp_GetUserMembership
GO

-- execute & test section

EXEC dbo.usp_GetListOfRegisteredDirectoryProviders
GO

-- try to check - if net framework carefully installed and AD objects created without any issue
DECLARE @pStr nvarchar(4000)
SET @pStr = N'LDAP://DC=HQ,DC=corp,DC=xxxxxxxx,DC=ru'
EXEC dbo.usp_TryAuthenticate @pStr, 1
GO
-- try to run under another account

DECLARE @pStr nvarchar(4000), @pUserName sysname, @pPassword nvarchar(100)
SELECT @pStr = N'LDAP://DC=HQ,DC=corp,DC=xxxxxxxx,DC=ru', @pUserName = N'SQLSvc', @pPassword = N'xxxxxxx'

EXEC dbo.usp_TryAuthenticateAsUser @pStr, @pUserName, @pPassword, 1
GO

-- extract AD info as relational tree (use ID & ParentID to build object tree)
DECLARE @pStr nvarchar(4000), @pUserName sysname, @pPassword nvarchar(100)
SET @pStr = N'LDAP://DC=HQ,DC=corp,DC=xxxxxxx,DC=ru'

EXEC dbo.usp_FillInfoByPath @pStr, @pUserName, @pPassword, 0
GO

--- get all properites of object
DECLARE @pStr nvarchar(4000), @pUserName sysname, @pPassword nvarchar(100)
--SET @pStr = N'LDAP://CN=User01,CN=Users,DC=HQ,DC=corp,DC=xxxxxxx,DC=ru'
SET @pStr = N'LDAP://CN=Domain Admins,CN=Users,DC=HQ,DC=corp,DC=xxxxxxxxxx,DC=ru'

EXEC dbo.usp_GetNodeProperties @pStr, @pUserName, @pPassword, 0
GO
---- get user list and attributes

DECLARE @pStr nvarchar(4000), @pOutputFieldList nvarchar(2000), @pUserName sysname, @pPassword nvarchar(100)
-- to extract users from exact OU
-- 'LDAP://OU=TestGroup,DC=HQ,DC=corp,DC=xxxxxxxx,DC=ru'
-- all users from AD
-- @pStr = N'LDAP://DC=HQ,DC=corp,DC=xxxxxxx,DC=ru'
SELECT @pStr = N'LDAP://DC=HQ,DC=corp,DC=xxxxxxxxx,DC=ru',
 @pOutputFieldList = 'cn,name,description,distinguishedName,whenChanged,primaryGroupID,memberOf', @pUserName = '', @pPassword = N''

EXEC dbo.usp_GetUserList @pStr, @pOutputFieldList, @pUserName, @pPassword, 0, 'Subtree'
GO

---- extract group list
DECLARE @pStr nvarchar(4000), @pOutputFieldList nvarchar(2000), @pUserName sysname, @pPassword nvarchar(100)
-- to extract groups from exact group
-- 'LDAP://CN=Domain Admins,CN=Users,DC=HQ,DC=corp,DC=xxxxxxx,DC=ru'
-- all groups from AD
-- @pStr = N'LDAP://DC=HQ,DC=corp,DC=xxxxxx,DC=ru'
SELECT @pStr = N'LDAP://DC=HQ,DC=corp,DC=xxxxxx,DC=ru',
 @pOutputFieldList = 'cn,name,description,distinguishedName,whenChanged', @pUserName = '', @pPassword = N''

EXEC dbo.usp_GetGroupList @pStr, @pOutputFieldList, @pUserName, @pPassword, 0, 'Subtree'
GO

---- get computer list
DECLARE @pStr nvarchar(4000), @pOutputFieldList nvarchar(2000), @pUserName sysname, @pPassword nvarchar(100)
SELECT @pStr = N'LDAP://DC=HQ,DC=corp,DC=xxxxxxxxx,DC=ru',
 @pOutputFieldList = 'cn,name,distinguishedName,whenChanged', @pUserName = '', @pPassword = N''

EXEC dbo.usp_GetComputerList @pStr, @pOutputFieldList, @pUserName, @pPassword, 0, 'Subtree'
GO

------- get group members
DECLARE @pStr nvarchar(4000), @pOutputFieldList nvarchar(2000), @pUserName sysname, @pPassword nvarchar(100)
--SELECT @pStr = N'LDAP://CN=Domain Admins,CN=Users,DC=HQ,DC=corp,DC=xxxxxxxxx,DC=ru',
-- @pOutputFieldList = 'sAMAccountName'
SELECT @pStr = N'LDAP://CN=Administrators,CN=Users,DC=HQ,DC=corp,DC=xxxxxxxxx,DC=ru',
 @pOutputFieldList = 'Name', @pUserName = '', @pPassword = N''

EXEC dbo.usp_GetGroupMembers @pStr, @pOutputFieldList, @pUserName, @pPassword, 0
GO

----- enlist user membership
DECLARE @pStr nvarchar(4000), @pOutputFieldList nvarchar(2000), @pUserName sysname, @pPassword nvarchar(100)
SELECT @pStr = N'LDAP://CN=Administrator,CN=Users,DC=HQ,DC=corp,DC=xxxxxxxxx,DC=ru',
 @pOutputFieldList = 'Name', @pUserName = '', @pPassword = N''

EXEC dbo.usp_GetUserMembership @pStr, @pOutputFieldList, @pUserName, @pPassword, 0
GO

-- Here is a section of cleanup script

USE <your_database_name>
GO

-- delete procedures
IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[usp_GetListOfRegisteredDirectoryProviders]') AND type in (N'P', N'PC'))
 DROP PROCEDURE [dbo].[usp_GetListOfRegisteredDirectoryProviders]
GO

IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[usp_TryAuthenticate]') AND type in (N'P', N'PC'))
 DROP PROCEDURE [dbo].[usp_TryAuthenticate]
GO

IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[usp_TryAuthenticateAsUser]') AND type in (N'P', N'PC'))
 DROP PROCEDURE [dbo].[usp_TryAuthenticateAsUser]
GO

IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[usp_FillInfoByPath]') AND type in (N'P', N'PC'))
 DROP PROCEDURE [dbo].[usp_FillInfoByPath]
GO

IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[usp_GetNodeProperties]') AND type in (N'P', N'PC'))
 DROP PROCEDURE [dbo].[usp_GetNodeProperties]
GO

IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[usp_GetUserList]') AND type in (N'P', N'PC'))
 DROP PROCEDURE [dbo].[usp_GetUserList]
GO

IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[usp_GetGroupList]') AND type in (N'P', N'PC'))
 DROP PROCEDURE [dbo].[usp_GetGroupList]
GO

IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[usp_GetComputerList]') AND type in (N'P', N'PC'))
 DROP PROCEDURE [dbo].[usp_GetComputerList]
GO

IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[usp_GetGroupMembers]') AND type in (N'P', N'PC'))
 DROP PROCEDURE [dbo].[usp_GetGroupMembers]
GO

IF  EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'[dbo].[usp_GetUserMembership]') AND type in (N'P', N'PC'))
 DROP PROCEDURE [dbo].[usp_GetUserMembership]
GO

-- delete assemblies
IF  EXISTS (SELECT * FROM sys.assemblies asms WHERE asms.name = N'MsForClient.SqlServer.SqlClrToolkit.MSADHelper')
 DROP ASSEMBLY [MsForClient.SqlServer.SqlClrToolkit.MSADHelper]
GO

IF  EXISTS (SELECT * FROM sys.assemblies asms WHERE asms.name = N'System.DirectoryServices')
 DROP ASSEMBLY [System.DirectoryServices]
GO

USE Master
GO

-- drop logins

IF  EXISTS (SELECT * FROM sys.server_principals WHERE name = N'SQLCLRSysDirServLogin')
 DROP LOGIN [SQLCLRSysDirServLogin]
GO

IF  EXISTS (SELECT * FROM sys.server_principals WHERE name = N'SQLCLRHelperLogin')
 DROP LOGIN [SQLCLRHelperLogin]
GO

-- drop keys 

IF EXISTS(SELECT * FROM sys.asymmetric_keys WHERE [name] = 'MSADHelperAsKey')
 DROP ASYMMETRIC KEY MSADHelperAsKey
GO

IF EXISTS(SELECT * FROM sys.asymmetric_keys WHERE [name] = 'SystemDirectoryServicesKey')
 DROP ASYMMETRIC KEY SystemDirectoryServicesKey
GO

-- Seems to me finished :-)

Dec 08, 2007 :

i updated source code to fix bug - many thanks to Taylor Gerring

MSADHelper2.rar