Parse DTSX Package Connection Manager Properties
The following query returns connection manager properties from the SSIS .dtsx packages stored in a particular file system folder.
The code relies upon the undocumented and unsupported sys.xp_dirtree
extended stored procedure that ships with all versions of Microsoft SQL Server. To use this code, you’ll need to be a member of the sysadmin
server role.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 |
DECLARE @root_dtsx_folder nvarchar(260) = N'C:\path\to\dtsx\files'; DECLARE @filelist TABLE ( [subdirectory] varchar(260) NULL , [depth] int NULL , [file] bit NULL ); INSERT INTO @filelist([subdirectory], [depth], [file]) EXEC sys.xp_dirtree @root_dtsx_folder, 0, 1; DECLARE @results TABLE ( [PackageName] nvarchar(1000) NULL , [ObjectName] nvarchar(1000) NULL , [CreationName] nvarchar(1000) NULL , [Property] nvarchar(1000) NULL , [Value] nvarchar(1000) NULL , [ConnectionString] nvarchar(1000) NULL ); DECLARE @filename varchar(260); DECLARE cur CURSOR LOCAL FORWARD_ONLY STATIC READ_ONLY FOR SELECT fl.subdirectory FROM @filelist fl WHERE fl.subdirectory LIKE '%dtsx' AND fl.[file] = 1; OPEN cur; FETCH NEXT FROM cur INTO @filename; WHILE @@FETCH_STATUS = 0 BEGIN SET @filename = @root_dtsx_folder + N'\' + @filename; DECLARE @sql nvarchar(max) = N' DECLARE @doc xml; SELECT @doc = CONVERT(xml, Document.BulkColumn) FROM OPENROWSET(BULK N''' + @filename + N''', SINGLE_BLOB) AS Document; DECLARE @idoc int; EXEC sp_xml_preparedocument @idoc OUTPUT, @doc, ''<DTS xmlns:DTS="www.microsoft.com/SqlServer/Dts" />''; SELECT [PackageName] , [ObjectName] , [CreationName] , [Property] , [Value] , [ConnectionString] FROM OPENXML(@idoc, N''/DTS:Executable/DTS:ConnectionManagers/DTS:ConnectionManager'', 2) WITH ( PackageName nvarchar(1000) N''../../@DTS:ObjectName'' , [ObjectName] nvarchar(1000) N''@DTS:ObjectName'' , CreationName nvarchar(1000) N''@DTS:CreationName'' , Property nvarchar(1000) N''DTS:PropertyExpression/@DTS:Name'' , [Value] nvarchar(1000) N''DTS:PropertyExpression'' , ConnectionString nvarchar(1000) N''DTS:ObjectData/DTS:ConnectionManager/@DTS:ConnectionString'' ) x; '; INSERT INTO @results EXEC sys.sp_executesql @sql; FETCH NEXT FROM cur INTO @filename; END CLOSE cur; DEALLOCATE cur; SELECT * FROM @results; |
Thanks for reading, and while you’re here, why not check out the rest of our free SQL Server Tools!