Skip to content

Instantly share code, notes, and snippets.

@nkavadias
Forked from cheynewallace/ExportSchema.ps1
Last active February 20, 2018 22:37
Show Gist options
  • Save nkavadias/44507500d428cea97932b101cf3f7cc7 to your computer and use it in GitHub Desktop.
Save nkavadias/44507500d428cea97932b101cf3f7cc7 to your computer and use it in GitHub Desktop.
Export MSSQL schema with PowerShell. This script will export your schema definitions for tables, stored procs, triggers, functions and views to .sql files
<#
.SYNOPSIS
Export schema for a database
.DESCRIPTION
This script will export your schema definitions for tables, stored procs, triggers, functions and views to .sql files
.PARAMETER ServerName
database server instance
.PARAMETER DatabaseName
You can specify a database name to only export single DB schema
.PARAMETER ScriptPath
directory where scripts will be dumped to. Relative paths are also ok
.PARAMETER RecursiveMode
Use this switch to export schema for ALL user databases on a servername
.EXAMPLE
Dump scripts for single database:
powershell ExportSchema.ps1 "SERVERNAME" "DATABASE" "C:\<YourOutputPath>"
.\ExportSchema.ps1 -ServerName Contososerver -DatabaseName Adventureworks -ScriptPath C:\export
.EXAMPLE
----
.NOTES
New features:
- created RecursiveMode to allow dumping all user databases on a server
- added commandline parameters, so can be called as a powershell commandlet
- changed logic to prevent creating of empty script files
- change logic to filter out encrypted functions/procedures, so no need to check for null script data
.LINK
https://gist.github.com/cheynewallace/9558179
#>
param(
[Parameter(Mandatory=$true)] [string][ValidateNotNullOrEmpty()] $ServerName
,[Parameter(Mandatory=$false)] [string][ValidateNotNullOrEmpty()] $DatabaseName
,[Parameter(Mandatory=$false)] [string][ValidateNotNullOrEmpty()] $ScriptPath = "."
,[Parameter(Mandatory=$false)] [switch] $RecursiveMode = $false
)
function GenerateDBScript([Microsoft.SqlServer.Management.SMO.Database] $database, [string]$scriptPath)
{
$scr = New-Object "Microsoft.SqlServer.Management.Smo.Scripter"
$deptype = New-Object "Microsoft.SqlServer.Management.Smo.DependencyType"
$scr.Server = $database.Parent
$literalpath = convert-path -Path $scriptPath
$options = New-Object "Microsoft.SqlServer.Management.SMO.ScriptingOptions"
$options.AllowSystemObjects = $false
$options.IncludeDatabaseContext = $true
$options.IncludeIfNotExists = $false
$options.ClusteredIndexes = $true
$options.Default = $true
$options.DriAll = $true
$options.Indexes = $true
$options.NonClusteredIndexes = $true
$options.IncludeHeaders = $false
$options.ToFileOnly = $true
$options.AppendToFile = $true
$options.ScriptDrops = $false
$options.Encoding = $Encoding
# Set options for SMO.Scripter
$scr.Options = $options
#=============
# Tables
#=============
$tables = $database.Tables | where {$_.IsSystemObject -eq $false}
if ( $tables.Count -gt 0 )
{
$options.FileName = Join-Path $literalpath "$($servername)_$($database.Name)_tables.sql"
New-Item $options.FileName -type file -force | Out-Null
Write-verbose "initalizing $($options.Filename)"
Foreach ($tb in $database.Tables)
{
If ($tb.IsSystemObject -eq $FALSE)
{
$smoObjects = New-Object Microsoft.SqlServer.Management.Smo.UrnCollection
$smoObjects.Add($tb.Urn)
$scr.Script($smoObjects)
}
}
}
#=============
# Views
#=============
$views = $database.Views | where {$_.IsSystemObject -eq $false}
if ( $($views).Count -gt 0 )
{
$options.FileName = Join-Path $literalpath "$($servername)_$($database.Name)_views.sql"
New-Item $options.FileName -type file -force | Out-Null
Write-verbose "initalizing $($options.Filename)"
Foreach ($view in $views)
{
$scr.Script($view)
}
}
#=============
# StoredProcedures
#=============
$StoredProcedures = $database.StoredProcedures | where {$_.IsSystemObject -eq $false -and $_.IsEncrypted -eq $false}
if ( $($StoredProcedures).Count -gt 0 )
{
$options.FileName = Join-Path $literalpath "$($servername)_$($database.Name)_stored_procs.sql"
New-Item $options.FileName -type file -force | Out-Null
Write-verbose "initalizing $($options.Filename)"
Foreach ($StoredProcedure in $StoredProcedures)
{
$scr.Script($StoredProcedure)
}
}
#=============
# Functions
#=============
$UserDefinedFunctions = $database.UserDefinedFunctions |where {$_.IsSystemObject -eq $false -and $_.IsEncrypted -eq $false}
if ( $($UserDefinedFunctions).Count -gt 0 )
{
$options.FileName = Join-Path $literalpath "$($servername)_$($database.Name)_functions.sql"
New-Item $options.FileName -type file -force | Out-Null
Write-verbose "initalizing $($options.Filename)"
foreach ($function in $UserDefinedFunctions)
{
$scr.Script($function)
}
}
#=============
# DBTriggers
#=============
$DBTriggers = $database.Triggers |where {$_.IsSystemObject -eq $false -and $_.IsEncrypted -eq $false}
if ( $($DBTriggers).Count -gt 0 )
{
$options.FileName = Join-Path $literalpath "$($servername)_$($database.Name)_db_triggers.sql"
New-Item $options.FileName -type file -force | Out-Null
Write-verbose "initalizing $($options.Filename)"
foreach ($trigger in $database.triggers)
{
$scr.Script($trigger)
}
}
#=============
# Table Triggers
#=============
$options.FileName = Join-Path $literalpath "$($servername)_$($database.Name)_table_triggers.sql"
New-Item $options.FileName -type file -force | Out-Null
foreach ($tb in $database.Tables)
{
if($($tb.triggers).Count -gt 0)
{
foreach ($trigger in $tb.triggers)
{
$scr.Script($trigger)
}
}
}
}
#=============
# Execute
#=============
$VerbosePreference = "Continue"
$ErrorActionPreference = "Stop"
#$Encoding = [system.Text.Encoding]::UTF8
$Encoding = [system.Text.Encoding]::ASCII
Write-Verbose "Checking scriptPath"
if (-not $(Test-Path -Path $ScriptPath))
{
Write-Error -Exception ([System.IO.FileNotFoundException]::new("Unable to find path specified $ScriptPath")) -ErrorAction Stop
#exit -1
}
if ( $($RecursiveMode -eq $false) -and -not $DatabaseName)
{
Write-Error -Message "the DatabaseName parameter is missing and you are not running in RecursiveMode" -Category InvalidArgument -ErrorAction Stop
#exit -1
}
Write-Verbose "Checking servername connectivity"
#check connectivity to db server
$SqlConnection = New-Object System.Data.SqlClient.SqlConnection
$SqlConnection.ConnectionString = "Server = $Servername ; Database = tempdb; Integrated Security = True"
try {$SqlConnection.Open()}
catch
{
Write-Error -Exception $($_.Exception) -ErrorAction Stop
#exit -1
}
$SqlConnection.Close()
# ok to load SMO objects
[System.Reflection.Assembly]::LoadWithPartialName("Microsoft.SqlServer.SMO") | Out-Null
[System.Reflection.Assembly]::LoadWithPartialName("System.Data") | Out-Null
$srv = new-object "Microsoft.SqlServer.Management.SMO.Server" $serverName
$srv.SetDefaultInitFields([Microsoft.SqlServer.Management.SMO.View], "IsSystemObject")
if ($RecursiveMode -eq $true)
{
#recursive mode
#get list of databases
$databases = $srv.Databases | where {$_.IsSystemObject -eq $false -and $_.isAccessible -eq $true}
foreach ($d in $databases)
{ GenerateDBScript -Database $d -ScriptPath $ScriptPath }
}
else
{
$db = New-Object "Microsoft.SqlServer.Management.SMO.Database"
$db = $srv.Databases[$DatabaseName]
GenerateDBScript -Database $db -ScriptPath $ScriptPath }
Write-Verbose "Success!"
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment