PDC_REPORT_CreazioneDB/script/estrae_table.ps1
2025-06-09 19:17:49 +02:00

150 lines
6.4 KiB
PowerShell
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

# Importa configurazione
. "$PSScriptRoot\conf.ps1"
$scriptName = $MyInvocation.MyCommand.Name
$logFile = Join-Path $env:logDir "${scriptName}.log"
"start" | Out-File -FilePath $logFile
# Imposta il percorso di output nella cartella sql
$OutputPath = Join-Path $env:workdir "sql\tables"
# Verifica che la directory di output esista, altrimenti la crea
if (-not (Test-Path -Path $OutputPath)) {
New-Item -ItemType Directory -Path $OutputPath | Out-Null
}
try {
# Importa il modulo SqlServer se non è già caricato
if (-not (Get-Module -Name SqlServer)) {
Import-Module SqlServer
}
# Query per estrarre la definizione delle tabelle
$query = @"
WITH TableColumns AS (
SELECT
t.object_id,
STRING_AGG(
CONCAT(
CHAR(9), '[', c.name, '] ',
CASE
WHEN t2.name IN ('char', 'varchar', 'nchar', 'nvarchar')
THEN t2.name + '(' +
CASE
WHEN c.max_length = -1 THEN 'MAX'
WHEN t2.name LIKE 'n%' THEN CAST(c.max_length/2 AS VARCHAR)
ELSE CAST(c.max_length AS VARCHAR)
END + ')'
WHEN t2.name IN ('decimal', 'numeric')
THEN t2.name + '(' + CAST(c.[precision] AS VARCHAR) + ',' + CAST(c.[scale] AS VARCHAR) + ')'
ELSE t2.name
END,
CASE WHEN c.is_nullable = 0 THEN ' NOT NULL' ELSE ' NULL' END,
CASE WHEN ic.is_identity = 1 THEN ' IDENTITY(' + CAST(IDENT_SEED(OBJECT_SCHEMA_NAME(t.object_id) + '.' + OBJECT_NAME(t.object_id)) AS VARCHAR) + ',' + CAST(IDENT_INCR(OBJECT_SCHEMA_NAME(t.object_id) + '.' + OBJECT_NAME(t.object_id)) AS VARCHAR) + ')' ELSE '' END,
CASE WHEN dc.definition IS NOT NULL THEN ' DEFAULT ' + dc.definition ELSE '' END
),
',' + CHAR(13) + CHAR(10)
) WITHIN GROUP (ORDER BY c.column_id) as ColumnDefinitions
FROM sys.tables t
INNER JOIN sys.columns c ON c.object_id = t.object_id
INNER JOIN sys.types t2 ON c.user_type_id = t2.user_type_id
LEFT JOIN sys.identity_columns ic ON ic.object_id = c.object_id AND ic.column_id = c.column_id
LEFT JOIN sys.default_constraints dc ON dc.parent_object_id = c.object_id AND dc.parent_column_id = c.column_id
GROUP BY t.object_id
),
TablePrimaryKeys AS (
SELECT
i.object_id,
CHAR(13) + CHAR(10) + 'ALTER TABLE [' + OBJECT_SCHEMA_NAME(i.object_id) + '].[' + OBJECT_NAME(i.object_id) + '] ADD CONSTRAINT [' + i.name + '] PRIMARY KEY ' +
CASE WHEN i.type = 1 THEN 'CLUSTERED' ELSE 'NONCLUSTERED' END +
' (' + STRING_AGG(QUOTENAME(c.name), ',') WITHIN GROUP (ORDER BY ic.key_ordinal) + ')' as PkDefinition
FROM sys.indexes i
INNER JOIN sys.index_columns ic ON ic.object_id = i.object_id AND ic.index_id = i.index_id
INNER JOIN sys.columns c ON c.object_id = ic.object_id AND c.column_id = ic.column_id
WHERE i.is_primary_key = 1
GROUP BY i.object_id, i.name, i.type
)
SELECT
s.name as SchemaName,
t.name as TableName,
CONCAT(
'CREATE TABLE [', s.name, '].[', t.name, '] (', CHAR(13), CHAR(10),
tc.ColumnDefinitions,
CHAR(13), CHAR(10), ')',
ISNULL(pk.PkDefinition, '')
) as TableDefinition
FROM sys.tables t
INNER JOIN sys.schemas s ON t.schema_id = s.schema_id
INNER JOIN TableColumns tc ON tc.object_id = t.object_id
LEFT JOIN TablePrimaryKeys pk ON pk.object_id = t.object_id
WHERE t.is_ms_shipped = 0
"@
# Esegui la query
Write-Host "Eseguo query su $env:dbHostInput..."
"Eseguo query su $env:dbHostInput..." | Out-File -FilePath $logFile -Append
$tables = Invoke-Sqlcmd -ServerInstance $env:dbHostInput -Database $env:dbName -Query $query -Username $env:dbUser -Password $env:dbPassword -MaxCharLength 1000000 -TrustServerCertificate
Write-Host "Trovate $($tables.Count) tabelle"
"Trovate $($tables.Count) tabelle" | Out-File -FilePath $logFile -Append
# Funzione per formattare il nome del file
function Format-FileName {
param([string]$name)
# Sostituisce caratteri non validi con underscore
$invalidChars = [IO.Path]::GetInvalidFileNameChars()
$invalidChars += '[', ']', ' ', '(', ')', '{', '}', '´', '`', '''', '"'
$result = $name
foreach ($char in $invalidChars) {
$result = $result.Replace($char, '_')
}
return $result
}
# Per ogni tabella trovata
Write-Host "Inizio elaborazione tabelle..."
"Inizio elaborazione tabelle..." | Out-File -FilePath $logFile -Append
foreach ($table in $tables) {
$schemaName = Format-FileName $table.SchemaName
$tableName = Format-FileName $table.TableName
$definition = $table.TableDefinition
# Crea il nome del file
$fileName = Join-Path $OutputPath "${schemaName}_${tableName}.sql"
Write-Host "Elaboro ${schemaName}.${tableName}..."
"Elaboro ${schemaName}.${tableName}..." | Out-File -FilePath $logFile -Append
# Formatta il contenuto
$content = @"
$($definition.Trim())
GO
"@
# Rimuovi righe vuote multiple
$lines = $content -split "`r`n" | Where-Object { -not [string]::IsNullOrWhiteSpace($_) }
$content = $lines -join "`r`n"
try {
# Scrivi il contenuto nel file con codifica UTF8 con BOM
$utf8WithBom = New-Object System.Text.UTF8Encoding($true)
[System.IO.File]::WriteAllText($fileName, $content, $utf8WithBom)
Write-Host "Creato file per tabella: ${schemaName}.${tableName}" -ForegroundColor Green
"Creato file per tabella: ${schemaName}.${tableName}" | Out-File -FilePath $logFile -Append
} catch {
$errorMessage = "ERRORE durante la scrittura del file per ${schemaName}.${tableName}: $($_.Exception.Message)"
Write-Host $errorMessage -ForegroundColor Red
$errorMessage | Out-File -FilePath $logFile -Append
}
}
Write-Host "`nEstrazione completata con successo!"
} catch {
Write-Error "Errore durante l'estrazione delle tabelle: $_"
exit 1
}