Estimating Nonclustered Index Size in SQL Server (Powershell)

I recently encountered a requirement to estimate the size of (a lot of) nonclustered indexes on some very large tables due to not having a test box to create them on or the time to build one. I couldn’t find a script to do this, and as any programmer knows, laziness is the real mother of invention, so I wrote one.
This post summarises how we can calculate this and provides a Powershell function to do so.

I used Microsoft’s documentation as a basis on how to do it, but as it’s a wall of text that’s a little tricky to follow, I’ll go over the basics here. I’m only covering the leaf levels and non-MAX columns that would create LOB pages – I’ll explain why later.

Fundamentally we need to figure out the size of an index record, work out how many fit cleanly on a page, then calculate the total size.

So what’s in an index record?

This, as of SQL 2012, is the most basic record possible. It has;

  • A header – 1 byte
  • Null bitmap – minimum 3 bytes, an extra byte for every 8 total columns in the index (so 4 bytes for 9 columns, 5 bytes for 17, etc)
  • Data row locator – this is either an 8-byte RID if the table is a heap, or the clustered index keys if not.
  • The index columns themselves – however many columns (key or included) are in the index, aside from clustering keys which are in the DRL.

If there are any variable-length columns present in the index (key, row locator or included), there’s an extra section;

The ‘variable tracker’ is 2 bytes plus 2 bytes for every variable length column (including the uniquifier on a primary key, if it exists).

On top of this, each record takes an extra 2 bytes of a page’s slot array so it can be located – this isn’t on the diagrams as it isn’t part of the record itself.

So the script needs to do the following;

  • Get the rowcount of the table
  • Check if the table is a heap or has a clustered index
  • If the table has a clustered index, is it unique? (does it have a uniquifier)
  • Count the total number of columns (for the null bitmap)
  • Count the number of variable-length columns
  • Calculate the total size of a record, plus the 2 byte slot array entry
  • Divide that size into 8096 bytes – the usable space on a page – rounding down as only entire rows are stored
  • Divide that number into the rowcount of the table, and then we have the pages (and thus size) required.

As well as those, I added a few bits of functionality;

  • Take a rowcount as a parameter, if we don’t want to hit a production table with COUNT_BIG()
  • Take fillfactor as a parameter in case we’re not using 100 for some reason
  • Keep track of null columns, as for versions prior to 2012, null bitmaps only exist on leaf pages if at least one column is null.

Script for the function Get-IndexSizeEstimate is at the bottom of the post and on github.
It takes an instance name, database, schema, string array of columns for the nonclustered index (including included columns) and optionally the rowcount and fill factor. The SQL and calculation blocks are documented so should be fairly self-explanatory combined with the above information – so onto some demos.

First, using a simple table I used for testing various cases, left as a heap, with 100k rows inserted to generate a few hundred pages;

CREATE TABLE dbo.IndexTesting 
(
CustID INT NULL,
OrderID INT NOT NULL,
IndexCol1 INT NOT NULL,
IndexCol2 INT NULL,
VarIndexCol1 VARCHAR(4) NOT NULL,
VarIndexCol2 VARCHAR(10) NOT NULL
)
GO

INSERT INTO dbo.IndexTesting (CustID, OrderID, IndexCol1, IndexCol2, VarIndexCol1, VarIndexCol2)
VALUES (1,2,3,4,'test','test')
GO 100000

If we want to create a single column index on IndexCol1 (4 bytes), the record should look like this;

for a total of 16 bytes.

Run the script for a single column index on IndexCol1;

Get-IndexSizeEstimate -Instance SQL2017-VM01 -Database TestDB -Schema dbo -Table IndexTesting -Column 'IndexCol1'

We can see the use of the 8-byte RID as row locator, the minimum null bitmap and no variable-width bytes as expected.
Create the index and see if we’re close;

SELECT index_level, page_count, record_count, min_record_size_in_bytes, max_record_size_in_bytes, avg_record_size_in_bytes
FROM sys.dm_db_index_physical_stats(DB_ID(),OBJECT_ID('dbo.IndexTesting'),2,NULL,'DETAILED')

SELECT SUM(used_page_count) * 8 / 1024 AS 'SizeMB'
FROM sys.indexes i 
INNER JOIN sys.dm_db_partition_stats p
	ON p.[object_id] = i.[object_id]
	AND i.index_id = p.index_id
WHERE i.[name] = 'ncx_test'

Bang on, 223 pages and 1MB.

Now for some more real-world examples.
A simple test case on a big table – using dbo.Posts from the StackOverflow2013 database, and choosing an index on OwnerUserId.

Get-IndexSizeEstimate -Instance SQL2017-VM01 -Database StackOverflow2013 -Schema dbo -Table Posts -Column 'OwnerUserId'

29658 pages and 232MB is the estimate – and note the row locator is now just 4 bytes, as it’s using the clustered index key instead of the RID in previous example.

Create the index and see how it stacks up (no pun intended);

CREATE NONCLUSTERED INDEX ncx_Posts_OwnerUserId 
ON dbo.Posts (OwnerUserId)

SELECT index_level, page_count, record_count, min_record_size_in_bytes, max_record_size_in_bytes, avg_record_size_in_bytes
FROM sys.dm_db_index_physical_stats(DB_ID(),OBJECT_ID('dbo.Posts'),2,NULL,'DETAILED')

SELECT SUM(used_page_count) * 8 / 1024 AS 'SizeMB'
FROM sys.indexes i 
INNER JOIN sys.dm_db_partition_stats p
	ON p.[object_id] = i.[object_id]
	AND i.index_id = p.index_id
WHERE i.[name] = 'ncx_Posts_OwnerUserId'

Not bad – just 2 pages out, and the same size after rounding to MB.

Now let’s go wide;

Get-IndexSizeEstimate -Instance SQL2017-VM01 -Database StackOverflow2013 -Schema dbo -Table Posts -Column 'Score','PostTypeId','CreationDate','FavoriteCount','OwnerUserId','ViewCount','LastActivityDate', 'ParentId'

108495 pages and 848MB. Note how since we have 9 total columns in the index when including the primary key, the null bitmap has spilled into 4 bytes.

Build the index and take a look;

CREATE NONCLUSTERED INDEX ncx_Posts_WideIndex 
ON dbo.Posts (Score,PostTypeId,CreationDate,FavoriteCount,OwnerUserId,ViewCount,LastActivityDate,ParentId)

SELECT index_level, page_count, record_count, min_record_size_in_bytes, max_record_size_in_bytes, avg_record_size_in_bytes
FROM sys.dm_db_index_physical_stats(DB_ID(),OBJECT_ID('dbo.Posts'),4,NULL,'DETAILED')

SELECT SUM(used_page_count) * 8 / 1024 AS 'SizeMB'
FROM sys.indexes i 
INNER JOIN sys.dm_db_partition_stats p
	ON p.[object_id] = i.[object_id]
	AND i.index_id = p.index_id
WHERE i.[name] = 'ncx_Posts_WideIndex'

One page out and a 5MB undershoot – again, not bad!
This is also an example of how, even with a wide (in column number terms) index, the contribution of the non-leaf levels is minor.
They explain the 5MB discrepancy – and that’s just ~0.5% of the total size. This is the first reason I didn’t include calculations for the non-leaf levels of the index.

Now for an example of where the estimate can be way off.
Using dbo.Posts again, but this time estimating for an index on LastEditorDisplayName, which is a nullable NVARCHAR(40) column.

Get-IndexSizeEstimate -Instance SQL2017-VM01 -Database StackOverflow2013 -Schema dbo -Table Posts -Column 'LastEditorDisplayName'

That’s ~200k pages and 1.5GB. Create the index and take a look;

CREATE NONCLUSTERED INDEX ncx_Posts_DisplayName
ON dbo.Posts (LastEditorDisplayName)

SELECT index_level, page_count, record_count, min_record_size_in_bytes, max_record_size_in_bytes, avg_record_size_in_bytes
FROM sys.dm_db_index_physical_stats(DB_ID(),OBJECT_ID('dbo.Posts'),3,NULL,'DETAILED')

SELECT SUM(used_page_count) * 8 / 1024 AS 'SizeMB'
FROM sys.indexes i 
INNER JOIN sys.dm_db_partition_stats p
	ON p.[object_id] = i.[object_id]
	AND i.index_id = p.index_id
WHERE i.[name] = 'ncx_Posts_DisplayName'

Ouch. That’s an order-of-magnitude overestimate. Why? Take a look at the record size figures. Min 8, max 72, and an average barely over the minimum.
Taking a glance at the table shows it appears to be sparsely populated, and with names that are much less than 40 characters to boot;

Well, there’s the rub. When variable length or null columns are included, the estimate can be nigh-on useless, depending on the distribution of data. Yep, there are things that could be done to get a better estimate – like taking a string array of parameters for ‘estimated null percent’ or ‘estimated varchar usage percent’, or going beyond guesses by calculating those figures from sampling/scanning the table…but at this point, a) the code starts getting increasingly complicated, b) we’re potentially needing to hit the database with some hefty queries and c) …it’s still not going to be completely accurate, so if it needs to be, we best get that test box set up. This is why I didn’t attempt to take non-leaf levels, LOB pages or variable-length column usage (script assumes maximum length) into account – it is an estimate, after all.

That said, I hope it proves useful to someone for the scenario it works well for – fixed-length column indexes. Code is below.

function Get-IndexSizeEstimate
{
<#

.SYNOPSIS
Returns estimated index size for a given column in a table

.DESCRIPTION
Calculates leaf-level index size for a given column in a table and returns the calculation and value in MB

.PARAMETER Instance
Specifies the SQL instance name

.PARAMETER Database
Specifies the database name

.PARAMETER Schema
Specifies the schema name

.PARAMETER Table
Specifies the table name

.PARAMETER Column
Specifies the column name(s) 

.PARAMETER Rows
Specifies the number of rows to calculate for instead of querying the table for COUNT()

.PARAMETER Fillfactor
Specifies the fillfactor (1-100) to use (default 100)

.OUTPUTS
Index leaf-level estimated size

.EXAMPLE
PS> Get-IndexSizeEstimate -Instance SQL2017-VM01 -Database TestDB -Schema dbo -Table IndexTesting -Column IndexCol1,VarIndexCol2
Using retrieved rowcount of 100000
Using variable-length column max length of 4 bytes
Using unique clustering key of total 4 bytes
Clustering key contains no null column(s)
0 clustering key column(s) are variable-length
Index contains 2 leaf columns total
1 total columns are variable-length
Using null bitmap of 3 bytes
Using variable-length column overhead size of 4 bytes
Index row size is 4 + 4 + 3 (null bitmap) + 4 (variable) + 1 (header) = 16 bytes
Leaf rows per page is 449
Leaf pages required is 223
Estimated nonclustered index size: 2 MB

#>
param
(
    [Parameter(position=0, mandatory=$true)][string]$Instance,
    [Parameter(position=1, mandatory=$true)][string]$Database,
    [Parameter(position=2, mandatory=$true)][string]$Schema,
    [Parameter(position=3, mandatory=$true)][string]$Table,
    [Parameter(position=4, mandatory=$true)][string[]]$Column,
    [Parameter(position=5, mandatory=$false)][long]$Rows,
    [Parameter(position=6, mandatory=$false)][int]$Fillfactor
)



Import-Module SqlServer

###### Pre-checks ######

# Parameter checks

if($Rows -and $Rows -lt 1)
{
    Write-Output "Rows parameter must be at least 1"

    return
}

if($Fillfactor -and ($Fillfactor -le 0 -or $Fillfactor -gt 100))
{
    Write-Output "Fillfactor must be an integer between 1 and 100"

    return;
}

# Check database exists and is online

$query = "SELECT 1
            FROM sys.databases
            WHERE [name] = '$($Database)'
            AND state_desc = 'ONLINE'"

try
{
    $check = Invoke-Sqlcmd -ServerInstance $Instance -Database master -Query $query -ConnectionTimeout 3 -QueryTimeout 3 -ErrorAction Stop

    if(!$check)
    {
        Write-Output "Error - database does not exist or is offline."

        return
    }
}
catch
{
    Write-Output "Error - can't connect to instance."
    Write-Output $error[0]

    return
}


# Check schema/table/column(s) exists
foreach($col in $Column)
{
    $query = "SELECT 1
                FROM sys.tables t
                INNER JOIN sys.schemas s
	                ON t.[schema_id] = s.[schema_id]
                INNER JOIN sys.columns c
	                ON t.[object_id] = c.[object_id]
                INNER JOIN sys.types ty
	                ON c.user_type_id = ty.user_type_id
                WHERE s.[name] = '$($Schema)'
                AND t.[name] = '$($Table)'
                AND c.[name] = '$($col)'"

    try
    {
        $check = Invoke-Sqlcmd -ServerInstance $Instance -Database $Database -Query $query -ConnectionTimeout 10 -QueryTimeout 300 -ErrorAction Stop

        if(!$check)
        {
            Write-Output "Error - schema/table/column doesn't exist for $($col)"
        
            return;
        }
    }
    catch
    {
        Write-Output "Error connecting to instance."
        Write-Output $error[0]

        return
    }
}

# Get SQL version

$query = "SELECT SUBSTRING(CONVERT(VARCHAR(128), SERVERPROPERTY('productversion')), 1, CHARINDEX('.', CONVERT(VARCHAR(128), SERVERPROPERTY('productversion')), 1) - 1) AS 'Version'"

try
{
    [int]$sqlversion = (Invoke-Sqlcmd -ServerInstance $Instance -Database master -Query $query -ConnectionTimeout 5 -QueryTimeout 5 -ErrorAction Stop).Version


}
catch
{
    Write-Output "Error retrieving SQL version"
    Write-Output $error[0]

    return
}

 
###### Code body ######

# Variable decarations
$leafcolumns = 0
$keylength = 0
$nullcolumns = $false
$nullbitmap = 0
$variablecolumns = 0
$variableoverheadsize = 0
$variablecolumnlist = 'text', 'ntext', 'image', 'varbinary', 'varchar', 'nvarchar'


# Get rowcount of table if not passed as parameter

if($Rows)
{
    $rowcount = $Rows

    Write-Output "Using passed rowcount of $($rowcount)"
}
else
{
    $query = "SELECT COUNT_BIG(*) AS 'Rowcount'
                FROM $($Schema).$($Table)"

    try
    {
        $rowcount = (Invoke-Sqlcmd -ServerInstance $Instance -Database $Database -Query $query -ConnectionTimeout 10 -QueryTimeout 300 -ErrorAction Stop).Rowcount

        if($rowcount -eq 0)
        {
            Write-Output "Table is empty. Aborting function"

            return
        }

        Write-Output "Using retrieved rowcount of $($rowcount)"

    }
    catch
    {
        Write-Output "Error retrieving rowcount."
        Write-Output $error[0]

        return
    }
}

# Get key column(s) length/nullability and increment leaf and variable key counters

foreach($col in $Column)
{
    $query = "SELECT c.is_nullable, c.max_length AS 'MaxLength', ty2.[Name]
                FROM sys.tables t
                INNER JOIN sys.schemas s
	                ON t.[schema_id] = s.[schema_id]
                INNER JOIN sys.columns c
	                ON t.[object_id] = c.[object_id]
                INNER JOIN sys.types ty
	                ON c.user_type_id = ty.user_type_id
                INNER JOIN sys.types ty2
	                ON ty.system_type_id = ty2.user_type_id
                WHERE s.[name] = '$($Schema)'
                AND t.[name] = '$($Table)'
                AND c.[name] = '$($col)'"

    try
    {
        $result = Invoke-Sqlcmd -ServerInstance $Instance -Database $Database -Query $query -ConnectionTimeout 5 -QueryTimeout 5 -ErrorAction Stop

        $keylength += $result.MaxLength

        $leafcolumns++

        # Set null columns flag true if index column is nullable (used for SQL < 2012)
        if($result.is_nullable)
        {
            $nullcolumns = $true
        }

        if($variablecolumnlist -contains $result.Name)
        {
            $variablecolumns++

            Write-Output "$($col): Using variable-length column max length of $($result.MaxLength) bytes"
        }
        else
        {
            Write-Output "$($col): Using fixed-length column max length of $($result.MaxLength) bytes"
        }
    
    }
    catch
    {
        Write-Output "Error retrieving column max length"
        Write-Output $error[0]
    
        return
    }
}


# Get clustered index size, nullability, column count and uniqueness (if exists)
$query = "SELECT i.is_unique, MAX(CAST(is_nullable AS TINYINT)) AS 'NullColumns', COUNT(*) AS 'NumKeyCols',  SUM(c.max_length) AS 'SummedMaxLength'
            FROM sys.tables t
            INNER JOIN sys.schemas s
	            ON t.[schema_id] = s.[schema_id]
            INNER JOIN sys.indexes i
	            ON t.[object_id] = i.[object_id]
            INNER JOIN sys.index_columns ic
	            ON i.[object_id] = ic.[object_id]
	            AND i.index_id = ic.index_id
            INNER JOIN sys.columns c
	            ON ic.[object_id] = c.[object_id]
	            AND ic.column_id = c.column_id
            WHERE s.[name] = '$($Schema)'
            AND t.[name] = '$($Table)'
            AND i.[type] = 1
            GROUP BY i.is_unique"

try
{
    $clusteringkey = Invoke-Sqlcmd -ServerInstance $Instance -Database $Database -Query $query -ConnectionTimeout 5 -QueryTimeout 5 -ErrorAction Stop

    # If there's no clustering key
    if(!$clusteringkey)
    {
        # Use value for heap RID (8 bytes)
        $rowlocatorlength = 8
        Write-Output "Table is a heap, using RID of 8 bytes"
    }
    else
    {
        # Increment leaf column count by clustering key count
        $leafcolumns += $clusteringkey.NumKeyCols

        if($clusteringkey.is_unique -eq 1)
        {
            $rowlocatorlength = $clusteringkey.SummedMaxLength

            Write-Output "Using unique clustering key of total $($rowlocatorlength) bytes"
        }
        else
        {
            # Need to add 4 bytes for uniquifier, and also increment $variablecolumns
            $rowlocatorlength = $clusteringkey.SummedMaxLength + 4
            $variablecolumns++

            Write-Output "Using nonunique clustering key of total $($rowlocatorlength) bytes with uniquifier"
        }

        # Check if any null columns exist in clustering key and set flag if so
        if($clusteringkey.NullColumns -eq 1)
        {
            $nullcolumns = $true

            Write-Output "Clustering key contains null column(s)"
        }
        else
        {
            Write-Output "Clustering key contains no null column(s)"
        }

        # Get count of clustering key variable colunns
        $query = "SELECT COUNT(*) AS 'Count'
                    FROM sys.tables t
                    INNER JOIN sys.schemas s
	                    ON t.[schema_id] = s.[schema_id]
                    INNER JOIN sys.indexes i
	                    ON t.[object_id] = i.[object_id]
                    INNER JOIN sys.index_columns ic
	                    ON i.[object_id] = ic.[object_id]
	                    AND i.index_id = ic.index_id
                    INNER JOIN sys.columns c
	                    ON ic.[object_id] = c.[object_id]
	                    AND ic.column_id = c.column_id
                    INNER JOIN sys.types ty
	                    ON c.user_type_id = ty.user_type_id
                    INNER JOIN sys.types ty2
	                    ON ty.system_type_id = ty2.user_type_id
                    WHERE s.[name] = '$($schema)'
                    AND t.[name] = '$($Table)'
                    AND i.[type] = 1
                    AND ty2.[name] IN ('text', 'ntext', 'image', 'varbinary', 'varchar', 'nvarchar')"

        $variableclusteringcolumns = (Invoke-Sqlcmd -ServerInstance $Instance -Database $Database -Query $query -ConnectionTimeout 5 -QueryTimeout 5 -ErrorAction Stop).Count

        Write-Output "$($variableclusteringcolumns) clustering key column(s) are variable-length"

        $variablecolumns += $variableclusteringcolumns

    }
}
catch
{
    Write-Output "Error retrieving clustering key info"
    Write-Output $error[0]

    return
}


Write-Output "Index contains $($leafcolumns) leaf columns total"


if(($nullcolumns) -and ($sqlversion -lt 11))
{
    Write-Output "Leaf record contains null columns"
}

Write-Output "$($variablecolumns) total columns are variable-length"
    
# Calculate null bitmap size
# If version is >= 2012 or null columns exist, add null bitmap - else don't add
if(($sqlversion -ge 11) -or ($nullcolumns -eq $true))
{
    $nullbitmap = [Math]::Floor(2 + (($leafcolumns + 7) / 8))

    Write-Output "Using null bitmap of $($nullbitmap) bytes"
}

# Calculate variable-length overhead size
if($variablecolumns -gt 0)
{
    $variableoverheadsize = 2 + ($variablecolumns * 2) 

    Write-Output "Using variable-length column overhead size of $($variableoverheadsize) bytes"
}

# Calculate total index size
$indexsize = $keylength + $rowlocatorlength + $nullbitmap + $variableoverheadsize + 1

Write-Output "Index row size is $($keylength) + $($rowlocatorlength) (locator) + $($nullbitmap) (null bitmap) + $($variableoverheadsize) (variable) + 1 (header) = $($indexsize) bytes"

# Calculate leaf rows per page - adding 2 bytes to indexsize for slot array entry 
$leafrowsperpage = [Math]::Floor(8096 / ($indexsize + 2))

Write-Output "Leaf rows per page is $leafrowsperpage"

# Use full pages if not specifying fillfactor
if(!$Fillfactor)
{
    $leafpages = [Math]::Ceiling($rowcount / $leafrowsperpage)

    Write-Output "Leaf pages required is $($leafpages)"
}
else
{
    Write-Output "Using fillfactor of $($Fillfactor)"

    $freerowsperpage = [Math]::Floor(8096 * ((100 - $Fillfactor) / 100) / ($indexsize + 2))

    $leafpages = [Math]::Ceiling($rowcount / ($leafrowsperpage - $freerowsperpage))

    Write-Output "Leaf pages required is $($leafpages)"
}


###### Final result ######

$estimate = $leafpages * 8192

$estimateMB = [Math]::Round($estimate / 1024 / 1024)

Write-Output "Estimated nonclustered index size: $($estimateMB) MB"

}


