├── LICENSE
├── Modules
    └── ReallySimpleDatabase
    │   ├── Binaries
    │       ├── System.Data.SQLite.dll
    │       ├── x64
    │       │   └── SQLite.Interop.dll
    │       └── x86
    │       │   └── SQLite.Interop.dll
    │   ├── Formats
    │       ├── database.ps1xml
    │       ├── field.ps1xml
    │       └── table.ps1xml
    │   ├── ReallySimpleDatabase.psd1
    │   ├── ReallySimpleDatabase.psm1
    │   ├── loadbinaries.ps1
    │   └── logic.ps1
└── README.md
/LICENSE:
--------------------------------------------------------------------------------
 1 | MIT License
 2 | 
 3 | Copyright (c) 2021 Dr. Tobias Weltner
 4 | 
 5 | Permission is hereby granted, free of charge, to any person obtaining a copy
 6 | of this software and associated documentation files (the "Software"), to deal
 7 | in the Software without restriction, including without limitation the rights
 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
 9 | copies of the Software, and to permit persons to whom the Software is
10 | furnished to do so, subject to the following conditions:
11 | 
12 | The above copyright notice and this permission notice shall be included in all
13 | copies or substantial portions of the Software.
14 | 
15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
21 | SOFTWARE.
22 | 
--------------------------------------------------------------------------------
/Modules/ReallySimpleDatabase/Binaries/System.Data.SQLite.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/TobiasPSP/ReallySimpleDatabase/b22519ce3fc00ed37507fe065b93eb1c67f15fec/Modules/ReallySimpleDatabase/Binaries/System.Data.SQLite.dll
--------------------------------------------------------------------------------
/Modules/ReallySimpleDatabase/Binaries/x64/SQLite.Interop.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/TobiasPSP/ReallySimpleDatabase/b22519ce3fc00ed37507fe065b93eb1c67f15fec/Modules/ReallySimpleDatabase/Binaries/x64/SQLite.Interop.dll
--------------------------------------------------------------------------------
/Modules/ReallySimpleDatabase/Binaries/x86/SQLite.Interop.dll:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/TobiasPSP/ReallySimpleDatabase/b22519ce3fc00ed37507fe065b93eb1c67f15fec/Modules/ReallySimpleDatabase/Binaries/x86/SQLite.Interop.dll
--------------------------------------------------------------------------------
/Modules/ReallySimpleDatabase/Formats/database.ps1xml:
--------------------------------------------------------------------------------
 1 | 
 2 | 
 3 |     
 4 |         
 5 |             Default
 6 |             
 7 |                 Database
 8 |             
 9 |             
10 |                 
11 |                     
12 |                         20
13 |                     
14 |                     
15 |                         20
16 |                     
17 |                     
18 |                         6
19 |                     
20 |                     
21 |                         6
22 |                         right
23 |                     
24 |                     
25 |                         6
26 |                     
27 |                     
28 |                         6
29 |                     
30 |                 
31 |                 
32 |                     
33 |                         
34 |                             
35 |                                 Path
36 |                             
37 |                             
38 |                                 Connection
39 |                             
40 |                             
41 |                                 IsOpen
42 |                             
43 |                             
44 |                                 QueryTimeout
45 |                             
46 |                             
47 |                                 LockDatabase
48 |                             
49 |                             
50 |                                 EnableUnsafePerformanceMode
51 |                             
52 |                         
53 |                     
54 |                 
55 |             
56 |         
57 |     
58 | 
--------------------------------------------------------------------------------
/Modules/ReallySimpleDatabase/Formats/field.ps1xml:
--------------------------------------------------------------------------------
 1 | 
 2 | 
 3 |     
 4 |         
 5 |             Default
 6 |             
 7 |                 Field
 8 |             
 9 |             
10 |                 
11 |                     
12 |                         10
13 |                     
14 |                     
15 |                         10
16 |                     
17 |                     
18 |                         12
19 |                     
20 |                     
21 |                         7
22 |                     
23 |                     
24 |                         4
25 |                         right
26 |                     
27 |                 
28 |                 
29 |                     
30 |                         
31 |                             
32 |                                 Name
33 |                             
34 |                             
35 |                                 Type
36 |                             
37 |                             
38 |                                 DefaultValue
39 |                             
40 |                             
41 |                                 NotNull
42 |                             
43 |                             
44 |                                 Id
45 |                             
46 |                         
47 |                     
48 |                 
49 |             
50 |         
51 |     
52 | 
--------------------------------------------------------------------------------
/Modules/ReallySimpleDatabase/Formats/table.ps1xml:
--------------------------------------------------------------------------------
 1 | 
 2 | 
 3 |     
 4 |         
 5 |             Default
 6 |             
 7 |                 Table
 8 |             
 9 |             
10 |                 
11 |                     
12 |                         10
13 |                     
14 |                     
15 |                         5
16 |                         right
17 |                     
18 |                     
19 |                         10
20 |                     
21 |                     
22 |                         10
23 |                     
24 |                     
25 |                         50
26 |                     
27 |                 
28 |                 
29 |                     
30 |                         
31 |                             
32 |                                 Name
33 |                             
34 |                             
35 |                                 Count
36 |                             
37 |                             
38 |                                 RowState
39 |                             
40 |                             
41 |                                 HasErrors
42 |                             
43 |                             
44 |                                 Definition
45 |                             
46 |                         
47 |                     
48 |                 
49 |             
50 |         
51 |     
52 | 
--------------------------------------------------------------------------------
/Modules/ReallySimpleDatabase/ReallySimpleDatabase.psd1:
--------------------------------------------------------------------------------
 1 | 
 2 | #
 3 | # Wrapper for SQLite file-based databases, comes with everything required including the SQLite engine
 4 | # Works for Windows PowerShell and PowerShell Core
 5 | # If you like the code, check out www.psconf.eu and make sure you come and join all fellow PowerShell Passionates!
 6 | # Use this code freely, MIT license for all PowerShell parts.
 7 | # The embedded SQLite database is free to use as well, license terms here: https://www.sqlite.org/copyright.html
 8 | #
 9 | 
10 | @{
11 | 
12 | # Module Loader File
13 | RootModule = 'ReallySimpleDatabase.psm1'
14 | 
15 | # Version Number
16 | ModuleVersion = '1.0'
17 | 
18 | # Unique Module ID
19 | GUID = '39538ca5-9ed9-4ee2-945e-393c246ac916'
20 | 
21 | # Module Author
22 | Author = 'Dr. Tobias Weltner'
23 | 
24 | # Company
25 | CompanyName = 'ISESteroids www.powertheshell.com'
26 | 
27 | # Copyright
28 | Copyright = '(c) 2019 Dr. Tobias Weltner. Wrapper around SQLite database. MIT license for all PowerShell code. SQLite is embedded in this code. SQLite license details: https://www.sqlite.org/copyright.html'
29 | 
30 | # Module Description
31 | Description = 'No-brainer SQLite database wrapper (comes with everything you need to start working with SQLite databases including the database engine. No dependencies. No prerequisites.)'
32 | 
33 | # Minimum PowerShell Version Required
34 | PowerShellVersion = ''
35 | 
36 | # Name of Required PowerShell Host
37 | PowerShellHostName = ''
38 | 
39 | # Minimum Host Version Required
40 | PowerShellHostVersion = ''
41 | 
42 | # Minimum .NET Framework-Version
43 | DotNetFrameworkVersion = ''
44 | 
45 | # Minimum CLR (Common Language Runtime) Version
46 | CLRVersion = ''
47 | 
48 | # Processor Architecture Required (X86, Amd64, IA64)
49 | ProcessorArchitecture = ''
50 | 
51 | # Required Modules (will load before this module loads)
52 | RequiredModules = @()
53 | 
54 | # Required Assemblies
55 | RequiredAssemblies = @()
56 | 
57 | # PowerShell Scripts (.ps1) that need to be executed before this module loads
58 | ScriptsToProcess = @()
59 | 
60 | # Type files (.ps1xml) that need to be loaded when this module loads
61 | TypesToProcess = @()
62 | 
63 | # Format files (.ps1xml) that need to be loaded when this module loads
64 | FormatsToProcess = @("Formats/table.ps1xml","Formats/field.ps1xml", "Formats/database.ps1xml")
65 | 
66 | # 
67 | NestedModules = @()
68 | 
69 | # List of exportable functions
70 | FunctionsToExport = '*'
71 | 
72 | # List of exportable cmdlets
73 | CmdletsToExport = '*'
74 | 
75 | # List of exportable variables
76 | VariablesToExport = '*'
77 | 
78 | # List of exportable aliases
79 | AliasesToExport = '*'
80 | 
81 | # List of all modules contained in this module
82 | ModuleList = @()
83 | 
84 | # List of all files contained in this module
85 | FileList = @()
86 | 
87 | # Private data that needs to be passed to this module
88 | PrivateData = ''
89 | 
90 | }
--------------------------------------------------------------------------------
/Modules/ReallySimpleDatabase/ReallySimpleDatabase.psm1:
--------------------------------------------------------------------------------
 1 | 
 2 | # load platform-specific sqlite binaries
 3 | & "$PSScriptRoot\loadbinaries.ps1"
 4 | 
 5 | # load logic (dot-sourced)
 6 | . "$PSScriptRoot\logic.ps1"
 7 | 
 8 | # declare public module members
 9 | Export-ModuleMember -Function Get-Database, Import-Database
