Extract ispac file from SSISDB

  • Hi -

    I need to extract the .ispac file from the SSISDB. I can retrieve the stream with catalog.get_project sp. However, the file I end up with cannot be unzipped, giving an error message. My guess is that it is meta-data on the zip/ispac file that has a problem, because I can actually unzip it with Winrar, but not with any of those I (programmatically) need to unzip it with.

    Below is the code for my stored procedure - please take a hard look at where something might go wrong. My own suspicion is in the BCP usage to turn the stream into a file.

    Thanks,

    Anders

    USE [SSISDB]

    GO

    ALTER PROCEDURE [dbo].[spGetIspacFile]

    @project VARCHAR(255) ,

    @environmentFolder VARCHAR(50) ,

    @ispacTempFolder VARCHAR(100) ,

    @ispacFilePath VARCHAR(200) OUTPUT

    AS

    BEGIN

    DECLARE @ispacFileName VARCHAR(200) = CONVERT(NVARCHAR(50), NEWID())

    + '.ispac'

    SET @ispacFilePath = @ispacTempFolder + '\' + @ispacFileName

    CREATE TABLE ##resultsTableVar

    (

    binaryProject VARBINARY(MAX)

    )

    INSERT ##resultsTableVar

    ( binaryProject

    )

    EXEC [SSISDB].[catalog].[get_project] @folder_name = @environmentFolder,

    @project_name = @project

    DECLARE @sqlCommand VARCHAR(500)

    SET @sqlCommand = 'BCP "SELECT binaryProject FROM ##resultsTableVar" queryout "'

    + @ispacFilePath + '" -T -n -S"' + @@SERVERNAME + '"'

    EXEC master.dbo.xp_cmdshell @sqlCommand

    DROP TABLE ##resultsTableVar

    END

  • I found the solution. Apparently, BCP is faulty, although it is uncertain exactly how - might be a header setting on the file that is not right, when it creates the file from the stream. So here is the solution, without using BCP. (thanks to this on Stackoverflow for leading to the solution):

    USE [SSISDB]

    GO

    ALTER PROCEDURE [dbo].[spGetIspacFile]

    @project VARCHAR(255) ,

    @environmentFolder VARCHAR(50) ,

    @ispacTempFolder VARCHAR(100) ,

    @ispacFilePath VARCHAR(200) OUTPUT

    AS

    BEGIN

    DECLARE @ispacFileName VARCHAR(200) = CONVERT(NVARCHAR(50), NEWID())

    + '.ispac'

    SET @ispacFilePath = @ispacTempFolder + '\' + @ispacFileName

    CREATE TABLE ##resultsTableVar

    (

    binaryProject VARBINARY(MAX)

    )

    INSERT ##resultsTableVar

    ( binaryProject

    )

    EXEC [SSISDB].[catalog].[get_project] @folder_name = @environmentFolder,

    @project_name = @project

    DECLARE @fileStream VARBINARY(MAX) ,

    @objectToken INT

    SELECT @fileStream = binaryProject

    FROM ##resultsTableVar

    EXEC sp_OACreate 'ADODB.Stream', @objectToken OUTPUT

    EXEC sp_OASetProperty @objectToken, 'Type', 1

    EXEC sp_OAMethod @objectToken, 'Open'

    EXEC sp_OAMethod @objectToken, 'Write', NULL, @fileStream

    EXEC sp_OAMethod @objectToken, 'SaveToFile', NULL, @ispacFilePath, 2

    EXEC sp_OAMethod @objectToken, 'Close'

    EXEC sp_OADestroy @objectToken

    DROP TABLE ##resultsTableVar

    END

  • first try (from powershell):

    Am able to write these out to an .ispac files and rename to .zip

    but the contents are garbage

    2nd try (SSMS)

    your OACREATE method works, creates the ispac/zip file fine

    but if im hitting a remore server

    the powershell calls TSQL on the remote server which calls OACreate (local to it) and saves it the file on the remote server's disk

  • Below is the code for my stored procedure - please take a hard look at where something might go wrong. My own suspicion is in the BCP usage to turn the stream into a file.

    I think that your issue with BCP is simply - it is the wrong tools for this task. BCP is intended to write data to a file on a row by row basis with a separator (e.g. CR/LF) between each row. What you need for this task is a method/tool that will write the individual bytes to a file with the extra separators. This is why the solution you found works.

  • Have you had success with this on SQL 2012 (11.0.5582) -- I am getting a transaction related error in the MS delivered sproc...

    Msg 3915, Level 16, State 0, Procedure get_project, Line 105

    Cannot use the ROLLBACK statement within an INSERT-EXEC statement.

  • https://github.com/gwalkey/SQLTranscriptase

    I have created an entire library of Powershell code to extract everything from SQL Server.

    09_SSIS_Packages_from_SSISDB.ps1 creates ispac files using BCP just fine.

    Cheers

Viewing 6 posts - 1 through 5 (of 5 total)

You must be logged in to reply to this topic. Login to reply