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

dataMinds Connect 2025 – Slides & Scripts

You can find all the session materials for the presentation "Indexing for Dummies" that was…

4 days ago

Cloud Data Driven User Group 2025 – Slides & Scripts

The slidedeck and the SQL scripts for the session Indexing for Dummies can be found…

2 weeks ago

Retro Data 2025 – Slidedeck

You can find the slides of my session on the €100 DWH in Azure on…

3 weeks ago

Secure Logic Apps with OAuth Authorization

I've used Logic Apps a couple of times over the past years for simple workflows,…

4 weeks ago

Free Online Sessions – Building the €100 DWH and Indexing for Dummies

I'm giving two online sessions soon on virtual events that are free to attend. The…

1 month ago

How to Install SQL Server 2025 RC0 on an Azure VM

I wanted to try out the new JSON index which is for the moment only…

1 month ago