10 | 
11 | # register argument completers
12 | 
13 | 
14 | Register-ArgumentCompleter -ParameterName TableName -CommandName Import-Database -ScriptBlock {
15 |   param
16 |   (
17 |     $CommandName,
18 |     $ParameterName,
19 |     $WordToComplete,
20 |     $CommandAst,
21 |     $params
22 |   )
23 | 
24 |   
25 |   if ($params.ContainsKey('Database'))
26 |   {
27 |     $db = $params['Database'] -as [Database]
28 |     if ($db -ne $null)
29 |     {
30 |       try 
31 |       {
32 |         $tables = $db.GetTables()
33 |         $tables.Keys -like "$WordToComplete*" |
34 |           ForEach-Object {
35 |             [System.Management.Automation.CompletionResult]::new($_, $_, [System.Management.Automation.CompletionResultType]::ParameterValue, ("$($tables[$_])".Trim() | Out-String))
36 |           }
37 |       }
38 |       catch {}
39 |     }
40 |   }
41 | }
42 | 
43 | Register-ArgumentCompleter -ParameterName Database -CommandName Import-Database -ScriptBlock {
44 |   param
45 |   (
46 |     $CommandName,
47 |     $ParameterName,
48 |     $WordToComplete,
49 |     $CommandAst,
50 |     $params
51 |   )
52 | 
53 |   Get-Variable | Where-Object {
54 |     $_.Value -is [Database]
55 |   } | ForEach-Object {
56 |     $value = '${0}' -f $_.Name
57 |     [System.Management.Automation.CompletionResult]::new($value, $value, [System.Management.Automation.CompletionResultType]::Variable, ("$($_.Value)".Trim() | Out-String))
58 |   }
59 | }
--------------------------------------------------------------------------------
/Modules/ReallySimpleDatabase/loadbinaries.ps1:
--------------------------------------------------------------------------------
 1 | #region prerequisites (MUST BE FIRST!)
 2 | 
 3 | 
 4 | function LoadBinaries
 5 | {
 6 | 
 7 |     # use API method to load Interop databases from wherever we want
 8 |     # (else, the DLL needs to be in the search path or inside the
 9 |     # folder the .NET assembly is located in)
10 |     # FreeLibrary allows us to potentially remove the DLL (for temp file cleanup)
11 |     $code = '
12 |         [DllImport("kernel32.dll")]
13 |         public static extern IntPtr LoadLibrary(string dllToLoad);
14 |          [DllImport("kernel32.dll")]
15 |         public static extern bool FreeLibrary(IntPtr hModule);'
16 | 
17 |     Add-Type -MemberDefinition $code -Namespace Internal -Name Helper
18 | 
19 |     # check the platform:
20 |     if ([Environment]::Is64BitProcess)
21 |     {
22 |         Write-Verbose "Platform x64"
23 |         $platform = "64"
24 |     }
25 |     else
26 |     {
27 |         Write-Verbose "Platform x86"
28 |         $platform = "86"
29 |     }
30 |   
31 |     # pre-load the platform specific DLL version
32 |     $parentFolder = Split-Path -Path $PSScriptRoot
33 | 
34 |     $Path = "$PSScriptRoot\binaries\x$platform\SQLite.Interop.dll"
35 |     $null = [Internal.Helper]::LoadLibrary($Path)
36 |     Write-Verbose "Interop assembly loaded"
37 | 
38 |     # next, load the .NET assembly. Since the Interop DLL is already
39 |     # pre-loaded, all is good:  
40 |     Add-Type -Path "$PSScriptRoot\binaries\System.Data.SQLite.dll"
41 |     Write-Verbose "database assembly loaded"
42 | 
43 | }
44 | 
45 | # load SQLite DLLs
46 | LoadBinaries
47 | 
48 | 
49 | 
50 | #endregion prerequisites
51 | 
52 | 
--------------------------------------------------------------------------------
/Modules/ReallySimpleDatabase/logic.ps1:
--------------------------------------------------------------------------------
   1 | 
   2 | 
   3 | #region Class Definitions
   4 | # this class represents a table column
   5 | class Field
   6 | {
   7 |   #region public properties
   8 | 
   9 |   # store all important details such as the table this column belongs to
  10 |   # the table object includes a reference to the database
  11 |   [Table]$Table
  12 |   [string]$Name
  13 |   [string]$Type
  14 |   [bool]$NotNull
  15 |   [object]$DefaultValue
  16 |   [int]$Id
  17 |   #endregion public properties
  18 | 
  19 |   #region CONSTRUCTOR
  20 |   # the constructor takes the table object plus the datarow returned by the
  21 |   # database with the column details
  22 |   Field([Table]$Table, [System.Data.DataRow]$ColumnInfo)
  23 |   {
  24 |     # translate the raw datarow information to the Column object properties:
  25 |     $this.Name = $ColumnInfo.Name
  26 |     $this.Type = $ColumnInfo.type
  27 |     $this.NotNull = $ColumnInfo.notnull
  28 |     $this.DefaultValue = $ColumnInfo.dflt_value
  29 |     $this.Table = $Table
  30 |     $this.Id = $ColumnInfo.cid
  31 |   }
  32 |   #endregion CONSTRUCTOR
  33 |   
  34 |   #region methods
  35 | 
  36 |   #region dynamic methods (bound to instance object)
  37 |   # create an index for this column
  38 |   [void]AddIndex()
  39 |   {
  40 |     # do we have an index for this column already?
  41 |     $tbl = $this.Table
  42 |     $clm = $this.Name
  43 |     
  44 |     $existingIndex = $tbl.GetIndexes() | 
  45 |     Where-Object { $_.Column.Name -eq $this.Name } | 
  46 |     Select-Object -First 1
  47 |     
  48 |     if ($existingIndex -ne $null)
  49 |     {
  50 |       $existing = $existingIndex.Name
  51 |       throw "$clm uses index $existing already. Remove this index before adding a new one."
  52 |     }
  53 |     
  54 |     $columnName = $this.Name
  55 |     $tableName = $this.Table.Name
  56 |     $indexName = "idx_" + $this.Name 
  57 |     $database = $this.Table.Database
  58 |     
  59 |     $database.AddIndex($indexName, $tableName, $columnName, $false)
  60 |   }
  61 |   
  62 |   # create an index for this column
  63 |   [void]AddUniqueIndex()
  64 |   {
  65 |     $columnName = $this.Name
  66 |     $tableName = $this.Table.Name
  67 |     $indexName = "idx_" + $this.Name 
  68 |     $database = $this.Table.Database
  69 |     
  70 |     $database.AddIndex($indexName, $tableName, $columnName, $true)
  71 |   }
  72 | 
  73 |   # removes all indices for this column
  74 |   [void]DropIndex()
  75 |   {
  76 |     $indexes = $this.Table.GetIndexes()[$this.Name]
  77 |     foreach($index in $indexes)
  78 |     {
  79 |       $sql = "Drop Index If Exists $($index.Name)"
  80 |       $this.Table.Database.InvokeSqlNoResult($sql)
  81 |     }
  82 |   }
  83 |     
  84 |   # override the ToString() method to provide a more meaningful display
  85 |   [string]ToString()
  86 |   {
  87 |     return '{0} ({1})' -f $this.Name, $this.Type
  88 |   }
  89 | 
  90 |   #endregion dynamic methods (bound to instance object)
  91 | 
  92 |   #endregion methods
  93 | }
  94 | 
  95 | 
  96 | 
  97 | # this class represents a single property
  98 | # it specifies the property name and the property value type
  99 | class NewFieldRequest
 100 | {
 101 |   [string]$Name
 102 |   [string]$Type
 103 |   
 104 |   NewFieldRequest([string]$Name, [string]$Type)
 105 |   {
 106 |     $this.Name = $Name
 107 |     $this.Type = $Type
 108 |   }
 109 | 
 110 |   # override the default ToString() method to provide a more
 111 |   # meaningful display
 112 |   [string]ToString()
 113 |   {
 114 |     # show the property name and property value type
 115 |     if ($this.Type -eq 'String')
 116 |     {
 117 |       return "'{0}' '{1}' COLLATE NOCASE" -f $this.Name, $this.Type
 118 |     }
 119 |     return "'{0}' '{1}'" -f $this.Name, $this.Type
 120 |   }
 121 | }
 122 | 
 123 | 
 124 | # represents a SQLite database and can either be file-based or memory-based
 125 | # requires the SQLite DLL to be imported
 126 | # requires these classes:
 127 | class Database
 128 | {
 129 |   #region public properties
 130 |   [string]$Path
 131 |   [System.Data.SQLite.SQLiteConnection]$Connection
 132 |   [bool]$IsOpen = $false
 133 | 
 134 |   # maximum time (in sec) for a query to complete
 135 |   # if a query takes more time, an exception is thrown
 136 |   # 600 represents 600 sec. = 10 min.
 137 |   # make sure you adjust this property if the query is expected to 
 138 |   # take longer, i.e. when inserting large numbers of objects
 139 |   # via Import-Database
 140 |   [int]$QueryTimeout = 600
 141 |   #endregion public properties
 142 | 
 143 |   #region hidden properties
 144 |   hidden [bool]$_enableUnsafePerformanceMode = $false
 145 |   hidden [bool]$_lockDatabase = $false
 146 |   hidden [string]$_path
 147 |   #endregion hidden properties
 148 | 
 149 |   #region define CONSTRUCTOR (Path: path to the database, or :memory:)
 150 | 
 151 |   # constructor takes the path to the database file
 152 |   # the file does not need to exist yet. It will be created if it does not yet exist.
 153 |   # If the path is ":memory:", then a memory-based database is created
 154 |   Database([string]$Path)
 155 |   {
 156 |         
 157 | 
 158 |     #region validate submitted path
 159 |     if ($Path -ne ':memory:')
 160 |     {
 161 |       # store the path
 162 |       $this.Path = $Path
 163 | 
 164 |       # check valid file path
 165 |       $valid = Test-Path -Path $Path -IsValid
 166 |       if (!$valid)
 167 |       {
 168 |         throw [System.ArgumentException]::new("Path is invalid: $Path") 
 169 |       }
 170 |         
 171 |       # emit a file extension warning if a non-default extension is used
 172 |       $extension = [IO.Path]::GetExtension($this.Path)
 173 |       if ($extension -ne '.db')
 174 |       {
 175 |         Write-Warning "Database files should use the extension '.db'. You are using extension '$extension'."
 176 |       }
 177 |         
 178 |       # check whether the path is relative
 179 |       $resolved = $PSCmdlet.SessionState.Path.GetUnresolvedProviderPathFromPSPath($Path)
 180 |         
 181 |       # emit a warning on relative paths
 182 |       if ($resolved -ne $Path) 
 183 |       { 
 184 |         Write-Warning "Absolute file paths preferred. Your path '$Path' resolved to '$resolved'"
 185 |         $this.Path = $resolved 
 186 |       }
 187 | 
 188 |       # save the path in hidden field
 189 |       $this._path = $this.Path
 190 |     }
 191 |     else
 192 |     {
 193 |       # save the path in hidden field
 194 |       $this._path = $Path
 195 |       $this.Path = '[memory]'
 196 |     }
 197 |     #endregion validate submitted path
 198 |     
 199 |     #region add SETTER properties (implemented via Add-Member)
 200 |     # add a scriptproperty to mimick setter properties
 201 | 
 202 |     #region "EnableUnsafePerformanceMode"
 203 |     #
 204 |     # when a new value is assigned, the database changes
 205 |     # when this property is set to $true, a number of database features
 206 |     # are changed to increase performance at the expense of safety
 207 |     # - the journal is switched to MEMORY which might cause data corruption when the
 208 |     #   script crashes in the middle of adding new data
 209 |     # - database synchronization is turned off which can cause data corruption
 210 |     #   when the database crashes
 211 |     $this | Add-Member -MemberType ScriptProperty -Name EnableUnsafePerformanceMode -Value {$this._enableUnsafePerformanceMode } -SecondValue {
 212 |       param($enable)
 213 |       
 214 |       # a hidden property is used to store the desired mode
 215 |       $this._enableUnsafePerformanceMode = $enable
 216 |       # if the database is open already, the change is made immediately
 217 |       # else, the change is performed later whenever Open() is called
 218 |       if ($this.IsOpen)
 219 |       {
 220 |         if ($enable)
 221 |         {
 222 |           $mode1 = 'OFF'
 223 |           $mode2 = 'MEMORY'
 224 |         }
 225 |         else
 226 |         {
 227 |           $mode1 = 'ON'
 228 |           $mode2 = 'DELETE'
 229 |         }
 230 |         $this.InvokeSqlNoResult("PRAGMA JOURNAL_MODE=$mode2")
 231 |         $this.InvokeSqlNoResult("PRAGMA SYNCHRONOUS=$mode1")
 232 |       }
 233 |     }
 234 |     #endregion "EnableUnsafePerformanceMode"
 235 | 
 236 |     #region "LockDatabase"
 237 |         
 238 |     # yet another scriptproperty that works very similar to EnableUnsafePerformanceMode
 239 |     # to increase performance, the database file can be locked
 240 |     # when the database file is locked, no other can access, delete, copy or move
 241 |     # the file
 242 |     $this | Add-Member -MemberType ScriptProperty -Name LockDatabase -Value {$this._lockDatabase } -SecondValue {
 243 |       param($enable)
 244 |       
 245 |       $this._lockDatabase = $enable
 246 |       if ($this.IsOpen)
 247 |       {
 248 |         if ($enable)
 249 |         {
 250 |           $mode = 'exclusive'
 251 |         }
 252 |         else
 253 |         {
 254 |           $mode = 'normal'
 255 |         }
 256 |         $this.InvokeSqlNoResult("PRAGMA LOCKING_MODE=$mode")
 257 |       }
 258 |     }
 259 |     #endregion "LockDatabase"
 260 | 
 261 |     #endregion add SETTER properties (implemented via Add-Member)
 262 | 
 263 |     #region add GETTER properties (implemented via Add-Member)...
 264 | 
 265 |     # the purpose of GETTER properties is to execute code
 266 |     # whenever the property is read. This way, the property
 267 |     # can return up-to-date information for things that are
 268 |     # not static
 269 | 
 270 |         
 271 |     #region "FileSize"
 272 |         
 273 |     # the getter is used to freshly calculate the actual
 274 |     # database file size
 275 |     $this | Add-Member -MemberType ScriptProperty -Name FileSize -Value {
 276 |       if ($this._Path -eq ':memory:')
 277 |       {
 278 |         'In-Memory Database'
 279 |       }
 280 |       else
 281 |       {
 282 |         $exists = Test-Path -Path $this.Path -PathType Leaf
 283 |         if ($exists)
 284 |         {
 285 |           "{0:n0} KB" -f (Get-Item -LiteralPath $this.Path).Length
 286 |         }
 287 |         else
 288 |         {
 289 |           'no file created yet'
 290 |         }
 291 |       }
 292 |     } 
 293 |     #endregion "FileSize"
 294 | 
 295 |     #endregion add GETTER properties (implemented via Add-Member)...
 296 |   }  
 297 |   #endregion define CONSTRUCTOR (Path: path to the database, or :memory:)
 298 | 
 299 |   #region define METHODS
 300 | 
 301 |   #region dynamic methods (bound to an object instance)
 302 | 
 303 |   #region Invoke Sql Statements
 304 | 
 305 |   #region "InvokeSqlNoResult"
 306 | 
 307 |   # send a SQL statement to the database
 308 |   # this method is used for sql statements that do not return anything
 309 |   [void]InvokeSqlNoResult([string]$Sql)
 310 |   {
 311 |     # the database is opened in case it is not open yet
 312 |     # if it is open already, the call does nothing
 313 |     # generally, the database is kept open after all methods
 314 |     # it is closed only when PowerShell ends, or when Close() is called
 315 |     # explicitly
 316 |     $this.Open()
 317 | 
 318 |     # create an SQL command and use the default timeout set in the 
 319 |     # database property
 320 |     $cmd = $this.Connection.CreateCommand()
 321 |     $cmd.CommandText = $Sql
 322 |     $cmd.CommandTimeout = $this.QueryTimeout
 323 |     $null = $cmd.ExecuteNonQuery()
 324 | 
 325 |     # the command object is disposed to free its memory
 326 |     $cmd.Dispose()
 327 |   }
 328 |   #endregion "InvokeSqlNoResult"
 329 | 
 330 |   #region "InvokeSql"
 331 | 
 332 |   # similar to InvokeSqlNoResult, however this method does return
 333 |   # data to the caller
 334 |   [System.Data.DataRow[]]InvokeSql([string]$Sql)
 335 |   {
 336 |     $this.Open()
 337 |     $cmd = $this.Connection.CreateCommand()
 338 |     $cmd.CommandText = $Sql
 339 |     $cmd.CommandTimeout = $this.QueryTimeout
 340 |     
 341 |     # create a new empty dataset. It will be filled with the
 342 |     # results later
 343 |     $ds = [System.Data.DataSet]::new() 
 344 | 
 345 |     # create a new data adapter based on the sql command
 346 |     $da = [System.Data.SQLite.SQLiteDataAdapter]::new($cmd)
 347 |     
 348 |     # fill the dataset with the results       
 349 |     $null = $da.fill($ds)
 350 | 
 351 |     # dispose the command to free its memory
 352 |     $cmd.Dispose()
 353 |     
 354 |     # return the table rows received in the dataset
 355 |     return $ds.Tables.Rows
 356 |   }
 357 |   #endregion "InvokeSql"
 358 | 
 359 |   [System.Data.DataRow[]]InvokeSql([string]$Sql, [bool]$CaseSensitive)
 360 |   {
 361 |     # remove all collate statements
 362 |     $sql = $sql -replace 'collate\s{1,}(binary|nocase|rtrim)\s{0,}'
 363 |     
 364 |     # add appropriate
 365 |     if ($CaseSensitive)
 366 |     {
 367 |       $sql += " collate binary"
 368 |     }
 369 |     else
 370 |     {
 371 |       $sql += " collate nocase"
 372 |     }
 373 |     
 374 |     return $this.InvokeSql($sql)
 375 |   }
 376 |   #endregion Invoke Sql Statements
 377 | 
 378 |   # explicitly close the database
 379 |   # typically, any method acting on the database will open the database
 380 |   # and keep it open, so consecutive methods can reuse the open connection
 381 |   # the database is closed only when PowerShell ends
 382 |   # to explicitly close the database, Close() must be called
 383 |   [void]Close()
 384 |   {
 385 |     # closes the current database connection
 386 |     # this is a CRITICAL operation for databases stored solely in memory
 387 |     # while file-based databases keep the data, memory-based databases are deleted
 388 |     # including all data collected inside of them
 389 |     if ($this.IsOpen)
 390 |     {
 391 |       $this.Connection.Close()
 392 | 
 393 |       # dispose the connection to free its memory
 394 |       $this.Connection.Dispose()
 395 | 
 396 |       # set the property to $null so when a user views the database
 397 |       # object, the old connection no longer shows up
 398 |       $this.Connection = $null
 399 | 
 400 |       # update this state property
 401 |       $this.IsOpen = $false
 402 |     }
 403 |   }
 404 | 
 405 |   # whenever a method wants to access the database, it must have an open connection
 406 |   [void]Open()
 407 |   {
 408 |     # if the database connection is already open, bail out:
 409 |     if ($this.IsOpen) { return }
 410 |     
 411 |     # create a new database connection using the path as connection string
 412 |         
 413 |     $ConnectionString = 'Data Source={0}' -f $this._path
 414 |     $this.Connection = [System.Data.SQLite.SQLiteConnection]::new($ConnectionString)
 415 | 
 416 |     # set this property to $true to allow UNC paths to work
 417 |     $this.Connection.ParseViaFramework = $true 
 418 | 
 419 |     # override the default ToString() method so that this object displays a more
 420 |     # meaningful string representation
 421 |     $this.Connection | Add-Member -MemberType ScriptMethod -Name ToString -Force -Value {
 422 |       # display the sqlite server version, the currently used memory in KB, and the state
 423 |       '{1:n0} KB,{2},V{0}' -f $this.ServerVersion, ($this.MemoryUsed/1KB),$this.State
 424 |     }
 425 |      
 426 |     # open the database connection           
 427 |     Try
 428 |     {
 429 |       $this.Connection.Open() 
 430 |     }
 431 |     Catch
 432 |     {
 433 |       # if the database cannot be opened, throw an exception
 434 |       # there are many different reasons why opening the database may fail. Here are some:
 435 |       # - the database file does not exist (should be validated by Get-Database)
 436 |       # - the user has no write permission to the database file
 437 |       #   - it may reside in a restricted place, i.e. the c:\ root folder
 438 |       #   - it may be locked by another application
 439 |       # - there is not enough free space on the drive left
 440 |       #
 441 |       # Unfortunately, the internally thrown exception does not provide a clue
 442 |       # it just complains that opening the database file did not work
 443 |       # so we cannot provide detailed guidance
 444 |       $message = "Cannot open database. You may not have sufficient write perission at this location, or the drive is full. Database file: $($this._path). Original error message: $($_.Exception.Message)"
 445 |       throw [System.InvalidOperationException]::new($message)
 446 |     }
 447 | 
 448 |     # set the state property accordingly:
 449 |     $this.IsOpen = $true
 450 |     
 451 |     # there are a number of performance options that a user can specify
 452 |     # these options do not take effect until the database is opened
 453 |     # so now that the database is open, the requested changes are applied
 454 |     # the requests are stored in hidden properties
 455 |     if ($this._enableUnsafePerformanceMode) { $this.EnableUnsafePerformanceMode = $true }
 456 |     if ($this._lockDatabase) { $this.LockDatabase = $true }
 457 |   }
 458 | 
 459 |   # returns all tables in the database as an ordered hashtable equivalent
 460 |   # a hashtable is used to make it easier to access a table directly via code
 461 |   # and also to provide a fast way of looking up tables
 462 |   # for example, thanks to the hashtable, code like this is possible:
 463 |   # $db.GetTables().masterTable.GetColumns()
 464 |   # an ordered hashtable is used to get an ordered list of tables without
 465 |   # having to sort anything again
 466 |   [System.Collections.Specialized.OrderedDictionary]GetTables()
 467 |   {
 468 |     $sql = "SELECT * FROM sqlite_master WHERE type='table' ORDER BY name;"
 469 |     $tables = $this.InvokeSql($sql)
 470 | 
 471 |     # create an empty ordered hashtable which really is a special case of
 472 |     # a dictionary
 473 |     $hash = [Ordered]@{}
 474 | 
 475 |     # add the tables to the hashtable
 476 |     foreach($row in $tables)
 477 |     {
 478 |       # use the table name as key, and create a Table object for the table
 479 |       $hash[$row.Name] = [Table]::new($this, $row)
 480 |     }
 481 |     return $hash
 482 |   }
 483 |   
 484 |   # get a specific table
 485 |   [Table]GetTable([string]$TableName)
 486 |   {
 487 |     # sqlite queries are case-sensitive. Since tables with a given name can exist
 488 |     # only once, regardless of casing, the search needs to be case-insensitive
 489 |     # for this to happen, add COLLATE NOCASE to the sql statement
 490 |     $sql = "SELECT * FROM sqlite_master WHERE type='table' and Name='$TableName' COLLATE NOCASE"
 491 |     $tables = $this.InvokeSql($sql)
 492 | 
 493 |     # if the table is not present, return $null
 494 |     if ($tables -eq $null) { return $null }
 495 | 
 496 |     # else return a Table object for the found table
 497 |     return [Table]::new($this, $tables[0])
 498 |   }
 499 |   
 500 |   # helper function (TODO make this static)
 501 |   # it takes any object and returns an array of ColumnInfo objects describing
 502 |   # the properties and their data types
 503 |   # this information can be used to construct a table definition based on any
 504 |   # object type
 505 |   [NewFieldRequest[]]GetFieldNamesFromObject([object]$data)
 506 |   {
 507 |     # get all members from the object via the hidden PSObject property
 508 |     $names = [object[]]$data.psobject.Members | 
 509 |     # select properties only 
 510 |     # (including dynamicly added properties such as ScriptProperties)
 511 |     Where-Object {$_.MemberType -like '*Property'} |
 512 |     # determine the appropriate data type and construct the ColumnInfo object
 513 |     ForEach-Object {
 514 |       $name = $_.Name
 515 |       # take the string name of the data type
 516 |       $type = $_.TypeNameOfValue
 517 |       # if there is no specific type defined, and if the object property
 518 |       # contains data, use the type from the actual value of the property
 519 |       if (($type -eq 'System.Object' -or $type -like '*#*') -and $_.Value -ne $null) { 
 520 |         $type = $_.Value.GetType().FullName
 521 |       }
 522 | 
 523 |       # remove the System namespace.
 524 |       if ($type -like 'System.*') { $type = $type.Substring(7) }
 525 |       # any complex and specific type now contains one or more "."
 526 |       # since the database supports only basic types, for complex types
 527 |       # the string datatype is used instead
 528 |       if ($type -like '*.*') { $type = 'String' }
 529 |       if ($type -eq 'boolean') { $type = 'Bool' }   
 530 |       # create the ColumnInfo object
 531 |       [NewFieldRequest]::new($name, $type)
 532 |     }
 533 | 
 534 |     # return the array of ColumnInfo objects that represent each
 535 |     # object property
 536 |     return $names
 537 |   }
 538 | 
 539 |   # add a new index
 540 |   [void]AddIndex([string]$Name, [string]$TableName, [string[]]$ColumnName, [bool]$Unique)
 541 |   {
 542 |     $UniqueString = ('','UNIQUE ')[$Unique]
 543 |     $ColumnString = $columnName -join ', '
 544 |     $sql = "Create $UniqueString Index $Name On $TableName ($columnString);"
 545 |         
 546 |     # creating an index may take a long time, so take a look at the table size
 547 |     $table = $this.GetTable($TableName)
 548 |     if ($table -eq $null)
 549 |     {
 550 |       throw "Table $table not found."
 551 |     }
 552 |     elseif ($table.Count -gt 10000)
 553 |     {
 554 |       Write-Warning "Creating an index on large tables may take considerable time. Please be patient."
 555 |     }
 556 |         
 557 |     try
 558 |     {
 559 |       $this.InvokeSqlNoResult($sql)
 560 |     }
 561 |     catch
 562 |     {
 563 |       if ($Unique -and $_.Exception.InnerException.Message -like '*constraint*')
 564 |       {
 565 |         throw "There are datasets in your table that share the same values, so a unique index cannot be created. Try a non-unique index instead."
 566 |       }
 567 |       throw $_.Exception
 568 |     }
 569 |         
 570 |   }
 571 | 
 572 |   #endregion dynamic methods (bound to an object instance)
 573 | 
 574 |   # backup the database to a file
 575 |   # this can also be used to save an in-memory-database to file
 576 |   [System.IO.FileInfo]Backup([string]$Path)
 577 |   {
 578 |     $this.InvokeSqlNoResult("VACUUM INTO '$Path';")
 579 |     return Get-Item -LiteralPath $Path 
 580 |   }
 581 | 
 582 |   [string]ToString()
 583 |   {
 584 |     
 585 |     # show the property name and property value type
 586 |     return 'Database,Tables {0} ({1})' -f ($this.GetTables().Keys -join ','),$this.FileSize
 587 |   }
 588 |   
 589 |   #endregion define METHODS
 590 | }
 591 | 
 592 | # this class represents an index in a database table
 593 | class Index
 594 | {
 595 |   [string]$Name
 596 |   [bool]$Unique
 597 |   [bool]$IsMultiColumn
 598 |   # column contains references to database and table
 599 |   [Field[]]$Column
 600 |   
 601 |   Index([string]$Name, [bool]$Unique, [Field[]]$Column)
 602 |   {
 603 |     $this.Name = $Name
 604 |     $this.Unique = $Unique
 605 |     $this.Column = $Column
 606 |     $this.IsMultiColumn = $Column.Count -gt 1
 607 |   }
 608 | 
 609 |   # override the default ToString() method to provide a more
 610 |   # meaningful display
 611 |   [string]ToString()
 612 |   {
 613 |     
 614 |     # show the property name and property value type
 615 |     return '{0} on {1} ({2}, {3})' -f $this.Name, $this.Column.Name, $this.Column.Type, ('NONUNIQUE','UNIQUE')[$this.Unique]
 616 |   }
 617 |   
 618 |   # remove index
 619 |   [void]DropIndex()
 620 |   {
 621 |     $sql = "Drop Index If Exists $($this.Name)"
 622 |     $this.Column.Table.Database.InvokeSqlNoResult($sql)
 623 |     
 624 |   }
 625 | }
 626 | 
 627 | # this class represents a database table
 628 | class Table
 629 | {
 630 |   # store all important details including the database this table lives in
 631 |   [Database]$Database
 632 |   [string]$Name
 633 |   [bool]$HasErrors
 634 |   [string]$RowError
 635 |   [System.Data.DataRowState]$RowState
 636 |   [string]$Definition
 637 |   
 638 |   # the constructor takes the database plus the original datarow with the
 639 |   # table infos returned by the database
 640 |   Table([Database]$Database, [System.Data.DataRow]$TableInfo)
 641 |   {
 642 |     # translate the original datarow object to the Table object properties:
 643 |     $this.Name = $TableInfo.Name
 644 |     $this.Definition = $TableInfo.Sql
 645 |     $this.Database = $Database
 646 |     $this.RowError = $TableInfo.RowError
 647 |     $this.RowState = $TableInfo.RowState
 648 |     $this.HasErrors = $TableInfo.HasErrors
 649 |         
 650 |     #region GETTER script properties
 651 |     # add scriptproperty "Count" to mimick a getter, and freshly calculate
 652 |     # the number of records in this table
 653 |     # note that Count is part of the immediately visible properties so when a user
 654 |     # dumps a table, this immediately calculates the actual number of records
 655 |     # and displays it along with the other details 
 656 |     
 657 |     # since Count(*) takes a long time on large tables, we output the number of rows
 658 |     # this is a good approximation but will not take into account deleted records
 659 |     # as the row id is constantly increasing
 660 |     $this |
 661 |     Add-Member -MemberType ScriptProperty -Name Count -Value {
 662 |       #$this.Database.InvokeSql("Select Count(*) from $($this.Name)") |
 663 |       $count = $this.Database.InvokeSql("SELECT MAX(_ROWID_) FROM $($this.Name) LIMIT 1;") |
 664 |       #Select-Object -ExpandProperty 'Count(*)'
 665 |       Select-Object -ExpandProperty 'MAX(_ROWID_)'
 666 |       if ($Count -eq [System.DBNull]::Value)
 667 |       {
 668 |         'EMPTY'
 669 |       }
 670 |       else
 671 |       {
 672 |         $count
 673 |       }
 674 |     }
 675 |     #endregion 
 676 |   }
 677 | 
 678 |   # get the column names and types of this table
 679 |   # similar approach as GetTables() in regards to returning an ordered hashtable  
 680 |   [System.Collections.Specialized.OrderedDictionary]GetFields()
 681 |   {
 682 |     # get the detailed table information for this table
 683 |     $sql = 'PRAGMA table_info({0});' -f $this.Name
 684 |     # and translate each returned record into a Column object  
 685 |     $hash = [Ordered]@{}
 686 |     foreach($column in $this.Database.InvokeSql($sql))
 687 |     {
 688 |       $hash[$column.Name] = [Field]::new($this, $column)
 689 |     }
 690 |     return $hash
 691 |   }
 692 |   
 693 |   
 694 |   # override the ToString() method so that this object displays in a more
 695 |   # meaningful way
 696 |   [string]ToString()
 697 |   {
 698 |     # return the number of records in this table, left-bound with a minimum of 6 characters,
 699 |     # plus a comma-separated list of the table columns
 700 |     return '{0,-6}:{1}' -f $this.Count, ($this.GetFields().Keys -join ',')
 701 |   }
 702 |   
 703 |   [int]GetRecordCount()
 704 |   {
 705 |     return ($this.Database.InvokeSql("Select Count(*) from $($this.Name)") |
 706 |     Select-Object -ExpandProperty 'Count(*)') -as [int]
 707 |   }
 708 |   
 709 |   # delete the table from the database
 710 |   [void]DropTable()
 711 |   {
 712 |     # WARNING: the table and all of its data is immediately deleted
 713 |     $SQL = "Drop Table $($this.Name);"
 714 |     $this.Database.InvokeSQL($SQL) 
 715 |   }
 716 |   
 717 |   # get indices
 718 |   [Index[]]GetIndexes()
 719 |   {
 720 |     $tableName = $this.Name
 721 |     $columns = $this.GetFields()
 722 |     
 723 |     $sql = "PRAGMA index_list('$tableName')"
 724 |     $indexes = foreach($index in $this.Database.InvokeSql($sql))
 725 |     {
 726 |       $indexName = $index.Name
 727 |       [bool]$unique = $index.Unique
 728 |       $columnName = $this.Database.InvokeSql("PRAGMA index_info('$indexName')").name
 729 |       [Index]::new($indexName, $unique, $columns[$columnName])
 730 |     }
 731 |     return $indexes
 732 |   }
 733 | 
 734 |   [System.Data.DataRow[]]GetData()
 735 |   {
 736 |     # dump all table data
 737 |     $sql = "select * from {0}" -f $this.Name
 738 |     return $this.Database.InvokeSql($sql)
 739 |   }
 740 | 
 741 |   [System.Data.DataRow[]]GetData([string]$Filter)
 742 |   {
 743 |     # dump all table data
 744 |     $sql = "select * from {0} where $Filter" -f $this.Name
 745 |     return $this.Database.InvokeSql($sql)
 746 |   }
 747 | 
 748 |   [System.Data.DataRow[]]GetData([string]$Filter, [bool]$CaseSensitive)
 749 |   {
 750 |     # dump all table data
 751 |     $sql = "select * from {0} where $Filter" -f $this.Name
 752 |     return $this.Database.InvokeSql($sql, $CaseSensitive)
 753 |   }
 754 |     
 755 |   # TODO: add method to query this table
 756 | }
 757 | 
 758 | 
 759 | 
 760 | #endregion Class Definitions
 761 | 
 762 | #region functions
 763 | 
 764 | 
 765 | 
 766 | function Get-Database
 767 | {
 768 |   <#
 769 |       .SYNOPSIS
 770 |       Returns a database object representing a SQLite database. 
 771 |       The database object provides all properties and methods to
 772 |       view and manage the database
 773 |       Its content (tables, columns, indices, etc) and can execute SQL statements
 774 |       Most of the functionality is found in the nested objects.
 775 |       To create new tables and store new data in the database, use Import-Database and
 776 |       supply the database object to this function
 777 | 
 778 |       .EXAMPLE
 779 |       $db = Get-Database
 780 |       returns a memory-based database
 781 | 
 782 |       .EXAMPLE
 783 |       $db = Get-Database -Path $env:temp\test.db
 784 |       Opens the file-based database. If the file does not exist, a new database file is created
 785 | 
 786 |       .EXAMPLE
 787 |       $db = Get-Database -Path c:\data\database1.db
 788 |       $db.GetTables()
 789 |       opens the file-based database and lists the tables found in the database
 790 | 
 791 |       .EXAMPLE
 792 |       $db = Get-Database -Path c:\data\database1.db
 793 |       $db.InvokeSQL('Select * from customers')
 794 |       runs the SQL statement and queries all records from the table "customers".
 795 |       The table "customers" must exist.
 796 |     
 797 |   #> 
 798 |   param
 799 |   (
 800 |     # path to the database file. If the file does not yet exist, it will be created
 801 |     # this parameter defaults to ":memory:" which creates a memory-based database
 802 |     # memory-based databases are very fast but the data is not permanently stored
 803 |     # once the database is closed or PowerShell ends, the memory-based database is
 804 |     # deleted
 805 |     [String]
 806 |     [Parameter(Mandatory=$false)]
 807 |     $Path = ':memory:'
 808 |   )
 809 | 
 810 |   # all work is done by the constructor of Database
 811 |   return [Database]::new($Path) 
 812 | }
 813 | 
 814 | function Import-Database
 815 | {
 816 |   <#
 817 |       .SYNOPSIS
 818 |       Imports new data to a database table. Data can be added to existing or new tables.
 819 |       Use Get-Database to get a database first.
 820 |       .DETAILS
 821 |       Import-Database automatically examines incoming objects and creates the
 822 |       table definition required to store these objects. The first object received
 823 |       by Import-Database determines the table layout.
 824 |       If the specified table already exists, Import-Database checks whether the existing
 825 |       table has fields for all object properties.
 826 | 
 827 |       .EXAMPLE
 828 |       $db = Get-Database
 829 |       Get-Service | Import-Database -Database $db -Table Services
 830 |       $db.InvokeSql('Select * From Services') | Out-GridView
 831 |       creates a memory-based database, then pipes all services into the database
 832 |       and stores them in a new table called "Services"
 833 |       Next, the table content is queried via Sql and the result displays in a gridview
 834 |       Note that the database content is lost once PowerShell ends
 835 | 
 836 |       .EXAMPLE
 837 |       $db = Get-Database -Path $env:temp\temp.db
 838 |       Get-Service | Import-Database -Database $db -Table Services
 839 |       $db.InvokeSql('Select * From Services') | Out-GridView
 840 |       opens the file-based database in $env:temp\temp.db, and if the file does not exist,
 841 |       a new file is created. All services are piped into the database
 842 |       and stored in a table called "Services". 
 843 |       If the table "Services" exists already, the data is appended to the table, else
 844 |       a new table is created.
 845 |       Next, the table content is queried via Sql and the result displays in a gridview
 846 |       Since the database is file-based, all content imported to the database is stored
 847 |       in the file specified.
 848 | 
 849 |       .EXAMPLE
 850 |       $db = Get-Database -Path $env:temp\temp.db
 851 |       $db.QueryTimeout = 6000
 852 |       Get-ChildItem -Path c:\ -Recurse -ErrorAction SilentlyContinue -File | 
 853 |       Import-Database -Database $db -Table Files
 854 |       Writes all files on drive C:\ to table "Files". Since this operation may take a long
 855 |       time, the database "QueryTimeout" property is set to 6000 seconds (100 min)
 856 |       A better way is to split up data insertion into multiple chunks that execute
 857 |       faster. This can be achieved via -TransactionSet. This parameter specifies the
 858 |       chunk size (number of objects) that should be imported before a new transaction
 859 |       starts.
 860 | 
 861 |       .EXAMPLE
 862 |       $db = Get-Database -Path $home\Documents\myDatabase.db
 863 |       Get-ChildItem -Path $home -Recurse -File -ErrorAction SilentlyContinue |
 864 |       Import-Database -Database $db -Table FileList -UseUnsafePerformanceTricks -LockDatabase -TransactionSet 10000
 865 |       $db.InvokeSql('Select * From FileList Where Extension=".log" Order By "Length"') | Out-GridView
 866 |       A file-based database is opened. If the file does not yet exist, it is created.
 867 |       Next, all files from the current user profile are collected by Get-ChildItem,
 868 |       and written to the database table "FileList". If the table exists, the data is
 869 |       appended, else the table is created.
 870 |       Next, the table "FileList" is queried by Sql, and all files with extension ".log"
 871 |       display in a gridview ordered by file size
 872 |       To improve performance, Import-Database temporarily locks the database and turns off
 873 |       database features that normally improve robustness in the event of a crash.
 874 |       By turning off these features, performance is increased considerably at the expense
 875 |       of data corruption. 
 876 |     
 877 |   #> 
 878 |   param
 879 |   (
 880 |     # Database object returned by Get-Database
 881 |     [Database]
 882 |     [Parameter(Mandatory)]
 883 |     $Database,
 884 |   
 885 |     # Name of table to receive the data. If the table exists, the data appends the table.
 886 |     # Else, a new table is created based on the properties of the first received object.
 887 |     [String]
 888 |     [Parameter(Mandatory)]
 889 |     $TableName,
 890 |     
 891 |     # the data to be written to the database table
 892 |     [Object[]]
 893 |     [Parameter(Mandatory,ValueFromPipeline)]
 894 |     $InputObject,
 895 |     
 896 |     # to increase performance, transactions are used. To increase robustness and
 897 |     # receive progress information, the transaction can be limited to any number of
 898 |     # new objects. Once the number of objects have been written to the database table,
 899 |     # the transaction is committed, status information and stats are returned,
 900 |     # and a new transaction starts. 
 901 |     [int]
 902 |     # commit data to database at least after these many of new data sets
 903 |     $TransactionSet = 20000,
 904 |     
 905 |     # temporarily turns off cost-intensive security features to increase speed
 906 |     # at the expense of a higher risk of data corruption if the database crashes
 907 |     # during the operation
 908 |     [Switch]
 909 |     # speeds up data insertion at the expense of protection against data corruption in case of crashes or unexpected failures
 910 |     $UseUnsafePerformanceTricks,
 911 | 
 912 |     # temporarily locks access to the database file to increase speed.
 913 |     # While the database file is locked, noone else can access the database.    
 914 |     [Switch]
 915 |     $LockDatabase,
 916 | 
 917 |     # takes the first object and defines the table. Does not add any data
 918 |     # this can be used to predefine a new table layout based on a sample
 919 |     # object
 920 |     [Switch]
 921 |     $DefineTableOnly,
 922 | 
 923 |     # when the type of a field does not match the type of an object property,
 924 |     # the type is autoconverted to the existing field type
 925 |     [Switch]
 926 |     $AllowTypeConversion,
 927 |     
 928 |     # returns the table object
 929 |     [Switch]
 930 |     $PassThru
 931 |   )
 932 |   
 933 |   begin 
 934 |   {
 935 |     # count the incoming objects
 936 |     $dataSetCount = 0
 937 | 
 938 |     # the first object is examined to figure out the table layout
 939 |     $first = $true
 940 | 
 941 |     #region Performance Options
 942 |     # if performance options were specified, save the current values
 943 |     # so they can be restored later, and apply the changes
 944 |     $oldSetting1 = $oldSetting2 = $null
 945 |     if ($UseUnsafePerformanceTricks)
 946 |     {
 947 |       $oldSetting1 = $database.EnableUnsafePerformanceMode
 948 |       $database.EnableUnsafePerformanceMode = $true
 949 |     }
 950 |     if ($LockDatabase)
 951 |     {
 952 |       $oldSetting2 = $database.LockDatabase
 953 |       $database.LockDatabase = $true
 954 |     }
 955 |     #endregion Performance Options
 956 | 
 957 |     # make sure the database can store the maximum amount of data
 958 |     $database.InvokeSqlNoResult('PRAGMA PAGE_SIZE=65535')
 959 |   }
 960 |   
 961 |   process
 962 |   {
 963 |     # process any object that is received either via the pipeline
 964 |     # or via an array
 965 |     foreach($object in $InputObject)
 966 |     {
 967 |       #region process first incoming object
 968 |       # if this is the first data item, we need to find out the 
 969 |       # column definition
 970 |       if ($first)
 971 |       {
 972 |         $first = $false
 973 |                 
 974 |         $wmiDatePattern = '^\d{14}\.\d{6}\+\d{3}$'
 975 | 
 976 |         # get the requirements for this object
 977 |         $Fields = $database.GetFieldNamesFromObject($object)
 978 |     
 979 |         # keep record of target field types so when data is inserted,
 980 |         # it can be converted to the desired type if required
 981 |         $fieldTypes = @{}
 982 |         $fields | ForEach-Object { $fieldTypes[$_.Name] = $_.Type }
 983 |     
 984 |         #region get or create table
 985 |         # check for the destination table inside the database
 986 |         $table = $database.GetTable($TableName)
 987 |         if ($table -eq $null)
 988 |         {
 989 |           # if it does not yet exist, create it based on the requirements
 990 |           # of the first object
 991 | 
 992 |           # we use the "object field separator" in $ofs to quickly
 993 |           # create the sql field string. $Fields contains an array of
 994 |           # Column objects. Their ToString() method displays field name and
 995 |           # field type separated by a space. The OFS turns the array into
 996 |           # a string and uses the string specified in $ofs to concatenate
 997 |           # the array elements, thus a comma-separated list is created:
 998 |           $ofs = ','
 999 |           $fieldstring = "$Fields".TrimEnd(',')
1000 | 
1001 |           # create the table based on the fieldstring:
1002 |           $query = 'CREATE TABLE {0} ({1})' -f $TableName, $fieldString
1003 |           $Database.InvokeSqlNoResult($query)
1004 | 
1005 |           # keep an array of field names that is later used to compile the
1006 |           # insertion statement
1007 |           $columnTable = $fields.Name
1008 |           
1009 |           # set $foundAny to $true because ALL fields are matching since we created
1010 |           # the table based on the object
1011 |           $foundAny = $true
1012 |         }
1013 |         else
1014 |         {
1015 |           # if the table is present already, check whether the fields in the
1016 |           # existing table match the required fields
1017 |           # for this, get the column names from the existing table
1018 |           $columns = $table.GetFields()
1019 |           # test whether columns match
1020 |           $foundAny = $false
1021 |           $missing = foreach($field in $fields)
1022 |           {
1023 |             # if the field exists...
1024 |             if ($columns.Contains($field.Name))
1025 |             {
1026 |               $foundAny = $true
1027 |               # ...check the field type. Does it match as well?
1028 |               $existingType = $columns[$field.Name].Type
1029 |               if ($existingType -ne $field.Type)
1030 |               { 
1031 |                 $message = 'Field {0} is of type {1} but you are adding type {2}.' -f $Field.Name, $existingType, $field.Type
1032 |                                     
1033 |                 if ($AllowTypeConversion)
1034 |                 {
1035 |                   Write-Warning $message
1036 |                   # update the field type because now the object property
1037 |                   # type does not match the table field type
1038 |                   $fieldTypes[$field.Name] = $existingType
1039 |                 }
1040 |                 else
1041 |                 {
1042 |                   # if the field exists but the field type is different,
1043 |                   # there is no way to fix this, and an exception is thrown
1044 |                   throw [System.InvalidOperationException]::new($message)
1045 |                 }
1046 |               }
1047 |             }
1048 |             else
1049 |             {
1050 |               # if the field does not exist, it is added to the $missing list 
1051 |               $field
1052 |             }
1053 |           }
1054 | 
1055 |           
1056 |           $missing | ForEach-Object {
1057 |             Write-Warning "Table '$($Table.Name)' has no field '$($_.Name)'."
1058 |           }
1059 |           if ($missing.Count -gt 0)
1060 |           {
1061 |             Write-Warning "Consider adding data to a new table with a more appropriate design, or adding missing fields to the table."
1062 |           }
1063 |           if (!$foundAny)
1064 |           {
1065 |             throw "There are NO matching fields in table '$($table.Name)'. Import to a new table, or use an existing table that matches the object type."
1066 |           }
1067 |           # keep an array of field names that is later used to compile the
1068 |           # insertion statement
1069 |           $columnTable = $columns.Keys
1070 |         }
1071 |         #endregion get or create table
1072 |         #region abort pipeline if table prototyping is active
1073 |         if ($DefineTableOnly.isPresent -or !$foundAny)
1074 |         {
1075 |           # abort pipeline
1076 |           $p = {Select-Object -First 1}.GetSteppablePipeline()
1077 |           $p.Begin($true)
1078 |           $p.Process(1)
1079 |         }
1080 |         #endregion abort pipeline if table prototyping is active
1081 | 
1082 |         #region precompile insertion command
1083 |         # adding new data via an INSERT INTO sql statement per object
1084 |         # would be very slow for large numbers of objects
1085 |         # a much faster way uses a precompiled insertion command
1086 |         # which is created now:
1087 | 
1088 |         # create a comma-separated list of field names
1089 |         $fieldNames = '"' + ($columnTable -join '","') + '"'
1090 |         # create a comma-separated list of variable names which really are
1091 |         # field names prepended with "$"
1092 |         $variableNames = foreach($_ in $columnTable) { '${0}' -f $_ }
1093 |         $variableNamesString = $variableNames -join ','
1094 |                         
1095 |         # precompile the insertion command 
1096 |         # the insertion command is a default INSERT INTO sql statement except
1097 |         # that it does not contain the actual values but instead
1098 |         # variable names:
1099 |         $command = $database.Connection.CreateCommand()
1100 |         $command.CommandText = 'INSERT INTO {0}({1}) VALUES({2});' -f $TableName, $fieldNames, $variableNamesString
1101 | 
1102 |         # to be able to later replace the variables with the actual data,
1103 |         # parameters need to be created for each variable:
1104 |         $parameters = $variableNames | ForEach-Object {
1105 |           # create a parameter
1106 |           $parameter = $command.CreateParameter()
1107 |           $parameter.ParameterName = $_
1108 | 
1109 |           # add the parameter to the command
1110 |           $null = $command.Parameters.Add($parameter)
1111 |           #endregion precompile insertion command
1112 | 
1113 |           # add a noteproperty so we can attach the original property name (less "$") for
1114 |           # easy retrieval later when the object properties are queried:
1115 |           $realName = $_.Substring(1)
1116 |           $parameter | 
1117 |           Add-Member -MemberType NoteProperty -Name RealName -Value $realName -PassThru |
1118 |           Add-Member -MemberType NoteProperty -Name RealType -Value $fieldTypes[$realName] -PassThru
1119 |         }
1120 |                     
1121 |         # bulk-insert groups of objects to improve performance. 
1122 |         # This is done by starting a transaction. 
1123 |         # While the transaction is active, no data is written to the
1124 |         # table. Only when the transaction is committed, the entire collected data
1125 |         # is written.
1126 |         # use a transaction to insert multiple data sets in one operation
1127 |         $transaction = $database.Connection.BeginTransaction()
1128 |         
1129 |         # remember start time for stats
1130 |         $start = $baseStart = Get-Date
1131 |       }
1132 |       #endregion process first incoming object
1133 | 
1134 |       # the remaining code is executed for any object received
1135 | 
1136 |       #region add one object to the table
1137 |       # increment the counter
1138 |       $dataSetCount++
1139 | 
1140 |       # submit the actual object property values for each parameter
1141 |       # we added to the INSERT INTO command
1142 |       foreach($parameter in $parameters)
1143 |       {
1144 |         # get the property name only
1145 |         $propName = $parameter.RealName 
1146 |         $value = $object.$propName
1147 | 
1148 |         # if the value is an array, turn the array into a comma-separated
1149 |         # string
1150 |         if ($value -is [Array])
1151 |         {
1152 |           $parameter.Value = $value -join ','
1153 |         }
1154 |         else
1155 |         {
1156 |           # if the data type is DateTime, we must make sure the value is
1157 |           # actually a suitable datetime because SQLite will store it anyway,
1158 |           # causing problems when the data is queried later and cannot be converted
1159 |           if ($parameter.RealType -eq 'DateTime')
1160 |           {
1161 |             $dateTimeValue = $value -as [DateTime]
1162 |             if ($dateTimeValue -ne $null)
1163 |             {
1164 |               $value = $dateTimeValue.ToString('yyyy-MM-dd HH:mm:ss')
1165 |             }
1166 |             elseif ($value -match $wmiDatePattern)
1167 |             {
1168 |               $value = [System.Management.ManagementDateTimeConverter]::ToDateTime($value).ToString('yyyy-MM-dd HH:mm:ss')
1169 |             }
1170 |             else
1171 |             {
1172 |               $value = $null
1173 |             }
1174 |           }
1175 |           $parameter.Value = $value
1176 |         }
1177 |       }
1178 | 
1179 |       # add the command to the transaction
1180 |       $null = $command.ExecuteNonQuery()
1181 |       #endregion add one object to the table
1182 | 
1183 |       #region check for transaction size
1184 |       # by default, the transaction is committed only when all objects are
1185 |       # received. For large numbers of objects, a transactionset size can be
1186 |       # specified. When the specified number of objects are received, the
1187 |       # current transaction is committed, and the caller gets back some stats.
1188 |       if ($TransactionSet -gt 0 -and ($dataSetCount % $TransactionSet -eq 0))
1189 |       {
1190 |         $chunkTimePassed = ((Get-Date)-$start).TotalSeconds
1191 |         $timePassed = ((Get-Date)-$baseStart).TotalMinutes
1192 |         $size = '{0:n2} MB' -f ([IO.FileInfo]::new($Database._path).Length/1MB)
1193 | 
1194 |         $info = [PSCustomObject]@{
1195 |           Processed = $dataSetCount
1196 |           ChunkTime = '{0:n1} sec.' -f $chunkTimePassed
1197 |           TotalTime = '{0:n1} min.' -f $timePassed
1198 |           FileSize = $size
1199 |           FilePath = $Database._path
1200 |         }
1201 |         $start = Get-Date
1202 |         Write-Warning -Message ($info | Out-String)
1203 |         # commit the current transaction
1204 |         $transaction.Commit()
1205 |         # start a new transaction
1206 |         $Transaction = $database.Connection.BeginTransaction()
1207 |         $dataSetCount = 0
1208 |       }
1209 |       #endregion check for transaction size
1210 |     }    
1211 |   }
1212 |   end
1213 |   {
1214 |     # commit pending transaction only if new records have been added
1215 |     if ($dataSetCount -gt 0)
1216 |     {
1217 |       $transaction.Commit()
1218 |     }
1219 |     #region reset temporary database options
1220 |     # reset performance settings to default
1221 |     if ($UseUnsafePerformanceTricks)
1222 |     {
1223 |       $Database.EnableUnsafePerformanceMode = $oldSetting1
1224 |     }
1225 |     if ($LockDatabase)
1226 |     {
1227 |       $database.LockDatabase = $oldSetting2
1228 |     }    
1229 |     #endregion reset temporary database options
1230 |   
1231 |     if ($PassThru)
1232 |     {
1233 |       $Database.GetTable($TableName)
1234 |     }
1235 |   }
1236 | }
1237 | 
1238 | 
1239 | 
1240 | #endregion functions
1241 | 
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
  1 | # ReallySimpleDatabase
  2 | Home of the PowerShell module ReallySimpleDatabase to work with SQLite databases
  3 | 
  4 | ## Install
  5 | 
  6 | Install module from *PowerShell Gallery*:
  7 | 
  8 | ```powershell
  9 | Install-Module -Name ReallySimpleDatabase -Scope CurrentUser
 10 | ```
 11 | 
 12 | ## Usage
 13 | 
 14 | The module imports two cmdlets: `Get-Database` and `Import-Database`.  With these two cmdlets, you can create new SQLite databases, add data to existing databases, or read data from existing database tables. 
 15 | 
 16 | There are no additional dependencies required, and the SQLite database created is a single file that is easily manageable.
 17 | 
 18 | ### Create New Database / Open Existing Database
 19 | 
 20 | To create a new SQLite database (or open an existing database), use `Get-Database`:
 21 | 
 22 | ```
 23 | PS> $database = Get-Database -Path $env:temp\mydb.db
 24 | PS> $database
 25 | 
 26 | Path                 Connection           IsOpen QueryT LockDa Enable
 27 |                                                  imeout tabase Unsafe
 28 |                                                                Perfor
 29 |                                                                manceM
 30 |                                                                ode
 31 | ----                 ----------           ------ ------ ------ ------
 32 | C:\Users\tobia\Ap...                      False     600 False  False
 33 | 
 34 | 
 35 | PS> $database | Select-Object -Property *
 36 | 
 37 | 
 38 | EnableUnsafePerformanceMode : False
 39 | LockDatabase                : False
 40 | FileSize                    : 118.784 KB
 41 | Path                        : C:\Users\tobia\AppData\Local\Temp\mydb.db
 42 | Connection                  :
 43 | IsOpen                      : False
 44 | QueryTimeout                : 600
 45 | ```
 46 | 
 47 | If you omit the parameter `-Path`, then a in-memory-database is created which is very fast but won't persist.
 48 | 
 49 | ### Creating Tables
 50 | 
 51 | To create new tables, simply pipe data to `Import-Database`:
 52 | 
 53 | ```powershell
 54 | Get-Process | Import-Database -Database $database -TableName Processes
 55 | Get-Service | Import-Database -Database $database -TableName Services
 56 | ```
 57 | 
 58 | `Import-Database` automatically analyzes the objects and creates the field definitions on the fly.
 59 | 
 60 | ### Adding Data to Tables
 61 | 
 62 | To add more data to an existing database table, pipe to `Import-Database`:
 63 | 
 64 | ```powershell
 65 | # add another process to table "processes"
 66 | Get-Process -Id $Pid | Import-Database -Database $database -TableName Processes
 67 | ```
 68 | 
 69 | ### List Tables
 70 | 
 71 | To list all tables in a database, run this:
 72 | 
 73 | ```powershell
 74 | PS> $database = Get-Database -Path $env:temp\mydb.db
 75 | PS> $database.GetTables()
 76 | 
 77 | Name      Value
 78 | ----      -----
 79 | Processes 197   :Name,SI,Handles,VM,WS,PM,NPM,Path,Company,CPU,FileVersion,ProductVe...
 80 | Services  292   :Name,RequiredServices,CanPauseAndContinue,CanShutdown,CanStop,Displ...
 81 | ```
 82 | 
 83 | ### Read Data
 84 | 
 85 | Use standard **SQL** to read data from a database:
 86 | 
 87 | ```
 88 | PS> $database = Get-Database -Path $env:temp\mydb.db
 89 | PS> $database.InvokeSql('select * from processes where name like "a%"') | Format-Table
 90 | 
 91 | Name                 SI Handles            VM        WS       PM   NPM Path
 92 | ----                 -- -------            --        --       --   --- ----
 93 | ApplicationFrameHost  1     460 2203637399552 110505984 61837312 27328 C:\WINDOWS\sy...
 94 | armsvc                0     123      69296128   6488064  1630208  8688
 95 | ```
 96 | 
 97 | ## Example: Dump Chrome Passwords
 98 | 
 99 | The browser *Chrome* uses a **SQLite** database to internally store password data. The user can dump this information like so:
