Categories: SSIS

Exporting Environment Variables out of the SSIS Catalog

Sometimes when you’ve created a SSIS catalog, along with folders, environments and environment variables, you want this content on another server. Unfortunately, you can only script out these objects in SSMS at the moment you’re creating them (thus right before you clikc ‘OK’ to confirm). Once the objects are created, you can no longer script them out using the GUI.

Luckily, there’s a whole slew of stored procedures and views in the catalog that allow us to extract information and use that information to re-create the objects. Here are two scripts that I found useful.

The first one extracts all environment variables out of an environment (I currently take only the data type String into account to put quotes around, but this might be expanded):

SELECT
    v.[name]
   ,v.[type]
   ,v.[value]
   ,Script = 'EXEC [SSISDB].[catalog].[create_environment_variable]
       @variable_name=''' + CONVERT(NVARCHAR(250), v.name) + '''
      ,@sensitive=0
      ,@description=''''
      ,@environment_name=''myenv''
      ,@folder_name=''myfolder''
      ,@value='
             + IIF(v.type = 'String'
                ,N'N''' + CONVERT(NVARCHAR(500), v.value) + ''''
                ,CONVERT(NVARCHAR(500), v.value)
                )
             + '
      ,@data_type=N''' + v.type + ''';
'
FROM    [SSISDB].[catalog].[environments]          e
JOIN [SSISDB].[catalog].[folders]               f ON f.[folder_id]      = e.[folder_id]
JOIN [SSISDB].[catalog].[environment_variables] v ON e.[environment_id] = v.[environment_id]
WHERE   f.[name] = N'myfolder'
    AND e.[name] = N'myenv';

It also creates a script for each environment variable. Just copy paste the column contents and execute it on the server where you wish to create the variables. Once the environment variables are created, you need to create a reference between the environment and the SSIS project. Then, you need to link each parameter with its corresponding environment variable. The following script extracts the info and again creates a SQL statement to create this reference. It assumes though the parameters and the environment variables have the same name (which seems kind of a best practice, right?):

SELECT -- v.[name], v.[type], v.[value]
    Script = 'EXEC [SSISDB].[catalog].[set_object_parameter_value]
        @object_type=20
      , @parameter_name=N''' + CONVERT(NVARCHAR(500), v.name) + '''
      , @object_name=N''SSIS''
      , @folder_name=N''myfolder''
      , @project_name=''SSIS''
      , @value_type=R
      , @parameter_value=N''' + CONVERT(NVARCHAR(500), v.name) + ''';
'
FROM [SSISDB].[catalog].[environments]          e
JOIN [SSISDB].[catalog].[folders]               f ON f.[folder_id]      = e.[folder_id]
JOIN [SSISDB].[catalog].[environment_variables] v ON e.[environment_id] = v.[environment_id]
WHERE   f.[name] = N'myfolder'
    AND e.[name] = N'myenv';

Creating a folder and the environment are easy enough to do manually. If you want to script those out as well, this article can get you started.


------------------------------------------------
Do you like this blog post? You can thank me by buying me a beer 🙂
Koen Verbeeck

Koen Verbeeck is a Microsoft Business Intelligence consultant at AE, helping clients to get insight in their data. Koen has a comprehensive knowledge of the SQL Server BI stack, with a particular love for Integration Services. He's also a speaker at various conferences.

Recent Posts

Free webinar – Tackling the Gaps and Islands Problem with T-SQL Window Functions

I'm hosting a free webinar at MSSQLTips.com at the 19th of December 2024, 6PM UTC.…

5 days ago

dataMinds Connect 2024 – Session Materials

The slides and scripts for my session "Tackling the Gaps & Islands Problem with T-SQL…

4 weeks ago

Connect to Power BI as a Guest User in another Tenant

Sometimes your Microsoft Entra ID account (formerly known as Azure Active Directory) is added as…

2 months ago

How to use a Script Activity in ADF as a Lookup

In Azure Data Factory (ADF, but also Synapse Pipelines and Fabric Pipelines), you have a…

4 months ago

Database Build Error – Incorrect syntax near DISTINCT

I wrote a piece of SQL that had some new T-SQL syntax in it: IS…

4 months ago

Speaking at dataMinds Connect 2024

I'm very excited to announce I've been selected as a speaker for dataMinds Connect 2024,…

5 months ago