Add basic function, tests, and sample file

This commit is contained in:
Roy Ashbrook
2021-10-29 13:21:52 -04:00
parent 533ed07ac8
commit a942f2133d
8 changed files with 237 additions and 0 deletions

View File

@@ -0,0 +1,4 @@
select
ROUND(F1) as [A1]
from
[sheet3$A1:A1]

View File

@@ -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]

View File

@@ -0,0 +1,4 @@
select
*
from
[sheet1$A1:E10]

View File

@@ -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]

View File

@@ -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]

View File

@@ -0,0 +1,113 @@
. .\Read-OleDbData.ps1
Describe "Read-OleDbData" {
BeforeAll{
$tfp = (Get-ChildItem Read-OleDbData.xlsx).fullname # test file path
$cs = "Provider=Microsoft.ACE.OLEDB.12.0;Data Source=$tfp;Extended Properties='Excel 12.0 Xml;HDR=NO;IMEX=1;'"
}
Context "When Read-OleDbData.xlsx and we want sheet1 a1" {
BeforeAll{
$sql = "select ROUND(F1) as [A1] from [sheet1`$A1:A1]"
$Results = Read-OleDbData -ConnectionString $cs -SqlStatement $sql
}
It "should be PSCustomObject" {
$Results.GetType().Name | Should -Be 'PSCustomObject'
}
It "should have length of 1" {
@($Results).length | Should -Be 1
}
It "should be value of 1" {
$Results.A1 | Should -Be 1
}
}
Context "When Read-OleDbData.xlsx and we want sheet2 a1" {
BeforeAll{
$sql = "select ROUND(F1) as [A1] from [sheet2`$A1:A1]"
$Results = Read-OleDbData -ConnectionString $cs -SqlStatement $sql
}
It "should be PSCustomObject" {
$Results.GetType().Name | Should -Be 'PSCustomObject'
}
It "should have length of 1" {
@($Results).length | Should -Be 1
}
It "should be value of 2" {
$Results.A1 | Should -Be 2
}
}
Context "When Read-OleDbData.xlsx and we want a1 on sheet3 and sql is in a file" {
BeforeAll{
$sql = Get-Content .\Read-OleDbData.TestA.sql -raw
$Results = Read-OleDbData -ConnectionString $cs -SqlStatement $sql
}
It "should be PSCustomObject" {
$Results.GetType().Name | Should -Be 'PSCustomObject'
}
It "should have length of 1" {
@($Results).length | Should -Be 1
}
It "should be value of 2" {
$Results.A1 | Should -Be 3
}
}
Context "When Read-OleDbData.xlsx, we want a1 on sheets1-7, want to validate the values match properly, and sql is in a file" {
BeforeAll{
$sql = Get-Content .\Read-OleDbData.TestB.sql -raw
$Results = Read-OleDbData -ConnectionString $cs -SqlStatement $sql
}
It "should be PSCustomObject" {
$Results[0].GetType().Name | Should -Be 'PSCustomObject'
}
It "should have length of 7" {
@($Results).length | Should -Be 7
}
It "should have data where sum of all initial records match the value of the last record" {
$a = $Results.A1
($a[0..5] | Measure-Object -sum).sum | Should -Be $a[6]
}
}
Context "When Read-OleDbData.xlsx, select range sheet1 A1:E10, and sql is in a file" {
#note, this spreadsheet doesn't have the fields populated other than A1, so it will, correctly, return only one value
BeforeAll{
$sql = Get-Content .\Read-OleDbData.TestC.sql -raw
$Results = Read-OleDbData -ConnectionString $cs -SqlStatement $sql
}
It "should be PSCustomObject" {
$Results.GetType().Name | Should -Be 'PSCustomObject'
}
It "should have length of 1" {
@($Results).length | Should -Be 1
}
}
Context "When Read-OleDbData.xlsx, select a1 from all sheets as a single record, and sql is in a file" {
#note, this spreadsheet doesn't have the fields populated other than A1, so it will, correctly, return only one value
BeforeAll{
$sql = Get-Content .\Read-OleDbData.TestD.sql -raw
$Results = Read-OleDbData -ConnectionString $cs -SqlStatement $sql
}
It "should be PSCustomObject" {
$Results.GetType().Name | Should -Be 'PSCustomObject'
}
It "should have length of 1" {
@($Results).length | Should -Be 1
}
It "should have 8 properties" {
@($Results.psobject.Properties).length | Should -Be 8
}
}
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" {
#note, this spreadsheet doesn't have the fields populated other than A1, so it will, correctly, return only one value
BeforeAll{
$sql = Get-Content .\Read-OleDbData.TestE.sql -raw
$Results = Read-OleDbData -ConnectionString $cs -SqlStatement $sql
}
It "should be Object[]" {
$Results.GetType().Name | Should -Be 'Object[]'
}
It "should have length of 4" {
@($Results).length | Should -Be 4
}
It "should have 5 properties on first record" {
@($Results[0].psobject.Properties).length | Should -Be 5
}
}
}

68
Public/Read-OleDbData.ps1 Normal file
View File

@@ -0,0 +1,68 @@
#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
)
if ($IsLinux -or $IsMacOS) {
#todo: possibly add support for linux/mac somehow. i haven't researched this at all as i
# don't have a need for that and i'm not sure anyone else would in this context, but it does
# appear that once upon a time mono had support for oledb, so maybe it is (or was) supported.
# mono link here: https://www.mono-project.com/archived/ole_db/
Write-Error "Read-OleDbData only runs on Windows"
return
}
#todo: add checks for dotnet libs
#todo: possibly add checks for ace drivers, but maybe only needed if we want to restrict usage.
# i currently just pass through the query and connection string so user is only limited by
# their own machine setup, but they have to check for those dependencies themselves.
#todo: possibly try/catch. i personally do not do this, as i let them throw naturally and catch
# them/handle them outside of this function.
#todo: possibly allow for DataSets instead of just DataTable. I used to use a similar method before
# switching to the sqlcmd module and use datasets as I had multiple tables coming back from
# sql sometimes. i think in this case, it's best to just keep it simple, but maybe someone
# out there would prefer to be able to get multiple tables back. i have not tested that
# with the OleDbDataAdapter.
#todo: possibly just return the datatable, i do it as below because i prefer to simplify the output
# and get rid of the extra fields that come back with the datatable or rows.
$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
}

BIN
Public/Read-OleDbData.xlsx Normal file

Binary file not shown.