Getting SQL Services Information with Powershell

Hopefully you already know everything about your SQL estate, including what services are installed and what’s running them, either because it’s so small you just know, or, preferably, you have some kind of CMDB. But what if you don’t? Powershell comes to the rescue, of course.

This post details a script to capture basic information – service name, account, start mode and status – about the database engine, Agent and any SSRS/SSAS/SSRS installs. It requires remote WMI connectivity and, for SSIS, SMB access to enabled administrative shares on the drives where the service is installed.

(Note – if all you’re after is the Database Engine and/or SQL Agent info, and you’re running SQL 2008 R2 SP1 or higher, no need to carry on reading – just use the sys.dm_server_services DMV instead, it’s easy.)

To begin we need some kind of data source containing both the hostnames and instance names (MSSQLSERVER if default instance) of the servers in the estate – as we’ll be connecting to the hostname but making checks using the instance name. Either stored in a table;

$instancesquery = "SELECT Hostname, InstanceName
                    FROM dbo.Instances"

$instances = Invoke-Sqlcmd -ServerInstance SQL2017A -Database 'TestDB' -Query $instancesquery

or from another source, say, a csv file – in this case an example of a single instance, which I’ll use as an example source for the rest of the post;

$instances = Import-Csv -Path "C:\temp\servers.txt"

Then we can loop over the servers and use the Get-WmiObject Win32_Service cmdlet. For the database engine, Agent, SSRS and SSAS this is straightforward – we’re filtering on the service name looking for a reference to the instance, then disregarding any CEIP services and pulling out a few pieces of information. For example, a snippet of the script checking for a SSAS install;

$SSAS = Get-WmiObject Win32_Service -ComputerName $instance.Hostname | Where-Object -Property DisplayName -EQ "SQL Server Analysis Services ($($instance.InstanceName))" | Where-Object -Property DisplayName -NotLike "*CEIP*" | Select-Object DisplayName, StartName, State, StartMode
Write-Output $SSAS

SSIS is a bit trickier. You may have noticed that, unlike for the Database Engine, SSRS or SSAS, the instance name is not part of the service name;

So we can’t just filter on the service name to check which instance the service is installed as part of. Instead we need to find the MsDtsSrvr.ini.xml file associated with the service (by using the service PathName), open it up as XML (this is where the requirement for SMB and administrative share access arises) and look at the DtsServiceConfiguration.TopLevelFolders.Folder.ServerName element;

$ConfigXMLPath = ($SSIS.PathName.Substring(0,$SSIS.PathName.IndexOf('MsDtsSrvr.exe')) + 'MsDtsSrvr.ini.xml') -replace '"', ''

$ConfigXMLPath = "\\$($instance.Hostname)\" + $SSIS.PathName.Substring(1,1) + '$\' + $ConfigXMLPath.Substring(3)

[xml]$ConfigXML = Get-Content -Path $ConfigXMLPath

if($ConfigXML.DtsServiceConfiguration.TopLevelFolders.Folder.ServerName -like "*$($instance.InstanceName)*")
{
    Write-Output $SSIS
}
elseif(($ConfigXML.DtsServiceConfiguration.TopLevelFolders.Folder.ServerName -EQ ".") -and ($instance.InstanceName -eq 'MSSQLSERVER'))
{
    Write-Output $SSIS
}

An example output from the whole script, ran on a single server;

This shows I have the database engine and agent running from MSAs, and two extra services installed – SSAS running as a local service and SSIS running as an MSA, all set to auto-start and only SSIS not currently running.

The entire skeleton script is below (github link), using the CSV file example for retrieving host/instance names as a base and simply writing the output to console – it’s easily modifiable to change the source and/or save the output to a file or table.

<#       
                
$instancesquery = "SELECT Hostname, InstanceName       
                
                   FROM dbo.Instances"       
                
       
                
$instances = Invoke-Sqlcmd -ServerInstance SQL2017A -Database 'TestDB' -Query $instancesquery       
                
#>       
      
$instances = Import-Csv -Path "C:\temp\servers.txt"       
                          
foreach ($instance in $instances)                     
{       
    Write-Output "Connecting to $($instance.Hostname)\$($instance.InstanceName).."       
                         
    try       
    {               
        $test = Get-WmiObject Win32_Service -ComputerName $instance.Hostname -ErrorAction Stop                 
    }       
    catch       
    {       
        Write-Output "Error connecting remotely to WMI"       
                
        continue       
    }       
                  
    # Database Engine                
    $DatabaseEngine = Get-WmiObject Win32_Service -ComputerName $instance.Hostname | Where-Object -Property DisplayName -EQ "SQL Server ($($instance.InstanceName))" | Select-Object DisplayName, StartName, State, Startmode       

    Write-Output $DatabaseEngine       
                

    # SQL Agent               
    $SQLAgent = Get-WmiObject Win32_Service -ComputerName $instance.Hostname | Where-Object -Property DisplayName -EQ "SQL Server Agent ($($instance.InstanceName))" | Select-Object DisplayName, StartName, State, Startmode       

    Write-Output $SQLAgent       
                  
    # SSAS       
    $SSAS = Get-WmiObject Win32_Service -ComputerName $instance.Hostname | Where-Object -Property DisplayName -EQ "SQL Server Analysis Services ($($instance.InstanceName))" | Where-Object -Property DisplayName -NotLike "*CEIP*" | Select-Object DisplayName, StartName, State, StartMode       

    Write-Output $SSAS       

    # SSRS       
    $SSRS = Get-WmiObject Win32_Service -ComputerName $instance.Hostname | Where-Object -Property DisplayName -EQ "SQL Server Reporting Services ($($instance.InstanceName))" | Where-Object -Property DisplayName -NotLike "*CEIP*" | Select-Object DisplayName, StartName, State, StartMode       
                
    Write-Output $SSRS       

    #SSIS       
    $SSISinstances = Get-WmiObject Win32_Service -ComputerName $instance.Hostname | Where-Object -Property DisplayName -Like "SQL Server Integration Services*" | Where-Object -Property DisplayName -NotLike "*CEIP*" | Select-Object DisplayName, PathName, StartName, State, StartMode       
                

    try       
    {       
        foreach($SSIS in $SSISinstances)       
        {          
            $ConfigXMLPath = ($SSIS.PathName.Substring(0,$SSIS.PathName.IndexOf('MsDtsSrvr.exe')) + 'MsDtsSrvr.ini.xml') -replace '"', ''       

            $ConfigXMLPath = "\\$($instance.Hostname)\" + $SSIS.PathName.Substring(1,1) + '$\' + $ConfigXMLPath.Substring(3)       

            [xml]$ConfigXML = Get-Content -Path $ConfigXMLPath              

            if ($ConfigXML.DtsServiceConfiguration.TopLevelFolders.Folder.ServerName -like "*$($instance.InstanceName)*")       
            {       
                Write-Output ($SSIS | Select-Object DisplayName, StartName, State, StartMode)       
            }       
            elseif (($ConfigXML.DtsServiceConfiguration.TopLevelFolders.Folder.ServerName -EQ ".") -and ($instance.InstanceName -eq 'MSSQLSERVER'))       
            {       
                Write-Output ($SSIS | Select-Object DisplayName, StartName, State, StartMode)       
            }       
        }       
    }       
    catch       
    {       
        Write-Output "SSIS Error: " + $error[0]       
    }       
}

Changing SQL Server Login Auditing setting with T-SQL/Powershell

The login auditing setting on a SQL Server instance controls the auditing of logins – either all, successful only, failed only or none. It’s set via SSMS on the Server properties dialog;

