PDC_REPORT_CreazioneDB/script/estrae_table.ps1
2025-06-26 18:47:11 +02:00

176 lines
7.7 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 e assembly necessari
Add-Type -AssemblyName System.Web
. "$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 "transito\tabelle"
# 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 {
# Carica l'assembly System.Data
Add-Type -AssemblyName System.Data
# Query per estrarre la definizione delle tabelle
$query = @"
WITH TableColumns AS (
SELECT DISTINCT
t.object_id,
(
SELECT STUFF((
SELECT ',' + CHAR(13) + CHAR(10) +
CHAR(9) + '[' + c2.name + '] ' +
CASE
WHEN t2.name IN ('char', 'varchar', 'nchar', 'nvarchar')
THEN t2.name + '(' +
CASE
WHEN c2.max_length = -1 THEN 'MAX'
WHEN t2.name LIKE 'n%' THEN CAST(c2.max_length/2 AS VARCHAR)
ELSE CAST(c2.max_length AS VARCHAR)
END + ')'
WHEN t2.name IN ('decimal', 'numeric')
THEN t2.name + '(' + CAST(c2.[precision] AS VARCHAR) + ',' + CAST(c2.[scale] AS VARCHAR) + ')'
ELSE t2.name
END +
CASE WHEN c2.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
FROM sys.columns c2
INNER JOIN sys.types t2 ON c2.user_type_id = t2.user_type_id
LEFT JOIN sys.identity_columns ic ON ic.object_id = c2.object_id AND ic.column_id = c2.column_id
LEFT JOIN sys.default_constraints dc ON dc.parent_object_id = c2.object_id AND dc.parent_column_id = c2.column_id
WHERE c2.object_id = t.object_id
ORDER BY c2.column_id
FOR XML PATH('')
), 1, 2, '')
) as ColumnDefinitions
FROM sys.tables t
),
TablePrimaryKeys AS (
SELECT DISTINCT
i.object_id,
(
SELECT 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 +
' (' + STUFF((
SELECT ',' + QUOTENAME(c2.name)
FROM sys.index_columns ic2
INNER JOIN sys.columns c2 ON c2.object_id = ic2.object_id AND c2.column_id = ic2.column_id
WHERE ic2.object_id = i.object_id AND ic2.index_id = i.index_id
ORDER BY ic2.key_ordinal
FOR XML PATH('')
), 1, 1, '') + ')'
) as PkDefinition
FROM sys.indexes i
WHERE i.is_primary_key = 1
)
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
try {
# Crea la connessione e esegui la query
$connectionString = "Server=$($env:dbHostInput);Database=$($env:dbNameInput);User Id=$($env:dbUserInput);Password=$($env:dbPasswordInput);TrustServerCertificate=True;Connection Timeout=30"
Write-Host "Tentativo di connessione a $($env:dbHostInput)..."
$connection = New-Object System.Data.SqlClient.SqlConnection($connectionString)
$command = New-Object System.Data.SqlClient.SqlCommand($query, $connection)
$adapter = New-Object System.Data.SqlClient.SqlDataAdapter($command)
$dataset = New-Object System.Data.DataSet
$adapter.Fill($dataset) | Out-Null
$tables = $dataset.Tables[0]
}
catch {
Write-Error "Errore di connessione al database: $($_.Exception.Message)"
Write-Host "Dettagli connessione:"
Write-Host "Server: $($env:dbHostInput)"
Write-Host "Database: $($env:dbNameInput)"
Write-Host "Utente: $($env:dbUserInput)"
throw
}
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
# Pulisci e formatta il contenuto
$content = $definition.Trim()
# Rimuovi caratteri speciali e di escape HTML
$content = $content -replace '
|#x0D;|\r|\n', "`r`n"
$content = [System.Web.HttpUtility]::HtmlDecode($content)
$content += "`r`nGO"
# Rimuovi righe vuote multiple e normalizza i line endings
$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
[System.IO.File]::WriteAllText($fileName, $content, [System.Text.UTF8Encoding]::new($true))
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
}