diff --git a/Examples/InvokeExcelQuery/Examples.ps1 b/Examples/InvokeExcelQuery/Examples.ps1 new file mode 100644 index 0000000..a42da76 --- /dev/null +++ b/Examples/InvokeExcelQuery/Examples.ps1 @@ -0,0 +1,14 @@ +try { Import-Module $PSScriptRoot\..\..\ImportExcel.psd1 } catch { throw ; return } + +$queries = +'select * from [sheet1$A:A]', +'select * from [sheet1$]', +'select * from [sheet1$A2:E11]', +'select F2,F5 from [sheet1$A2:E11]', +'select * from [sheet1$A2:E11] where F2 = "Grocery"', +'select F2 as [Category], F5 as [Discount], F5*2 as [DiscountPlus] from [sheet1$A2:E11]' + +foreach ($query in $queries) { + "query: $($query)" + Invoke-ExcelQuery .\testOleDb.xlsx $query | Format-Table +} diff --git a/Examples/InvokeExcelQuery/testOleDb.xlsx b/Examples/InvokeExcelQuery/testOleDb.xlsx new file mode 100644 index 0000000..944751c Binary files /dev/null and b/Examples/InvokeExcelQuery/testOleDb.xlsx differ diff --git a/ImportExcel.psd1 b/ImportExcel.psd1 index 8a267c3..8143435 100644 --- a/ImportExcel.psd1 +++ b/ImportExcel.psd1 @@ -64,6 +64,7 @@ Check out the How To Videos https://www.youtube.com/watch?v=U3Ne_yX4tYo&list=PL5 'Import-USPS', 'Invoke-AllTests', 'Invoke-Sum', + 'Invoke-ExcelQuery', 'Join-Worksheet', 'LineChart', 'Merge-MultipleSheets', @@ -80,6 +81,7 @@ Check out the How To Videos https://www.youtube.com/watch?v=U3Ne_yX4tYo&list=PL5 'Pivot', 'Read-Clipboard', 'ReadClipboardImpl', + 'Read-OleDbData', 'Remove-Worksheet', 'Select-Worksheet', 'Send-SQLDataToExcel', diff --git a/Public/Invoke-ExcelQuery.ps1 b/Public/Invoke-ExcelQuery.ps1 new file mode 100644 index 0000000..4cb01a9 --- /dev/null +++ b/Public/Invoke-ExcelQuery.ps1 @@ -0,0 +1,63 @@ +#Requires -Version 5 +function Invoke-ExcelQuery { + <# + .SYNOPSIS + Helper method for executing Read-OleDbData with some basic defaults. + + For additional help, see documentation for Read-OleDbData cmdlet. + + .DESCRIPTION + Uses Read-OleDbData to execute a sql statement against a xlsx file. For finer grained control over the interaction, you may use that cmdlet. This cmdlet assumes a file path will be passed in and the connection string will be built with no headers and treating all results as text. + + Running this command is equivalent to running the following: + + $FullName = (Get-ChildItem $Path).FullName + Read-OleDbData ` + -ConnectionString "Provider=Microsoft.ACE.OLEDB.12.0;Data Source=$FullName;Extended Properties='Excel 12.0 Xml;HDR=NO;IMEX=1;'" ` + -SqlStatement $Query + + Note that this command uses the MICROSOFT.ACE.OLEDB provider and will not work without it. + + If needed, please download the appropriate package from https://www.microsoft.com/en-us/download/details.aspx?id=54920. + + .EXAMPLE + Invoke-ExcelQuery .\test.xlsx 'select ROUND(F1) as [A1] from [sheet3$A1:A1]' + + .EXAMPLE + $Path = (Get-ChildItem 'test.xlsx').FullName + $Query = "select ROUND(F1) as [A] from [sheet1$A1:A1]" + Read-XlsxUsingOleDb -Path $Path -Query $Query + + .EXAMPLE + $ReadDataArgs = @{ + Path = .\test.xlsx + Query = Get-Content query.sql -Raw + } + $Results = Invoke-ExcelQuery @ReadDataArgs + #> + param( + #The path to the file to open. + [Parameter(Mandatory)] + [ValidateNotNullOrEmpty()] + [String] $Path, # var name consistent with Import-Excel + [Parameter(Mandatory)] + [ValidateNotNullOrEmpty()] + [String] $Query # var name consistent with Invoke-Sqlcmd + ) + + try { + if ((New-Object system.data.oledb.oledbenumerator).GetElements().SOURCES_NAME -notcontains "Microsoft.ACE.OLEDB.12.0") { + Write-Error "Microsoft.ACE.OLEDB.12.0 provider is missing! Please install from https://www.microsoft.com/en-us/download/details.aspx?id=54920" + return + } + } + catch { + Write-Error "System.Data.OleDb is not working or you are on an unsupported platform." + return + } + + $FullName = (Get-ChildItem $Path).FullName + Read-OleDbData ` + -ConnectionString "Provider=Microsoft.ACE.OLEDB.12.0;Data Source=$FullName;Extended Properties='Excel 12.0 Xml;HDR=NO;IMEX=1;'" ` + -SqlStatement $Query +} \ No newline at end of file diff --git a/Public/Read-OleDbData.ps1 b/Public/Read-OleDbData.ps1 new file mode 100644 index 0000000..491b54c --- /dev/null +++ b/Public/Read-OleDbData.ps1 @@ -0,0 +1,54 @@ +#Requires -Version 5 +function Read-OleDbData { + <# + .SYNOPSIS + Read data from an OleDb source using dotnet classes. This allows for OleDb queries against excel spreadsheets. Examples will only be for querying xlsx files. + + For additional documentation, see Microsoft's documentation on the System.Data OleDb namespace here: + https://docs.microsoft.com/en-us/dotnet/api/system.data.oledb + + .DESCRIPTION + Read data from an OleDb source using dotnet classes. This allows for OleDb queries against excel spreadsheets. Examples will only be for querying xlsx files using ACE. + + .EXAMPLE + Read-OleDbData ` + -ConnectionString "Provider=Microsoft.ACE.OLEDB.12.0;Data Source=file.xlsx;Extended Properties='Excel 12.0 Xml;HDR=NO;IMEX=1;'" ` + -SqlStatement "select ROUND(F1) as [A] from [sheet1$A1:A1]" + + .EXAMPLE + $ConnectionString = "Provider=Microsoft.ACE.OLEDB.12.0;Data Source=file.xlsx;Extended Properties='Excel 12.0 Xml;HDR=NO;IMEX=1;'" + $SqlStatement = "select ROUND(F1) as [A] from [sheet1$A1:A1]" + Read-OleDbData -ConnectionString $ConnectionString -SqlStatement $SqlStatement + + .EXAMPLE + $ReadDataArgs = @{ + SqlStatement = Get-Content query.sql -Raw + ConnectionString = "Provider=Microsoft.ACE.OLEDB.12.0;Data Source=file.xlsx;Extended Properties='Excel 12.0 Xml;HDR=NO;IMEX=1;'" + } + $Results = Read-OleDbData @ReadDataArgs + #> + param( + [Parameter(Mandatory)] + [ValidateNotNullOrEmpty()] + [String] $ConnectionString, + [Parameter(Mandatory)] + [ValidateNotNullOrEmpty()] + [String] $SqlStatement + ) + + try { + if ((New-Object system.data.oledb.oledbenumerator).GetElements().SOURCES_NAME -notcontains "Microsoft.ACE.OLEDB.12.0") { + Write-Warning "Microsoft.ACE.OLEDB.12.0 provider is missing! You will not be able to query Excel files without it. Please install from https://www.microsoft.com/en-us/download/details.aspx?id=54920" + } + } + catch { + Write-Error "System.Data.OleDb is not working or you are on an unsupported platform." + return + } + + $DataTable = new-object System.Data.DataTable + $DataAdapter = new-object System.Data.OleDb.OleDbDataAdapter $SqlStatement, $ConnectionString + $null = $DataAdapter.Fill($DataTable) + $null = $DataAdapter.Dispose() + $DataTable.Rows | Select-Object $DataTable.Columns.ColumnName +} \ No newline at end of file diff --git a/__tests__/Read-OleDbDataTests/Invoke-ExcelQuery.Tests.ps1 b/__tests__/Read-OleDbDataTests/Invoke-ExcelQuery.Tests.ps1 new file mode 100644 index 0000000..e79f96d --- /dev/null +++ b/__tests__/Read-OleDbDataTests/Invoke-ExcelQuery.Tests.ps1 @@ -0,0 +1,46 @@ +#Requires -Modules Pester +if (-not (Get-command Import-Excel -ErrorAction SilentlyContinue)) { + Import-Module $PSScriptRoot\..\ImportExcel.psd1 +} + +$skip = $false +if ($IsLinux -or $IsMacOS) { + $skip = $true + Write-Warning "Invoke-ExcelQuery: Linux and MacOs are not supported. Skipping tests." +}else{ + try { + if ((New-Object system.data.oledb.oledbenumerator).GetElements().SOURCES_NAME -notcontains "Microsoft.ACE.OLEDB.12.0") { + $skip = $true + Write-Warning "Invoke-ExcelQuery: Microsoft.ACE.OLEDB.12.0 provider not found. Skipping tests." + } + } + catch { + $skip = $true + Write-Warning "Invoke-ExcelQuery: Calls to System.Data.OleDb failed. Skipping tests." + } +} + + +Describe "Invoke-ExcelQuery" -Tag "Invoke-ExcelQuery" { + $PSDefaultParameterValues = @{ 'It:Skip' = $skip } + BeforeAll { + $tfp = "$PSScriptRoot\Read-OleDbData.xlsx" + } + Context "Basic Checks" { + It "Should have a valid Test file" { + Test-Path $tfp | Should -Be $true + } + It "Should have the Read-OleDbData command loaded" { + (Get-Command Read-OleDbData -ErrorAction SilentlyContinue) -ne $null | Should -Be $true + } + It "Should have the Invoke-ExcelQuery command loaded" { + (Get-Command Invoke-ExcelQuery -ErrorAction SilentlyContinue) -ne $null | Should -Be $true + } + } + Context "Sheet1`$A1" { + It "Should return 1 result with a value of 1" { + $Results = Invoke-ExcelQuery $tfp "select ROUND(F1) as [A1] from [sheet1`$A1:A1]" + @($Results).length + $Results.A1 | Should -Be 2 + } + } +} diff --git a/__tests__/Read-OleDbDataTests/Read-OleDbData.TestA.sql b/__tests__/Read-OleDbDataTests/Read-OleDbData.TestA.sql new file mode 100644 index 0000000..576c6af --- /dev/null +++ b/__tests__/Read-OleDbDataTests/Read-OleDbData.TestA.sql @@ -0,0 +1,4 @@ +select + ROUND(F1) as [A1] +from + [sheet3$A1:A1] \ No newline at end of file diff --git a/__tests__/Read-OleDbDataTests/Read-OleDbData.TestB.sql b/__tests__/Read-OleDbDataTests/Read-OleDbData.TestB.sql new file mode 100644 index 0000000..9334b90 --- /dev/null +++ b/__tests__/Read-OleDbDataTests/Read-OleDbData.TestB.sql @@ -0,0 +1,7 @@ +select ROUND(F1) as [A1] from [sheet1$A1:A1] +union all select ROUND(F1) as [A1] from [sheet2$A1:A1] +union all select ROUND(F1) as [A1] from [sheet3$A1:A1] +union all select ROUND(F1) as [A1] from [sheet4$A1:A1] +union all select ROUND(F1) as [A1] from [sheet5$A1:A1] +union all select ROUND(F1) as [A1] from [sheet6$A1:A1] +union all select ROUND(F1) as [A1] from [sheet7$A1:A1] \ No newline at end of file diff --git a/__tests__/Read-OleDbDataTests/Read-OleDbData.TestC.sql b/__tests__/Read-OleDbDataTests/Read-OleDbData.TestC.sql new file mode 100644 index 0000000..9e3f5f7 --- /dev/null +++ b/__tests__/Read-OleDbDataTests/Read-OleDbData.TestC.sql @@ -0,0 +1,4 @@ +select + * +from + [sheet1$A1:E10] diff --git a/__tests__/Read-OleDbDataTests/Read-OleDbData.TestD.sql b/__tests__/Read-OleDbDataTests/Read-OleDbData.TestD.sql new file mode 100644 index 0000000..efb169c --- /dev/null +++ b/__tests__/Read-OleDbDataTests/Read-OleDbData.TestD.sql @@ -0,0 +1,10 @@ +select top 1 + 'All A1s' as [A1], + F1 as [Sheet1], + (select F1 FROM [sheet2$a1:a1]) as [Sheet2], + (select F1 FROM [sheet3$a1:a1]) as [Sheet3], + (select F1 FROM [sheet4$a1:a1]) as [Sheet4], + (select F1 FROM [sheet5$a1:a1]) as [Sheet5], + (select F1 FROM [sheet6$a1:a1]) as [Sheet6], + (select F1 FROM [sheet7$a1:a1]) as [Sheet7] +FROM [sheet1$a1:a1] \ No newline at end of file diff --git a/__tests__/Read-OleDbDataTests/Read-OleDbData.TestE.sql b/__tests__/Read-OleDbDataTests/Read-OleDbData.TestE.sql new file mode 100644 index 0000000..bd98cfa --- /dev/null +++ b/__tests__/Read-OleDbDataTests/Read-OleDbData.TestE.sql @@ -0,0 +1,31 @@ +select top 1 + 'All A1s Start from Sheet1' as [A1], + F1 as [Sheet1], + (select F1 FROM [sheet2$a1:a1]) as [Sheet2], + (select F1 FROM [sheet3$a1:a1]) as [Sheet3], + (select F1 FROM [sheet4$a1:a1]) as [Sheet4] +FROM [sheet1$a1:a1] +UNION ALL +select top 1 + 'All A1s Start from Sheet2' as [A1], + (select F1 FROM [sheet1$a1:a1]) as [Sheet1], + F1 as [Sheet2], + (select F1 FROM [sheet3$a1:a1]) as [Sheet3], + (select F1 FROM [sheet4$a1:a1]) as [Sheet4] +FROM [sheet2$a1:a1] +UNION ALL +select top 1 + 'All A1s Start from Sheet3' as [A1], + (select F1 FROM [sheet1$a1:a1]) as [Sheet1], + (select F1 FROM [sheet2$a1:a1]) as [Sheet2], + F1 as [Sheet3], + (select F1 FROM [sheet4$a1:a1]) as [Sheet4] +FROM [sheet3$a1:a1] +UNION ALL +select top 1 + 'All A1s Start from Sheet4' as [A1], + (select F1 FROM [sheet1$a1:a1]) as [Sheet1], + (select F1 FROM [sheet2$a1:a1]) as [Sheet2], + (select F1 FROM [sheet3$a1:a1]) as [Sheet3], + F1 as [Sheet4] +FROM [sheet4$a1:a1] diff --git a/__tests__/Read-OleDbDataTests/Read-OleDbData.Tests.ps1 b/__tests__/Read-OleDbDataTests/Read-OleDbData.Tests.ps1 new file mode 100644 index 0000000..7a9ef5c --- /dev/null +++ b/__tests__/Read-OleDbDataTests/Read-OleDbData.Tests.ps1 @@ -0,0 +1,92 @@ +#Requires -Modules Pester +if (-not (Get-command Import-Excel -ErrorAction SilentlyContinue)) { + Import-Module $PSScriptRoot\..\ImportExcel.psd1 +} + +$skip = $false +if ($IsLinux -or $IsMacOS) { + $skip = $true + Write-Warning "Read-OleDbData: Linux and MacOs are not supported. Skipping tests." +}else{ + try { + if ((New-Object system.data.oledb.oledbenumerator).GetElements().SOURCES_NAME -notcontains "Microsoft.ACE.OLEDB.12.0") { + $skip = $true + Write-Warning "Read-OleDbData: Microsoft.ACE.OLEDB.12.0 provider not found. Skipping tests." + } + } + catch { + $skip = $true + Write-Warning "Read-OleDbData: Calls to System.Data.OleDb failed. Skipping tests." + } +} +Describe "Read-OleDbData" -Tag "Read-OleDbData" { + $PSDefaultParameterValues = @{ 'It:Skip' = $skip } + BeforeAll { + $scriptPath = $PSScriptRoot + $tfp = "$scriptPath\Read-OleDbData.xlsx" + $cs = "Provider=Microsoft.ACE.OLEDB.12.0;Data Source=$tfp;Extended Properties='Excel 12.0 Xml;HDR=NO;IMEX=1;'" + } + Context "Basic Tests" { + It "Should have a valid Test file" { + Test-Path $tfp | Should -Be $true + } + It "Should have the Read-OleDbData command loaded" { + (Get-Command Read-OleDbData -ErrorAction SilentlyContinue) -ne $null | Should -Be $true + } + It "Should be able to open spreadsheet" { + $null = Read-OleDbData -ConnectionString $cs -SqlStatement "select 1" + $true | Should -Be $true + } + It "Should return PSCustomObject for single result" { + #multiple records will come back as Object[], but not going to test for that + $Results = Read-OleDbData -ConnectionString $cs -SqlStatement "select 1" + $Results.GetType().Name | Should -Be 'PSCustomObject' + } + } + Context "Sheet1`$A1" { + It "Should return 1 result with a value of 1" { + $sql = "select ROUND(F1) as [A1] from [sheet1`$A1:A1]" + $Results = Read-OleDbData -ConnectionString $cs -SqlStatement $sql + @($Results).length + $Results.A1 | Should -Be 2 + } + } + Context "Sheet2`$A1" { + It "Should return 1 result with value of 2" { + $sql = "select ROUND(F1) as [A1] from [sheet2`$A1:A1]" + $Results = Read-OleDbData -ConnectionString $cs -SqlStatement $sql + @($Results).length + $Results.A1 | Should -Be 3 + } + } + Context "Sheet3`$A1, Sql from file" { + It "Should return 1 result with value of 3" { + $Results = Read-OleDbData -ConnectionString $cs -SqlStatement (Get-Content "$scriptPath\Read-OleDbData.TestA.sql" -raw) + @($Results).length + $Results.A1 | Should -Be 4 + } + } + Context "Sheets[1-7]`$A1, Sql from file" { + It "Should return 7 result with where sum values 1-6 = value 7" { + $Results = Read-OleDbData -ConnectionString $cs -SqlStatement (Get-Content "$scriptPath\Read-OleDbData.TestB.sql" -raw) + $a = $Results.A1 + $a.length + ($a[0..5] | Measure-Object -sum).sum | Should -Be (7 + $a[6]) + } + } + Context "Sheet1`$:A1:E10, Sql from file" { + #note, this spreadsheet doesn't have the fields populated other than A1, so it will, correctly, return only one value + It "Should return 1 result with value of 1" { + $Results = Read-OleDbData -ConnectionString $cs -SqlStatement (Get-Content "$scriptPath\Read-OleDbData.TestC.sql" -raw) + @($Results).length + $Results.F1 | Should -Be 2 + } + } + Context "When Read-OleDbData.xlsx, select a1 from all sheets as a single record, and sql is in a file" { + It "should return one row with 8 columns" { + $Results = Read-OleDbData -ConnectionString $cs -SqlStatement (Get-Content "$scriptPath\Read-OleDbData.TestD.sql" -raw) + @($Results).length + @($Results.psobject.Properties).length | Should -Be 9 + } + } + Context "When Read-OleDbData.xlsx, select a1 from all sheets as a single record multiple times to create a range, and sql is in a file" { + It "should return 4 records with 5 columns" { + $Results = Read-OleDbData -ConnectionString $cs -SqlStatement (Get-Content "$scriptPath\Read-OleDbData.TestE.sql" -raw) + @($Results).length + @($Results[0].psobject.Properties).length | Should -Be 9 + } + } +} \ No newline at end of file diff --git a/__tests__/Read-OleDbDataTests/Read-OleDbData.xlsx b/__tests__/Read-OleDbDataTests/Read-OleDbData.xlsx new file mode 100644 index 0000000..5458ccf Binary files /dev/null and b/__tests__/Read-OleDbDataTests/Read-OleDbData.xlsx differ