and is responsible for these types of message in the log;

You might want to change this for several reasons – perhaps you have strict auditing requirements so want everything logged, or perhaps you only care about failures – especially if you have a noisy application that floods the log with successful logins.

It’s straightforward enough to change in SSMS – though note that a service restart is required for changes to take effect – but what if you want to change this setting on a bunch of servers? Fortunately, it can be programmatically read/changed using the (undocumented) xp_instance_regread and xp_instance_regwrite extended stored procedures, reading from/writing to the Windows registry value AuditLevel (specifically, the value in the correct key for the instance the proc is executed from) – that the setting in SSMS actually represents;

Illustration purposes only – we don’t need to go into the Registry manually for this.

This key maps to the following values;

  • 0 – None
  • 1 – Successful logins only
  • 2 – Failed logins only
  • 3 – All logins only

To retrieve the value, we can use xp_instance_regread ;

DECLARE @result INT
EXEC xp_instance_regread N'HKEY_LOCAL_MACHINE', N'Software\Microsoft\MSSQLServer\MSSQLServer', N'AuditLevel', @result OUTPUT
SELECT @result AS 'AuditLevel'

To set it, we use xp_instance_regwrite. An example of setting it to 2 (Failed logins only);

EXEC xp_instance_regwrite N'HKEY_LOCAL_MACHINE', N'Software\Microsoft\MSSQLServer\MSSQLServer', N'AuditLevel', REG_DWORD, 2

So by calling this procedure we can script out a read/change to the setting to multiple instances at once using Powershell. (Yep, we could directly modify the registry with Powershell and skip the call, but doing it this way benefits from the wrapping of the registry modification in the SQL extended proc, and thus the correct key for the instance being automatically used thanks to the ‘instance’ versions of the reg read/write procs vs the standard xp_regread/regwrite)

Retrieving the key is a straightforward iteration over instances. In this example I’ve populated an $instances variable with an array of instance names, but this can be substituted with reading from a text file or database;

$regread = "DECLARE @result INT
            EXEC xp_instance_regread N'HKEY_LOCAL_MACHINE', N'Software\Microsoft\MSSQLServer\MSSQLServer', N'AuditLevel', @result OUTPUT
            SELECT @result AS 'AuditLevel'"

$instances = @('SQL1', 'SQL2', 'SQL3')

foreach($instance in $instances)
{
    try
    {          
        $flag = 99
        $flag = (Invoke-Sqlcmd -ServerInstance $instance -Query $regread -ConnectionTimeout 3 -QueryTimeout 3 -ErrorAction Stop).AuditLevel
       
        Write-Host "$($instance): $($flag)"
     }
     catch
     {
         Write-Host "$($instance): Error"
         Write-Host $error[0]
     }
}

Setting the key is also a straightforward iteration. In this example I’m also setting the value to ‘2’ (Failed logins only);

$regwrite = "EXEC xp_instance_regwrite N'HKEY_LOCAL_MACHINE', 
                N'Software\Microsoft\MSSQLServer\MSSQLServer', 
                N'AuditLevel', REG_DWORD, 2"

$instances = @('SQL1', 'SQL2', 'SQL3')

foreach($instance in $instances)
{
    try
    {          
        Invoke-Sqlcmd -ServerInstance $instance -Query $regwrite -ConnectionTimeout 3 -QueryTimeout 3 -ErrorAction Stop
        Write-Host "$($instance.ConnectionString): Success"
    }
    catch
    {
        Write-Host "$($instance): Error"
        Write-Host $error[0]
    }
}

After modification, the first script can be re-ran to confirm the modifications – and don’t forget a service restart is required to kick the setting into action.

Disclaimer – the registry-editing procedures used here are undocumented, and editing the registry is generally best avoided – any such code should be tested thoroughly before use in production.

Automating SSISDB Migration 4/4 – Copying Object Parameter Changes with Powershell

Last in this four-part series on automating a non-wizard SSIS migration (Part one, two and three).

To recap, previous scripts covered exporting both MSDB and SSISDB projects and then – after manual upgrade/deployment- copying environments and their references. The final piece of the puzzle is to copy object parameter values that have been manually overriden – where a value is shown in bold in SSMS after clicking Configure on a project/package and the ‘Edit Value’ has some manually-set value;

I wrote a function Copy-SSISObjectParameters to do this. It runs at Project level, so takes a Project name along with source/target servers and Folder name as parameters. As in the last post’s script for copying environments, I’m using the inbuilt SSISDB procedure [catalog].[set_object_parameter_value] to wrap the process.

Because of the way Powershell handles passing boolean values, I had to do some plumbing involving creating and passing a BIT variable in the SQL batch (the proc will accept a numeric 1 or 0 but will essentially corrupt the parameter making it uneditable in the GUI), otherwise it’s quite straightforward, and works for both Project and Package level ‘overrides’. The -WhatIf switch outputs the SQL statements it would normally run without the switch.

Example – Copy-SSISObjectParameters -SourceServer SQLSSIS2014 -TargetServer SQLSSIS2017 -FolderName DailyETL -ProjectName LoadDailySales

Unfortunately the Code Syntax Block plugin isn’t displaying the full code nicely below and it would be an awful lot of manual editing to fix, especially inappropriate for a blog post series on automation, but it’s working as normal on github – Copy-SSISObjectParameters

And that’s probably it for my Powershell-SSIS repo for now, pending further migration work that might need something adding, and pending the fate of SSIS in the face of ADF, for that matter!

