Invoke-SqliteBulkCopy.ps1
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 |
function Invoke-SQLiteBulkCopy { <# .SYNOPSIS Use a SQLite transaction to quickly insert data .DESCRIPTION Use a SQLite transaction to quickly insert data. If we run into any errors, we roll back the transaction. The data source is not limited to SQL Server; any data source can be used, as long as the data can be loaded to a DataTable instance or read with a IDataReader instance. .PARAMETER DataSource Path to one ore more SQLite data sources to query .PARAMETER Force If specified, skip the confirm prompt .PARAMETER NotifyAfter The number of rows to fire the notification event after transferring. 0 means don't notify. Notifications hit the verbose stream (use -verbose to see them) .PARAMETER QueryTimeout Specifies the number of seconds before the queries time out. .PARAMETER SQLiteConnection An existing SQLiteConnection to use. We do not close this connection upon completed query. .PARAMETER ConflictClause The conflict clause to use in case a conflict occurs during insert. Valid values: Rollback, Abort, Fail, Ignore, Replace See https://www.sqlite.org/lang_conflict.html for more details .EXAMPLE # #Create a table Invoke-SqliteQuery -DataSource "C:\Names.SQLite" -Query "CREATE TABLE NAMES ( fullname VARCHAR(20) PRIMARY KEY, surname TEXT, givenname TEXT, BirthDate DATETIME)" #Build up some fake data to bulk insert, convert it to a datatable $DataTable = 1..10000 | %{ [pscustomobject]@{ fullname = "Name $_" surname = "Name" givenname = "$_" BirthDate = (Get-Date).Adddays(-$_) } } | Out-DataTable #Copy the data in within a single transaction (SQLite is faster this way) Invoke-SQLiteBulkCopy -DataTable $DataTable -DataSource $Database -Table Names -NotifyAfter 1000 -ConflictClause Ignore -Verbose .INPUTS System.Data.DataTable .OUTPUTS None Produces no output .NOTES This function borrows from: Chad Miller's Write-Datatable jbs534's Invoke-SQLBulkCopy Mike Shepard's Invoke-BulkCopy from SQLPSX .LINK https://github.com/RamblingCookieMonster/Invoke-SQLiteQuery .LINK New-SQLiteConnection .LINK Invoke-SQLiteBulkCopy .LINK Out-DataTable .FUNCTIONALITY SQL #> [cmdletBinding( DefaultParameterSetName = 'Datasource', SupportsShouldProcess = $true, ConfirmImpact = 'High' )] param( [parameter( Position = 0, Mandatory = $true, ValueFromPipeline = $false, ValueFromPipelineByPropertyName= $false)] [System.Data.DataTable] $DataTable, [Parameter( ParameterSetName='Datasource', Position=1, Mandatory=$true, ValueFromRemainingArguments=$false, HelpMessage='SQLite Data Source required...' )] [Alias('Path','File','FullName','Database')] [validatescript({ #This should match memory, or the parent path should exist if ( $_ -match ":MEMORY:" -or (Test-Path $_) ) { $True } else { Throw "Invalid datasource '$_'.`nThis must match :MEMORY:, or must exist" } })] [string] $DataSource, [Parameter( ParameterSetName = 'Connection', Position=1, Mandatory=$true, ValueFromPipeline=$false, ValueFromPipelineByPropertyName=$true, ValueFromRemainingArguments=$false )] [Alias( 'Connection', 'Conn' )] [System.Data.SQLite.SQLiteConnection] $SQLiteConnection, [parameter( Position=2, Mandatory = $true)] [string] $Table, [Parameter( Position=3, Mandatory=$false, ValueFromPipeline=$false, ValueFromPipelineByPropertyName=$false, ValueFromRemainingArguments=$false)] [ValidateSet("Rollback","Abort","Fail","Ignore","Replace")] [string] $ConflictClause, [int] $NotifyAfter = 0, [switch] $Force, [Int32] $QueryTimeout = 600 ) Write-Verbose "Running Invoke-SQLiteBulkCopy with ParameterSet '$($PSCmdlet.ParameterSetName)'." Function CleanUp { [cmdletbinding()] param($conn, $com, $BoundParams) #Only dispose of the connection if we created it if($BoundParams.Keys -notcontains 'SQLiteConnection') { $conn.Close() $conn.Dispose() Write-Verbose "Closed connection" } $com.Dispose() } function Get-ParameterName { [CmdletBinding()] Param( [Parameter(Mandatory = $true, ValueFromPipeline = $true)] [string[]]$InputObject, [Parameter(ValueFromPipelineByPropertyName = $true)] [string]$Regex = '(\W+)', [Parameter(ValueFromPipelineByPropertyName = $true)] [string]$Separator = '_' ) Process{ $InputObject | ForEach-Object { if($_ -match $Regex){ $Groups = @($_ -split $Regex | Where-Object {$_}) for($i = 0; $i -lt $Groups.Count; $i++){ if($Groups[$i] -match $Regex){ $Groups[$i] = ($Groups[$i].ToCharArray() | ForEach-Object {[string][int]$_}) -join $Separator } } $Groups -join $Separator } else { $_ } } } } function New-SqliteBulkQuery { [CmdletBinding()] Param( [Parameter(Mandatory = $true, ValueFromPipelineByPropertyName = $true)] [string]$Table, [Parameter(Mandatory = $true, ValueFromPipelineByPropertyName = $true)] [string[]]$Columns, [Parameter(Mandatory = $true, ValueFromPipelineByPropertyName = $true)] [string[]]$Parameters, [Parameter(ValueFromPipelineByPropertyName = $true)] [string]$ConflictClause = '' ) Begin{ $EscapeSingleQuote = "'","''" $Delimeter = ", " $QueryTemplate = "INSERT{0} INTO {1} ({2}) VALUES ({3})" } Process{ $fmtConflictClause = if($ConflictClause){" OR $ConflictClause"} $fmtTable = "'{0}'" -f ($Table -replace $EscapeSingleQuote) $fmtColumns = ($Columns | ForEach-Object { "'{0}'" -f ($_ -replace $EscapeSingleQuote) }) -join $Delimeter $fmtParameters = ($Parameters | ForEach-Object { "@$_"}) -join $Delimeter $QueryTemplate -f $fmtConflictClause, $fmtTable, $fmtColumns, $fmtParameters } } #Connections if($PSBoundParameters.Keys -notcontains "SQLiteConnection") { if ($DataSource -match ':MEMORY:') { $Database = $DataSource } else { $Database = $ExecutionContext.SessionState.Path.GetUnresolvedProviderPathFromPSPath($DataSource) } $ConnectionString = "Data Source={0}" -f $Database $SQLiteConnection = New-Object System.Data.SQLite.SQLiteConnection -ArgumentList $ConnectionString $SQLiteConnection.ParseViaFramework = $true #Allow UNC paths, thanks to Ray Alex! } Write-Debug "ConnectionString $($SQLiteConnection.ConnectionString)" Try { if($SQLiteConnection.State -notlike "Open") { $SQLiteConnection.Open() } $Command = $SQLiteConnection.CreateCommand() $CommandTimeout = $QueryTimeout $Transaction = $SQLiteConnection.BeginTransaction() } Catch { Throw $_ } write-verbose "DATATABLE IS $($DataTable.gettype().fullname) with value $($Datatable | out-string)" $RowCount = $Datatable.Rows.Count Write-Verbose "Processing datatable with $RowCount rows" if ($Force -or $PSCmdlet.ShouldProcess("$($DataTable.Rows.Count) rows, with BoundParameters $($PSBoundParameters | Out-String)", "SQL Bulk Copy")) { #Get column info... [array]$Columns = $DataTable.Columns | Select-Object -ExpandProperty ColumnName $ColumnTypeHash = @{} $ColumnToParamHash = @{} $Index = 0 foreach($Col in $DataTable.Columns) { $Type = Switch -regex ($Col.DataType.FullName) { # I figure we create a hashtable, can act upon expected data when doing insert # Might be a better way to handle this... '^(|\ASystem\.)Boolean$' {"BOOLEAN"} #I know they're fake... '^(|\ASystem\.)Byte\[\]' {"BLOB"} '^(|\ASystem\.)Byte$' {"BLOB"} '^(|\ASystem\.)Datetime$' {"DATETIME"} '^(|\ASystem\.)Decimal$' {"REAL"} '^(|\ASystem\.)Double$' {"REAL"} '^(|\ASystem\.)Guid$' {"TEXT"} '^(|\ASystem\.)Int16$' {"INTEGER"} '^(|\ASystem\.)Int32$' {"INTEGER"} '^(|\ASystem\.)Int64$' {"INTEGER"} '^(|\ASystem\.)UInt16$' {"INTEGER"} '^(|\ASystem\.)UInt32$' {"INTEGER"} '^(|\ASystem\.)UInt64$' {"INTEGER"} '^(|\ASystem\.)Single$' {"REAL"} '^(|\ASystem\.)String$' {"TEXT"} Default {"BLOB"} #Let SQLite handle the rest... } #We ref columns by their index, so add that... $ColumnTypeHash.Add($Index,$Type) # Parameter names can only be alphanumeric: https://www.sqlite.org/c3ref/bind_blob.html # So we have to replace all non-alphanumeric chars in column name to use it as parameter later. # This builds hashtable to correlate column name with parameter name. $ColumnToParamHash.Add($Col.ColumnName, (Get-ParameterName $Col.ColumnName)) $Index++ } #Build up the query if ($PSBoundParameters.ContainsKey('ConflictClause')) { $Command.CommandText = New-SqliteBulkQuery -Table $Table -Columns $ColumnToParamHash.Keys -Parameters $ColumnToParamHash.Values -ConflictClause $ConflictClause } else { $Command.CommandText = New-SqliteBulkQuery -Table $Table -Columns $ColumnToParamHash.Keys -Parameters $ColumnToParamHash.Values } foreach ($Column in $Columns) { $param = New-Object System.Data.SQLite.SqLiteParameter $ColumnToParamHash[$Column] [void]$Command.Parameters.Add($param) } for ($RowNumber = 0; $RowNumber -lt $RowCount; $RowNumber++) { $row = $Datatable.Rows[$RowNumber] for($col = 0; $col -lt $Columns.count; $col++) { # Depending on the type of thid column, quote it # For dates, convert it to a string SQLite will recognize switch ($ColumnTypeHash[$col]) { "BOOLEAN" { $Command.Parameters[$ColumnToParamHash[$Columns[$col]]].Value = [int][boolean]$row[$col] } "DATETIME" { Try { $Command.Parameters[$ColumnToParamHash[$Columns[$col]]].Value = $row[$col].ToString("yyyy-MM-dd HH:mm:ss") } Catch { $Command.Parameters[$ColumnToParamHash[$Columns[$col]]].Value = $row[$col] } } Default { $Command.Parameters[$ColumnToParamHash[$Columns[$col]]].Value = $row[$col] } } } #We have the query, execute! Try { [void]$Command.ExecuteNonQuery() } Catch { #Minimal testing for this rollback... Write-Verbose "Rolling back due to error:`n$_" $Transaction.Rollback() #Clean up and throw an error CleanUp -conn $SQLiteConnection -com $Command -BoundParams $PSBoundParameters Throw "Rolled back due to error:`n$_" } if($NotifyAfter -gt 0 -and $($RowNumber % $NotifyAfter) -eq 0) { Write-Verbose "Processed $($RowNumber + 1) records" } } } #Commit the transaction and clean up the connection $Transaction.Commit() CleanUp -conn $SQLiteConnection -com $Command -BoundParams $PSBoundParameters } |