December 18, 2013 at 11:56 am
Folks:
I need help with a SQL Query. I have this data extracted from AD and have in a SQL table with single column.
CREATE TABLE #tblADData
(
DomainData nvarchar(2000)
)
insert into #tblADData values ('CN=James,OU=Luxembourg,OU=Italy,OU=Standard users,OU=Users,OU=Managed objects,DC=XYZ,DC=ABC Ltd,DC=fr')
insert into #tblADData values ('CN=Ernst,OU=Luxembourg,OU=Italy,OU=Standard users,OU=Users,OU=Managed objects,DC=XYZ,DC=ABC Ltd,DC=it')
insert into #tblADData values ('CN=Tommy,OU=Luxembourg,OU=Belgium,OU=Standard users,OU=Users,OU=Managed objects,DC=ABSD,DC=XYZ Ltd,DC=ne')
insert into #tblADData values ('CN=Dcruz,OU=Tuscany,DC=PQRST,DC=PQR Ltd,DC=PQRS')
insert into #tblADData values ('CN=Marti Ho,OU=Intl Contacts,OU=Japan,OU=Contacts,OU=Users,DC=ABSD,DC=ne')
insert into #tblADData values ('CN=Miranda,OU=Montreal,DC=PQR,DC=ABC Ltd,DC=ABSD')
insert into #tblADData values ('CN=Will Hay,OU=Local Contacts,OU=Paris,OU=Contacts,OU=Users,DC=XYZ,DC=fr')
I want to split the data into seperate columns (8 columns).
In some cases if you notice the OU is reflected only once or twice instead of the standard 5 times and the DC is reflected only once instead of standard 2 times. If I use the export utility then the problem is because there are no extra commas it adds the data to a differnt column. I would want the output to be like this in the
CREATE TABLE #tblSplitADData
(
CN VARCHAR(200),
OU1 VARCHAR(200),
OU2 VARCHAR(200),
OU3 VARCHAR(200),
OU4 VARCHAR(200),
OU5 VARCHAR(200),
DC1 VARCHAR(200),
DC2 VARCHAR(200)
)
INSERT INTO #tblSplitADData values ('James','Luxembourg','Italy','Standard users','Users','Managed Objects','XYZ','fr')
INSERT INTO #tblSplitADData values ('Ernst','Luxembourg','Italy','Standard users','Users','Managed Objects','XYZ','it')
INSERT INTO #tblSplitADData values ('Tommy','Luxembourg','Belgium','Standard users','Users','Managed Objects','ABSD','ne')
INSERT INTO #tblSplitADData values ('Dcruz','Tuscany','','','','','PQRS','')
INSERT INTO #tblSplitADData values ('Marti','Intl Contacts','Japan','Contacts','Users','','ABSD','ne')
INSERT INTO #tblSplitADData values ('Miranda','Montreal','','','','','ABSD','fr')
INSERT INTO #tblSplitADData values ('Will Hay','Local Contacts','Paris','Contacts','Users','','XYZ','fr')
Thanks !
December 18, 2013 at 12:07 pm
it might be easier to just query the active directory from SQL via a linked server.
then the pieces can be pulled out automatically;
does this help you at all? it just worked on my domain:
--sp_dropserver ADSI
EXEC master.dbo.sp_addlinkedserver @server = N'ADSI',
@srvproduct=N'Active Directory Services', @provider=N'ADsDSOObject',
@datasrc=N'MyDomain'
select * from openquery
(ADSI,'SELECT
cn,
sn,
SamAccountName,
mail,
telephoneNumber,
mobile,
co,
distinguishedName,
displayName,
physicalDeliveryOfficeName,
department
FROM ''LDAP://MyDomain''
WHERE objectCategory = ''Person'' AND objectClass = ''user'''
)
Lowell
December 18, 2013 at 12:13 pm
I know pulling the data directly from AD would have been easier but we are getting this data (flat file) from some other source (1 time activity) and don't have access to their network.
December 18, 2013 at 2:30 pm
Lowell,
Querying AD directly has always given me a problem when extracting things that have multiple occurrances (like OU or group membership). Is there a way to get those types of data items from a linked server?
December 18, 2013 at 3:09 pm
Offhand, I would recommend normalizing this data if you have any intentions of searching for groups or similar. The reason being group xyz could be in the 3rd, 4th, or 5th position, making searching very difficult via this model.
Either way, though, you're looking at stripping the string down, determining the individual entries, then choosing what to do with them. If you were to normalize it, I'd recommend the following:
First, you want the delimitedSplit8k. Found here: Tally oh! article[/url]
Once you've got that, your code would look like this:
/*
DROP TABLE #tblADData
GO
CREATE TABLE #tblADData
(
RowID INT IDENTITY( 1,1),
DomainData nvarchar(2000)
)
insert into #tblADData values ('CN=James,OU=Luxembourg,OU=Italy,OU=Standard users,OU=Users,OU=Managed objects,DC=XYZ,DC=ABC Ltd,DC=fr')
insert into #tblADData values ('CN=Ernst,OU=Luxembourg,OU=Italy,OU=Standard users,OU=Users,OU=Managed objects,DC=XYZ,DC=ABC Ltd,DC=it')
insert into #tblADData values ('CN=Tommy,OU=Luxembourg,OU=Belgium,OU=Standard users,OU=Users,OU=Managed objects,DC=ABSD,DC=XYZ Ltd,DC=ne')
insert into #tblADData values ('CN=Dcruz,OU=Tuscany,DC=PQRST,DC=PQR Ltd,DC=PQRS')
insert into #tblADData values ('CN=Marti Ho,OU=Intl Contacts,OU=Japan,OU=Contacts,OU=Users,DC=ABSD,DC=ne')
insert into #tblADData values ('CN=Miranda,OU=Montreal,DC=PQR,DC=ABC Ltd,DC=ABSD')
insert into #tblADData values ('CN=Will Hay,OU=Local Contacts,OU=Paris,OU=Contacts,OU=Users,DC=XYZ,DC=fr')
*/
;WITH cte AS
(SELECT
*
FROM
#tblADData AS a
CROSS APPLY
dbo.DelimitedSplit8k( a.DomainData, ',') AS split
)
SELECT
STUFF( c1.Item , 1, 3, '') AS NameOfUser,
LEFT( c2.Item, 2) AS AttributeType,
STUFF( c2.Item, 1, 3, '') AS AttributeValue
FROM
cte AS c1
JOIN
cte AS c2
ONc1.RowID = c2.RowID
WHERE
LEFT( c1.Item, 2) = 'CN'
AND LEFT( c2.Item, 2) <> 'CN'
EDIT: Forgot to mention that you need to adjust your source table to have an easy row identifier.
Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.
For better assistance in answering your questions[/url] | Forum Netiquette
For index/tuning help, follow these directions.[/url] |Tally Tables[/url]
Twitter: @AnyWayDBA
December 18, 2013 at 9:24 pm
Lowell (12/18/2013)
it might be easier to just query the active directory from SQL via a linked server.then the pieces can be pulled out automatically;
does this help you at all? it just worked on my domain:
--sp_dropserver ADSI
EXEC master.dbo.sp_addlinkedserver @server = N'ADSI',
@srvproduct=N'Active Directory Services', @provider=N'ADsDSOObject',
@datasrc=N'MyDomain'
select * from openquery
(ADSI,'SELECT
cn,
sn,
SamAccountName,
mail,
telephoneNumber,
mobile,
co,
distinguishedName,
displayName,
physicalDeliveryOfficeName,
department
FROM ''LDAP://MyDomain''
WHERE objectCategory = ''Person'' AND objectClass = ''user'''
)
Crud. Apparently, that doesn't work in 2005?
Msg 7321, Level 16, State 2, Line 1
An error occurred while preparing the query "SELECT
cn,
sn,
SamAccountName,
mail,
telephoneNumber,
mobile,
co,
distinguishedName,
displayName,
physicalDeliveryOfficeName,
department
FROM 'LDAP://MyDomain'
WHERE objectCategory = 'Person' AND objectClass = 'user'" for execution against OLE DB provider "ADsDSOObject" for linked server "ADSI".
An, yeah... I tried changing "MyDomain" to the name of my domain and it produced the same error. Way too bad for me :crying: because this would be wicked useful for the internal security audit we're getting ready to do.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 6 posts - 1 through 5 (of 5 total)
You must be logged in to reply to this topic. Login to reply