Skip to content

Instantly share code, notes, and snippets.

@Brar
Last active October 10, 2023 12:29
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save Brar/5ffeb958765e2b6fd33af54ccb33cef8 to your computer and use it in GitHub Desktop.
Save Brar/5ffeb958765e2b6fd33af54ccb33cef8 to your computer and use it in GitHub Desktop.
A PowerShell script to apply database migrations from files stored in the same directoy.
#Requires -Version 7.3
[CmdletBinding()]
Param(
[Version]$TargetVersion = [Version]::new([int]::MaxValue,[int]::MaxValue,[int]::MaxValue,[int]::MaxValue),
[string]$Server = 'localhost',
[ushort]$Port = 5432,
[string]$UserName = [Environment]::UserName,
[Parameter(Mandatory)][string]$Database,
[string]$ApplicationUser = $Database,
[string]$AdminUser = "$Database.Admin",
[string]$MaintenanceDb
)
begin{
try
{
$connectionStringBuilder = [Npgsql.NpgsqlConnectionStringBuilder]::new()
$connectionStringBuilder.Host = $Server
$connectionStringBuilder.Port = $Port
$connectionStringBuilder.Username = $UserName
$dataSource = [Npgsql.NpgsqlDataSource]::Create($connectionStringBuilder.ToString())
}
catch
{
$npgsqlAssemblyFilePath = "$PSScriptRoot/Npgsql.*/lib/net7.0/Npgsql.dll"
$npgsqlAssemblyFile = Resolve-Path -Path $npgsqlAssemblyFilePath
if ($null -eq $npgsqlAssemblyFile -or -not (Test-Path -Path $npgsqlAssemblyFile))
{
Write-Debug "Installing Npgsql"
Install-Package -Name Npgsql -MinimumVersion 7.0.6 -ProviderName NuGet -Scope CurrentUser -SkipDependencies -Destination $PSScriptRoot -Force > $null
$npgsqlAssemblyFile = Resolve-Path -Path $npgsqlAssemblyFilePath
}
$loggingAbstractionsAssemblyFilePath = "$PSScriptRoot/Microsoft.Extensions.Logging.Abstractions.*/lib/net7.0/Microsoft.Extensions.Logging.Abstractions.dll"
$loggingAbstractionsAssemblyFile = Resolve-Path -Path $loggingAbstractionsAssemblyFilePath
if ($null -eq $loggingAbstractionsAssemblyFile -or -not (Test-Path -Path $loggingAbstractionsAssemblyFile))
{
Write-Debug "Installing Microsoft.Extensions.Logging.Abstractions"
Install-Package -Name Microsoft.Extensions.Logging.Abstractions -MinimumVersion 7.0.1 -ProviderName NuGet -Scope CurrentUser -SkipDependencies -Destination $PSScriptRoot -Force > $null
$loggingAbstractionsAssemblyFile = Resolve-Path -Path $loggingAbstractionsAssemblyFilePath
}
$onAssemblyResolve = [System.ResolveEventHandler] {
param($sender, $e)
Write-Debug "Resolving assembly '$($e.Name)'"
if ($e.Name -like 'Microsoft.Extensions.Logging.Abstractions, *') {
$assembly = [System.Reflection.Assembly]::LoadFrom($loggingAbstractionsAssemblyFile)
return $assembly
}
throw "Failed to resolve assembly '$($e.Name)'"
}
[System.AppDomain]::CurrentDomain.add_AssemblyResolve($onAssemblyResolve)
[System.Reflection.Assembly]::LoadFrom($npgsqlAssemblyFile) > $null
$connectionStringBuilder = [Npgsql.NpgsqlConnectionStringBuilder]::new()
$connectionStringBuilder.Host = $Server
$connectionStringBuilder.Port = $Port
$connectionStringBuilder.Username = $UserName
$dataSource = [Npgsql.NpgsqlDataSource]::Create($connectionStringBuilder.ToString())
[System.AppDomain]::CurrentDomain.remove_AssemblyResolve($onAssemblyResolve)
}
try
{
# Try to connect to find out whether we need a password or SSPI
$dataSource.OpenConnection().Dispose()
}
catch [Npgsql.NpgsqlException]
{
if ($_.Exception.Message.StartsWith('No password has been provided but the backend requires one'))
{
$dataSource.Dispose()
$connectionStringBuilder.Password = (Read-Host -Prompt "Enter password" -MaskInput).ToString()
$dataSource = [Npgsql.NpgsqlDataSource]::Create($connectionStringBuilder.ToString())
}
elseif ($_.Exception.Message.Contains('GSS/SSPI authentication but IntegratedSecurity not enabled'))
{
$dataSource.Dispose()
$connectionStringBuilder.IntegratedSecurity = $true
$dataSource = [Npgsql.NpgsqlDataSource]::Create($connectionStringBuilder.ToString())
}
else
{
throw
}
}
$existsCommand = $dataSource.CreateCommand('SELECT EXISTS(SELECT FROM pg_database WHERE datname = $1)')
$dbParam = [Npgsql.NpgsqlParameter]::new()
$dbParam.NpgsqlDbType = [NpgsqlTypes.NpgsqlDbType]::Text
$dbParam.Value = $Database
$existsCommand.Parameters.Add($dbParam) > $null
$dbExists = $existsCommand.ExecuteScalar()
$cb = [Npgsql.NpgsqlCommandBuilder]::new()
if (-not $dbExists)
{
$batch = $dataSource.CreateBatch()
$batch.EnableErrorBarriers = $true
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"CREATE ROLE $($cb.QuoteIdentifier($AdminUser)) WITH NOLOGIN NOINHERIT"))
# Set a password via ALTER ROLE "TheRole" WITH PASSWORD 'whatever' VALID UNTIL 'infinity';
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"CREATE ROLE $($cb.QuoteIdentifier($ApplicationUser)) WITH LOGIN NOINHERIT"))
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"CREATE DATABASE $($cb.QuoteIdentifier($Database)) WITH OWNER $($cb.QuoteIdentifier($AdminUser))"))
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"SET ROLE $($cb.QuoteIdentifier($AdminUser))"))
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"REVOKE CONNECT, TEMPORARY ON DATABASE $($cb.QuoteIdentifier($Database)) FROM PUBLIC"))
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"GRANT CONNECT ON DATABASE $($cb.QuoteIdentifier($Database)) TO $($cb.QuoteIdentifier($ApplicationUser))"))
$batch.ExecuteNonQuery() > $null
$dataSource.Dispose()
$connectionStringBuilder.Database = $Database
$dataSource = [Npgsql.NpgsqlDataSource]::Create($connectionStringBuilder.ToString())
$batch = $dataSource.CreateBatch()
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"SET ROLE $($cb.QuoteIdentifier($AdminUser))"))
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"CREATE TABLE __schema_version (version text NOT NULL, timestamp timestamp with time zone DEFAULT transaction_timestamp(), CONSTRAINT pk___schema_version PRIMARY KEY(version, timestamp));"))
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"INSERT INTO __schema_version (version) VALUES ('0.0')"))
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"ALTER DEFAULT PRIVILEGES REVOKE EXECUTE ON ROUTINES FROM PUBLIC"))
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"ALTER DEFAULT PRIVILEGES REVOKE USAGE ON TYPES FROM PUBLIC"))
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT EXECUTE ON ROUTINES TO $($cb.QuoteIdentifier($ApplicationUser))"))
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT USAGE ON TYPES TO $($cb.QuoteIdentifier($ApplicationUser))"))
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT SELECT ON TABLES TO $($cb.QuoteIdentifier($ApplicationUser))"))
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT INSERT ON TABLES TO $($cb.QuoteIdentifier($ApplicationUser))"))
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT UPDATE ON TABLES TO $($cb.QuoteIdentifier($ApplicationUser))"))
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT DELETE ON TABLES TO $($cb.QuoteIdentifier($ApplicationUser))"))
$batch.ExecuteNonQuery() > $null
$schemaVersion = [Version]::new(0,0)
}
else
{
$dataSource.Dispose()
$connectionStringBuilder.Database = $Database
$dataSource = [Npgsql.NpgsqlDataSource]::Create($connectionStringBuilder.ToString())
$batch = $dataSource.CreateBatch()
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"SET ROLE $($cb.QuoteIdentifier($AdminUser))"))
$batch.BatchCommands.Add([Npgsql.NpgsqlBatchCommand]::new(
"SELECT version FROM __schema_version ORDER BY timestamp DESC LIMIT 1"))
$schemaVersion = [Version]::new(
$batch.ExecuteScalar())
}
if ($schemaVersion -lt $TargetVersion)
{
Write-Information "Upgrading database schema from version $schemaVersion"
$conn = $dataSource.OpenConnection()
try
{
$newVersion = $schemaVersion
$tran = $conn.BeginTransaction()
Get-ChildItem -Path .\DbSchema -File -Filter '*up*.sql' |
Select-Object `
FullName, `
@{
l = 'Version'
e = {
if ($_.Name -match '\d\d?\.\d\d?((\.\d\d?)?\.\d\d?)?') {
[Version]::new($Matches[0])
} else { $null }
}
},`
@{
l = 'Index'
e = {
if ($_.Name -match '\d\d?\.\d\d?((\.\d\d?)?\.\d\d?)?[^.]*(\d+)') {
[ulong]::Parse($Matches[3])
} else { $null }
}
} |
Where-Object Version -GT $schemaVersion |
Sort-Object -Property Version,Index |
ForEach-Object {
$script:newVersion = $_.Version
Write-Verbose "Applying commands from $($_.FullName)"
$c = $conn.CreateCommand()
$c.CommandText = "SET ROLE $($cb.QuoteIdentifier($AdminUser)); " +
(Get-Content -LiteralPath $_.FullName -Raw -Encoding utf8)
Write-Debug ($c.CommandText -replace '(\r|\n|\t)+', ' ' -replace ' +', ' ')
$c.ExecuteNonQuery() > $null
}
$c = $conn.CreateCommand()
$c.CommandText = 'INSERT INTO __schema_version (version) VALUES ($1)'
$p = [Npgsql.NpgsqlParameter]::new()
$p.NpgsqlDbType = [NpgsqlTypes.NpgsqlDbType]::Text
$p.Value = $newVersion.ToString()
$c.Parameters.Add($p) > $null
$c.ExecuteNonQuery() > $null
$tran.Commit()
Write-Information "New version is $newVersion"
}
catch { if ($null -ne $tran) { $tran.Rollback() }; throw }
finally { if ($null -ne $conn) { $conn.Dispose() } }
}
elseif ($schemaVersion -gt $TargetVersion)
{
Write-Information "Downgrading database schema from version $schemaVersion"
$conn = $dataSource.OpenConnection()
try
{
$newVersion = $schemaVersion
$tran = $conn.BeginTransaction()
Get-ChildItem -Path .\DbSchema -File -Filter '*down*.sql' |
Select-Object `
FullName, `
@{
l = 'Version'
e = {
if ($_.Name -match '\d\d?\.\d\d?((\.\d\d?)?\.\d\d?)?') {
[Version]::new($Matches[0])
} else { $null }
}
},`
@{
l = 'Index'
e = {
if ($_.Name -match '\d\d?\.\d\d?((\.\d\d?)?\.\d\d?)?[^.]*(\d+)') {
[ulong]::Parse($Matches[3])
} else { $null }
}
} |
Where-Object Version -GE $TargetVersion |
Sort-Object -Property Version,Index -Descending |
ForEach-Object {
$script:newVersion = $_.Version
Write-Verbose "Applying commands from $($_.FullName)"
$c = $conn.CreateCommand()
$c.CommandText = "SET ROLE $($cb.QuoteIdentifier($AdminUser)); " +
(Get-Content -LiteralPath $_.FullName -Raw -Encoding utf8)
Write-Debug ($c.CommandText -replace '(\r|\n|\t)+', ' ' -replace ' +', ' ')
$c.ExecuteNonQuery() > $null
}
$c = $conn.CreateCommand()
$c.CommandText = 'INSERT INTO __schema_version (version) VALUES ($1)'
$p = [Npgsql.NpgsqlParameter]::new()
$p.NpgsqlDbType = [NpgsqlTypes.NpgsqlDbType]::Text
$p.Value = $TargetVersion.ToString()
$c.Parameters.Add($p) > $null
$c.ExecuteNonQuery() > $null
$tran.Commit()
Write-Information "New version is $TargetVersion"
}
catch { if ($null -ne $tran) { $tran.Rollback() }; throw }
finally { if ($null -ne $conn) { $conn.Dispose() } }
}
else
{
Write-Information "The database schema version is equal to the target version ($schemaVersion). No changes were applied."
}
}
clean { if ($null -ne $dataSource) { $dataSource.Dispose() } }
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment