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

Techorama 2025 – Slides

You can find the slides for my session Building the €100 data warehouse with the…

1 week ago

Redgate SQL Prompt in SSMS 21

Disclaimer: this post is not sponsored by Redgate :) For those who've missed it, the…

2 weeks ago

Execute Fabric Data Pipeline from Azure Data Factory

In the blog post Call a Fabric REST API from Azure Data Factory I explained…

1 month ago

Azure Data Factory Pipeline Debugging Fails with BadRequest

I recently had a new pipeline fail. It was actually a copy of an old…

2 months ago

Call a Fabric REST API from Azure Data Factory

Suppose you want to call a certain Microsoft Fabric REST API endpoint from Azure Data…

2 months ago

Cool Stuff in Snowflake – Part 14: Asynchronous Execution of SQL Statements

I’m doing a little series on some of the nice features/capabilities in Snowflake (the cloud data warehouse).…

3 months ago