100 | 
101 | ```powershell
102 | # default path to Chrome user passwords database:
103 | $Path = "$env:LOCALAPPDATA\Google\Chrome\User Data\Default\Login Data"
104 | # check whether database exists:
105 | $exists = Test-Path -Path $path -PathType Leaf
106 | # if it is missing, then you might not be using the Google Chrome browser:
107 | if (!$exists)
108 | {
109 |   Write-Warning "No Chrome Database found."
110 |   return
111 | }
112 | 
113 | # define function to decrypt encrypted text
114 | function Unprotect-Secret($value)
115 | {
116 |   Add-Type -AssemblyName System.Security
117 |   $bytes = [System.Security.Cryptography.ProtectedData]::Unprotect($value,$null,[System.Security.Cryptography.DataProtectionScope]::CurrentUser)
118 |   [System.Text.Encoding]::Default.GetString($bytes)
119 | }
120 | 
121 | # copy the database (the original file is locked while Chrome is running):
122 | $Destination = "$env:temp\database.db"
123 | Copy-Item -Path $Path -Destination $Destination
124 | 
125 | # query to retrieve the cached passwords:
126 | $sql = "SELECT action_url, username_value, password_value FROM logins"
127 | 
128 | #region define calculated properties
129 | # rename column headers:
130 | $url = @{N='Url';E={$_.action_url}}
131 | $username = @{N='Username';E={$_.username_value}}
132 | $password = @{N='Password'; E={Unprotect-Secret -Secret $_.password_value}} 
133 | #endregion define calculated properties                          
134 | 
135 | $db = Get-Database -Path $Destination
136 | $db.InvokeSql($sql) | Select-Object $url, $username,$password 
137 | ```
138 | 
139 | Note that only the user who saved the passwords can dump them. Chrome uses the Windows cryptography API which protects the passwords by using the machine and user identity.
140 | 
--------------------------------------------------------------------------------