function Copy-SSISObjectParameters
 {
 param
 (
     [Parameter(position=0, mandatory=$true)][string]$SourceServer,
     [Parameter(position=1, mandatory=$true)][string]$TargetServer,
     [Parameter(position=2, mandatory=$true)][string]$FolderName,
     [Parameter(position=3, mandatory=$true)][string]$ProjectName,
     [Parameter(position=4, mandatory=$false)][switch]$WhatIf
 )
 <#
 .SYNOPSIS
 Copies object parameter overrides from a SSIS project on a source instance to a target instance.
 .DESCRIPTION
 Copies object parameter overrides - that is, 'Edited' values on Configuration dialog - from a SSIS project 
 on a source instance to a target instance. This includes both project and package-level overrides,
 but does not include environment references, which are copied as part of the Copy-SSISEnvironments function.
 .PARAMETER SourceServer
 Specifies the source SQL instance name
 .PARAMETER TargetServer
 Specifies the target SQL instance name
 .PARAMETER FolderName
 Specifies the SSISDB folder the project is in. Case sensitive.
 .PARAMETER ProjectName
 Specifies the SSIS project (including packages) to copy the object parameter overrides from and to. Case sensitive.
 .PARAMETER WhatIf
 Outputs generated SQL statements only - does not execute them or make any other changes.
 .OUTPUTS
 No direct outputs from function - updates target server SSISDB object parameters
 .EXAMPLE
 PS> Copy-SSISObjectParameters -SourceServer SQLSSIS2014 -TargetServer SQLSSIS2017 -FolderName DailyETL -ProjectName LoadDailySales
 Sets project/package parameter overrides in SSIS project DailyETL/LoadDailySales on server SQLSSIS2017 to the same as the project on SQLSSIS2014
 >
 Import-Module SqlServer
 Check that folders and projects exist on both servers
 $checkexistsquery = "SELECT 1 FROM [catalog].[folders] f
                             INNER JOIN [catalog].[projects] p
                                 ON f.folder_id = p.folder_id
                             WHERE f.[name] = '$($FolderName)'
                                 AND p.[name] = '$($ProjectName)'"
 try
 {
     $check = Invoke-Sqlcmd -ServerInstance $SourceServer -Database SSISDB -Query $checkexistsquery -ConnectionTimeout 5 -QueryTimeout 5 -ErrorAction Stop
 }
 catch
 {
     Write-Output "Error connecting to source server."
     Write-Output $error[0]
     return
 }
 if(!$check)
 {
     Write-Output "Error: Folder or project doesn't exist on source server."
     return
 }
 try
 {
     $check = Invoke-Sqlcmd -ServerInstance $TargetServer -Database SSISDB -Query $checkexistsquery -ConnectionTimeout 5 -QueryTimeout 5 -ErrorAction Stop
 }
 catch
 {
     Write-Output "Error connecting to target server."
     Write-Output $error[0]
     return
 }
 if(!$check)
 {
     Write-Output "Error: Folder or project doesn't exist on target server."
     return
 }
 Get manually overridden parameter values (value_type V)
 $getoverridevaluesquery = "SELECT op.object_type, op.object_name, op.parameter_name, op.data_type, op.default_value
                             FROM [catalog].[object_parameters] op
                             INNER JOIN [catalog].[projects] p
                                 ON op.project_id = p.project_id
                             INNER JOIN [catalog].[folders] f
                                 ON p.folder_id = f.folder_id
                             WHERE f.[name] = '$($FolderName)'
                             AND p.[name] = '$($ProjectName)'
                             AND op.value_type = 'V'
                             AND op.value_set = 1"
 $overridevalues = Invoke-Sqlcmd -ServerInstance $SourceServer -Database SSISDB -Query $getoverridevaluesquery -ConnectionTimeout 3 -QueryTimeout 5 -ErrorAction Stop
 foreach($overridevalue in $overridevalues)
 {
     if($overridevalue.data_type -eq 'String')
     {
         if($overridevalue.object_type -eq 20) # Project parameter
         {
             $updateparameterquery = "EXEC [catalog].[set_object_parameter_value]
                                                                         @object_type = $($overridevalue.object_type),
                                                                         @folder_name = '$($FolderName)',
                                                                         @project_name = '$($ProjectName)',
                                                                         @parameter_name = '$($overridevalue.parameter_name)',
                                                                         @parameter_value = N'$($overridevalue.default_value)',
                                                                         @value_type = 'V'"
         }
         elseif($overridevalue.object_type -eq 30) # Package parameter
         {
             $updateparameterquery = "EXEC [catalog].[set_object_parameter_value]
                                                                         @object_type = $($overridevalue.object_type),
                                                                         @folder_name = '$($FolderName)',
                                                                         @project_name = '$($ProjectName)',
                                                                         @parameter_name = '$($overridevalue.parameter_name)',
                                                                         @parameter_value = N'$($overridevalue.default_value)',
                                                                         @object_name = '$($overridevalue.object_name)',
                                                                         @value_type = 'V'"
         }
     }
     elseif($overridevalue.data_type -eq 'Boolean')
     {
         if($overridevalue.default_value -eq 'True')
         {
             $bool_value = 1
         }
         else
         {
             $bool_value = 0
         }
     if($overridevalue.object_type -eq 20) # Project parameter     {         $updateparameterquery = "DECLARE @var BIT;                                  SET @var = $($bool_value);                                  EXEC [catalog].[set_object_parameter_value]                                                                     @object_type = $($overridevalue.object_type),                                                                     @folder_name = '$($FolderName)',                                                                     @project_name = '$($ProjectName)',                                                                     @parameter_name = '$($overridevalue.parameter_name)',                                                                     @parameter_value = @var,                                                                     @value_type = 'V'"     }     elseif($overridevalue.object_type -eq 30) # Package parameter     {         $updateparameterquery = "DECLARE @var BIT;                                  SET @var = $($bool_value);                                  EXEC [catalog].[set_object_parameter_value]                                                                     @object_type = $($overridevalue.object_type),                                                                     @folder_name = '$($FolderName)',                                                                     @project_name = '$($ProjectName)',                                                                     @parameter_name = '$($overridevalue.parameter_name)',                                                                     @parameter_value = @var,                                                                     @object_name = '$($overridevalue.object_name)',                                                                     @value_type = 'V'"     } } else # Integer or other number {     if($overridevalue.object_type -eq 20) # Project parameter     {         $updateparameterquery = "EXEC [catalog].[set_object_parameter_value]                                                                     @object_type = $($overridevalue.object_type),                                                                     @folder_name = '$($FolderName)',                                                                     @project_name = '$($ProjectName)',                                                                     @parameter_name = '$($overridevalue.parameter_name)',                                                                     @parameter_value = $($overridevalue.default_value),                                                                     @value_type = 'V'"     }     elseif($overridevalue.object_type -eq 30) # Package parameter     {         $updateparameterquery = "EXEC [catalog].[set_object_parameter_value]                                                                     @object_type = $($overridevalue.object_type),                                                                     @folder_name = '$($FolderName)',                                                                     @project_name = '$($ProjectName)',                                                                     @parameter_name = '$($overridevalue.parameter_name)',                                                                     @parameter_value = $($overridevalue.default_value),                                                                     @object_name = '$($overridevalue.object_name)',                                                                     @value_type = 'V'"      } } if($WhatIf) {     $updateparameterquery } else {     try     {         Invoke-Sqlcmd -ServerInstance $TargetServer -Database SSISDB -Query $updateparameterquery -ConnectionTimeout 5 -QueryTimeout 5 -ErrorAction Stop         Write-Output "Updated parameter $($overridevalue.parameter_name)"     }     catch     {         Write-Output "Error updating parameter $($overridevalue.parameter_name)"         Write-Output $updateparameterquery         Write-Output $error[0]     } }
 }
 }

Automating SSISDB Migration 3/4 – Copying SSIS Environments with Powershell

Part 3 of a 4-part series on automating an SSISDB migration without using the SSISDB Upgrade Wizard. Parts one and two covered exporting MSDB and SSISDB projects, after which upgrading then deploying from Visual Studio is neccessary. This post assumes this is done and the next task is to copy the environments over, as they exist outside of SSIS projects and are thus not carried with them.

To automate this we have to do a few different things;

  • Copy the environments
  • Copy environment variables
  • Copy environment references (between environment to project)
  • Copy environment-object parameter links

I created the Copy-SSISEnvironments function shown below to perform these steps. It works at folder level, taking a source/target server and foldername. Though it’s possible to directly update the internal schema tables with the required values, I’m using the built-in catalog stored procedures which wrap and sanity check the required code for safety, namely;

  • [catalog].[create_environment]
  • [catalog].[create_environment_variable]
  • [catalog].[create_environment_reference]
  • [catalog].[set_object_parameter_value]

The function supports ‘relative’ references (that is projects referencing an Environment in the same Folder), string, boolean and numeric datatypes, de and re-encrypting encrypted strings, and both project and package-level object references. It doesn not support copying ‘absolute’ references (projects referencing an Environment in a different folder) or decrypting non-string datatypes as I had no need for that in our environment. The -WhatIf switch will simply output the SQL statements it would otherwise execute, and is recommended to run before use to check the output.

Example – Copy-SSISEnvironments -SourceServer SQLSSIS2014 -TargetServer SQLSSIS2017 -FolderName MySSISFolder

Github link to the Powershell-SSIS repo I’ve added this to.

function Copy-SSISEnvironments
{
param
(
    [Parameter(position=0, mandatory=$true)][string]$SourceServer,
    [Parameter(position=1, mandatory=$true)][string]$TargetServer,
    [Parameter(position=2, mandatory=$true)][string]$FolderName,
    [Parameter(position=3, mandatory=$false)][switch]$WhatIf
)

<#
.SYNOPSIS
Copies environments and references from one SSISDB folder to the same folder on another server

.DESCRIPTION
Copies environments - including variables, project references and object-variable links - from a source SSISDB folder to the same folder on a target server.
Works with string, numeric, boolean and encrypted string variables and relative project references.
Does not copy absolute references.

.PARAMETER SourceServer
Specifies the source SQL instance name

.PARAMETER TargetServer
Specifies the target SQL instance name

.PARAMETER FolderName
Specifies the SSISDB folder to copy the environment from and to. Case sensitive.

.PARAMETER WhatIf
Outputs generated SQL statements only - does not execute them or make any other changes.

.OUTPUTS
No direct outputs from function - updates target server SSISDB folder

.EXAMPLE
PS> Copy-SSISEnvironments -SourceServer SQLSSIS2014 -TargetServer SQLSSIS2017 -FolderName DailyETL

Copies environment data from SSISDB folder 'DailyETL' on server SQLSSIS2014 to server SQLSSIS2017
#>

Import-Module SqlServer

### Check that folder exists on both servers
$checkexistsquery = "SELECT 1 FROM [catalog].[folders] f
                     WHERE f.[name] = '$($FolderName)'"

try
{
    $check = Invoke-Sqlcmd -ServerInstance $SourceServer -Database SSISDB -Query $checkexistsquery -ConnectionTimeout 5 -QueryTimeout 5 -ErrorAction Stop
}
catch
{
    Write-Output "Error connecting to source server."
    Write-Output $error[0]
    return
}


if(!$check)
{
    Write-Output "Error: Folder $($FolderName) doesn't exist on source server."
    return
}

try
{
    $check = Invoke-Sqlcmd -ServerInstance $TargetServer -Database SSISDB -Query $checkexistsquery -ConnectionTimeout 5 -QueryTimeout 5 -ErrorAction Stop
}
catch
{
    Write-Output "Error connecting to target server."
    Write-Output $error[0]
    return
}

if(!$check)
{
    Write-Output "Error: Folder $($FolderName) doesn't exist on target server."
    return
}



$source_folder_id = 0
$target_folder_id = 0

$GetFolderIDQuery = "SELECT folder_id
                    FROM [catalog].folders
                    WHERE [name] = '$($FolderName)'"

# Get folder_id of source and target folders
$source_folder_id = (Invoke-Sqlcmd -ServerInstance $SourceServer -Database SSISDB -Query $GetFolderIDQuery -ConnectionTimeout 5 -QueryTimeout 5 -ErrorAction Stop).folder_id
$target_folder_id = (Invoke-Sqlcmd -ServerInstance $TargetServer -Database SSISDB -Query $GetFolderIDQuery -ConnectionTimeout 5 -QueryTimeout 5 -ErrorAction Stop).folder_id

$GetEnvironmentQuery = "SELECT environment_id, [name], [description]
                            FROM [catalog].environments
                            WHERE folder_id = '$($source_folder_id)'"

# Get environments from the source folder
$envs = (Invoke-Sqlcmd -ServerInstance $SourceServer -Database SSISDB -Query $GetEnvironmentQuery -ConnectionTimeout 5 -QueryTimeout 5 -ErrorAction Stop)


# Get environment references 
$GetEnvironmentRefsQuery = "SELECT p.project_id, p.[name] AS 'ProjectName', er.reference_type, er.environment_name
                            FROM [catalog].projects p
                            INNER JOIN [catalog].environment_references er
	                            ON p.project_id = er.project_id
                            WHERE p.folder_id = $($source_folder_id)"

try
{
    $env_refs = Invoke-Sqlcmd -ServerInstance $SourceServer -Database SSISDB -Query $GetEnvironmentRefsQuery -ConnectionTimeout 5 -QueryTimeout 5 -ErrorAction Stop
}
catch
{
    Write-Output "Error retrieving environment references"
    $GetEnvironmentRefsQuery
    Write-Output $error[0]
}

 
foreach($env in $envs)
{
    # Create environment on target server
    $CreateNewEnvironmentQuery = "EXEC [SSISDB].[catalog].[create_environment] @folder_name = '$($FolderName)', @environment_name = '$($env.name)', @environment_description = '$($env.description)'"

    if($WhatIf)
    {
        Write-Output $CreateNewEnvironmentQuery
    }
    else
    {
        try
        {
            Invoke-Sqlcmd -ServerInstance $TargetServer -Database SSISDB -Query $CreateNewEnvironmentQuery -ConnectionTimeout 5 -QueryTimeout 5 -ErrorAction Stop
            Write-Output "Created environment $($env.name)"
        }
        catch
        {
            Write-Output "Error creating environment"
            Write-Output $CreateNewEnvironmentQuery
            Write-Output $error[0]

            return
        }
    }

    # Get environment variables
    $GetEnvironmentVarsQuery = "SELECT variable_id, [name], sensitive, [type], [description], [value]
                                FROM [catalog].environment_variables
                                WHERE environment_id = $($env.environment_id)"

    $env_vars = (Invoke-Sqlcmd -ServerInstance $SourceServer -Database SSISDB -Query $GetEnvironmentVarsQuery -ConnectionTimeout 5 -QueryTimeout 5 -ErrorAction Stop)

    # Loop over environment variables
    foreach($env_var in $env_vars)
    {
        if($env_var.type -eq 'String')
        {
            # If variable is sensitive string, pull the encrypted value from [internal] table and decrypt it
            if($env_var.sensitive -eq 1)
            {
                $getencryptedvaluequery = "SELECT [internal].[get_value_by_data_type](DECRYPTBYKEYAUTOCERT(CERT_ID(N'MS_Cert_Env_' + CONVERT(NVARCHAR(20), [environment_id])), NULL, [sensitive_value]), [type]) AS DecryptedValue
                                            FROM [SSISDB].[internal].[environment_variables]
                                            WHERE variable_id = $($env_var.variable_id)"

                try
                {
                    $decryptedvalue = (Invoke-Sqlcmd -ServerInstance $SourceServer -Database SSISDB -Query $getencryptedvaluequery -ConnectionTimeout 3 -QueryTimeout 5 -ErrorAction Stop).DecryptedValue

                    $CreateEnvironmentVarQuery = "EXEC [SSISDB].[catalog].[create_environment_variable] @environment_name = '$($env.name)',
	                                                                                                    @folder_name = '$($FolderName)',
	                                                                                                    @variable_name = '$($env_var.name)',
	                                                                                                    @Sensitive = 1,
	                                                                                                    @data_type = '$($env_var.type)',
	                                                                                                    @description = '$($env_var.description)',
	                                                                                                    @value = N'$($decryptedvalue)'"
                }
                catch
                {
                    Write-Output "Failed to retrieve encrypted variable value"
                    $getencryptedvaluequery
                    Write-Output $error[0]
                }

            } 
            else
            {
                $CreateEnvironmentVarQuery = "EXEC [SSISDB].[catalog].[create_environment_variable] @environment_name = '$($env.name)',
	                                                                                                @folder_name = '$($FolderName)',
	                                                                                                @variable_name = '$($env_var.name)',
	                                                                                                @Sensitive = 0,
	                                                                                                @data_type = '$($env_var.type)',
	                                                                                                @description = '$($env_var.description)',
	                                                                                                @value = N'$($env_var.value)'"
            }
        }
        elseif($env_var.type -eq 'Boolean')
        {
            if($env_var.value -eq 'True')
            {
                $bool_value = 1
            }
            else
            {
                $bool_value = 0
            }

            $CreateEnvironmentVarQuery = "EXEC SSISDB.[catalog].[create_environment_variable] @environment_name = '$($env.name)',
	                                                                                            @folder_name = '$($FolderName)',
	                                                                                            @variable_name = '$($env_var.name)',
	                                                                                            @Sensitive = $([int]$env_var.sensitive),
	                                                                                            @data_type = '$($env_var.type)',
	                                                                                            @description = '$($env_var.description)',
	                                                                                            @value = $($bool_value)"

        }
        else
        {
            $CreateEnvironmentVarQuery = "EXEC SSISDB.[catalog].[create_environment_variable] @environment_name = '$($env.name)',
	                                                                                            @folder_name = '$($FolderName)',
	                                                                                            @variable_name = '$($env_var.name)',
	                                                                                            @Sensitive = $([int]$env_var.sensitive),
	                                                                                            @data_type = '$($env_var.type)',
	                                                                                            @description = '$($env_var.description)',
	                                                                                            @value = $($env_var.value)"
        }
        

        if($WhatIf)
        {
            Write-Output $CreateEnvironmentVarQuery
        }
        else
        {
            try
            {
                Invoke-Sqlcmd -ServerInstance $TargetServer -Database SSISDB -Query $CreateEnvironmentVarQuery -QueryTimeout 5 -ConnectionTimeout 5 -ErrorAction Stop
                Write-Output "Created variable $($env_var.name)"
            }
            catch
            {
                Write-Output "Error creating environment variable."
                Write-Output $CreateEnvironmentVarQuery
                Write-Output $error[0]
            }
        }
    }

    # Check if a reference exists for this environment, then for projects in target folder
    foreach($env_ref in $env_refs)
    {
        if($env_ref.reference_type -eq 'A')
        {
            Write-Warning "Warning - Absolute reference detected. Add manually. Project name $($env_ref.ProjectName)"
        }
        elseif($env_ref.environment_name -eq $env.name)
        {
            $CheckProjectExistsQuery = "SELECT 1 AS 'Result' WHERE EXISTS (SELECT [name]
                                                            FROM [catalog].projects
                                                            WHERE folder_id = $($target_folder_id)
                                                            AND name = '$($env_ref.ProjectName)')"

            #### Add reference for $env_ref.ProjectName

            try
            {
                $exists = (Invoke-SqlCmd -ServerInstance $TargetServer -Database SSISDB -Query $CheckProjectExistsQuery -ConnectionTimeout 5 -QueryTimeout 5 -ErrorAction Stop).Result

                if($exists -eq 1)
                {
                    # Add environment reference for this project
                    $CreateEnvironmentRefQuery = "EXEC [SSISDB].[catalog].[create_environment_reference] @environment_name = '$($env.name)',
														    @project_name = '$($env_ref.ProjectName)',
														    @folder_name = '$($FolderName)',
														    @reference_type = R,
                                                            @reference_id = NULL"
                    
                    if($WhatIf)
                    {
                        Write-Output $CreateEnvironmentRefQuery
                    }
                    else
                    {
                        try
                        {
                            Invoke-Sqlcmd -ServerInstance $TargetServer -Database SSISDB -Query $CreateEnvironmentRefQuery -ConnectionTimeout 5 -QueryTimeout 5 -ErrorAction Stop
                            Write-Output "Created reference between $($env_ref.ProjectName) and $($env.name)"


                            
                            #### Set object parameters to use environment variables where linked

                            $getobjectparamsquery = "SELECT object_type, [object_name], parameter_name, referenced_variable_name
                                        FROM catalog.object_parameters
                                        WHERE project_id = $($env_ref.project_id)
                                        AND value_type = 'R'"

                            $object_params = Invoke-Sqlcmd -ServerInstance $SourceServer -Database SSISDB -Query $getobjectparamsquery -ConnectionTimeout 3 -QueryTimeout 5 -ErrorAction Stop

                            foreach($object_param in $object_params)
                            {
                                if($object_param.object_type -eq 20) # Project parameter
                                {
                                    $setobjectparamquery = "EXEC [catalog].[set_object_parameter_value]
                                                                    @object_type = $($object_param.object_type),
                                                                    @folder_name = '$($FolderName)',
                                                                    @project_name = '$($env_ref.ProjectName)',
                                                                    @parameter_name = '$($object_param.parameter_name)',
                                                                    @parameter_value = '$($object_param.referenced_variable_name)',
                                                                    @value_type = 'R'"    
                                }
                                elseif($object_param.object_type -eq 30) # Package parameter
                                {
                                    $setobjectparamquery = "EXEC [catalog].[set_object_parameter_value]
                                            @object_type = $($object_param.object_type),
                                            @folder_name = '$($FolderName)',
                                            @project_name = '$($env_ref.ProjectName)',
                                            @parameter_name = '$($object_param.parameter_name)',
                                            @parameter_value = '$($object_param.referenced_variable_name)',
                                            @object_name = '$($object_param.object_name)',
                                            @value_type = 'R'"  
                                }

                                try
                                {
                                    Invoke-Sqlcmd -ServerInstance $TargetServer -Database SSISDB -Query $setobjectparamquery -ConnectionTimeout 3 -QueryTimeout 5 -ErrorAction Stop
                                    Write-Output "Linked parameter $($object_param.parameter_name) to env var $($object_param.referenced_variable_name)"
                                }
                                catch
                                {
                                    Write-Output "Error linking parameter."
                                    $setobjectparamquery
                                    Write-Output $error[0]
                                }

                            }

                        }
                        catch
                        {
                            Write-Output "Error creating environment reference."
                            $CreateEnvironmentRefQuery
                            Write-Output $error[0]
                        }
                    }
                }
            }
            catch
            {
                Write-Output $CheckProjectExistsQuery
                Write-Output $error[0]
            }


            if($WhatIf)
            {
                #### Set object parameters to use environment variables where linked

                $getobjectparamsquery = "SELECT object_type, [object_name], parameter_name, referenced_variable_name
                                        FROM catalog.object_parameters
                                        WHERE project_id = $($env_ref.project_id)
                                        AND value_type = 'R'"

                $object_params = Invoke-Sqlcmd -ServerInstance $SourceServer -Database SSISDB -Query $getobjectparamsquery -ConnectionTimeout 3 -QueryTimeout 5 -ErrorAction Stop

                foreach($object_param in $object_params)
                {
                    if($object_param.object_type -eq 20)
                    {
                        $setobjectparamquery = "EXEC [catalog].[set_object_parameter_value]
                                                        @object_type = $($object_param.object_type),
                                                        @folder_name = '$($FolderName)',
                                                        @project_name = '$($env_ref.ProjectName)',
                                                        @parameter_name = '$($object_param.parameter_name)',
                                                        @parameter_value = '$($object_param.referenced_variable_name)',
                                                        @value_type = 'R'"    
                    }
                    elseif($object_param.object_type -eq 30)
                    {
                        $setobjectparamquery = "EXEC [catalog].[set_object_parameter_value]
                                @object_type = $($object_param.object_type),
                                @folder_name = '$($FolderName)',
                                @project_name = '$($env_ref.ProjectName)',
                                @parameter_name = '$($object_param.parameter_name)',
                                @parameter_value = '$($object_param.referenced_variable_name)',
                                @object_name = '$($object_param.object_name)',
                                @value_type = 'R'"  
                    }

                    $setobjectparamquery
                }
            }

        }

    }

}

}