From 9969a94309c019cd90d8eb3f873575138e6bf8fa Mon Sep 17 00:00:00 2001 From: jhoneill Date: Wed, 15 Nov 2017 18:04:14 +0000 Subject: [PATCH] Minor Fixes, Set-Row, Set-Column, Send-SQLDataToExcel Export-Excel : * Fixed a typo in the message at line 373. * Now catch an attempt to both clear the sheet and append to it. * Fixed some issues when appending to sheets where the header isn't in row 1 or the data doesn't start in column 1. * Added support for more settings when creating a pivot chart. * Corrected a typo PivotTableName was PivtoTableName in definition of New-PivotTableDefinition Add-ConditionalFormat and Set-Format added to the parameters so each has the choice of working more like the other. Added Set-Row and Set-Column - fill a formula down or across. Added Send-SQLDataToExcel. Insert a rowset and then call Export-Excel for ranges, charts, pivots etc --- AddConditionalFormatting.ps1 | 30 ++++- Examples/SQL+FillColumns+Pivot/Example.ps1 | 88 ++++++++++++ Examples/SQL+FillColumns+Pivot/Example2.ps1 | 22 +++ Export-Excel.ps1 | 51 ++++--- ImportExcel.psm1 | 5 + Send-SqlDataToExcel.ps1 | 132 ++++++++++++++++++ Set-Column.ps1 | 139 +++++++++++++++++++ Set-Row.ps1 | 142 ++++++++++++++++++++ SetFormat.ps1 | 102 ++++++++------ 9 files changed, 647 insertions(+), 64 deletions(-) create mode 100644 Examples/SQL+FillColumns+Pivot/Example.ps1 create mode 100644 Examples/SQL+FillColumns+Pivot/Example2.ps1 create mode 100644 Send-SqlDataToExcel.ps1 create mode 100644 Set-Column.ps1 create mode 100644 Set-Row.ps1 diff --git a/AddConditionalFormatting.ps1 b/AddConditionalFormatting.ps1 index 346407f..fc89b8f 100644 --- a/AddConditionalFormatting.ps1 +++ b/AddConditionalFormatting.ps1 @@ -1,4 +1,4 @@ -Function Add-ConditionalFormatting { +Function Add-ConditionalFormatting { <# .Synopsis Adds contitional formatting to worksheet @@ -19,27 +19,49 @@ Function Add-ConditionalFormatting { #> Param ( #The worksheet where the format is to be applied + [Parameter(Mandatory = $true, ParameterSetName = "NamedRule")] + [Parameter(Mandatory = $true, ParameterSetName = "DataBar")] + [Parameter(Mandatory = $true, ParameterSetName = "ThreeIconSet")] + [Parameter(Mandatory = $true, ParameterSetName = "FourIconSet")] + [Parameter(Mandatory = $true, ParameterSetName = "FiveIconSet")] [OfficeOpenXml.ExcelWorksheet]$WorkSheet , #The area of the worksheet where the format is to be applied + [Parameter(Mandatory = $true, ParameterSetName = "NamedRule")] + [Parameter(Mandatory = $true, ParameterSetName = "DataBar")] + [Parameter(Mandatory = $true, ParameterSetName = "ThreeIconSet")] + [Parameter(Mandatory = $true, ParameterSetName = "FourIconSet")] + [Parameter(Mandatory = $true, ParameterSetName = "FiveIconSet")] [OfficeOpenXml.ExcelAddress]$Range , + #One or more row(s), Column(s) and/or block(s) of cells to format + [Parameter(Mandatory = $true, ParameterSetName = "NamedRuleAddress")] + [Parameter(Mandatory = $true, ParameterSetName = "DataBarAddress")] + [Parameter(Mandatory = $true, ParameterSetName = "ThreeIconSetAddress")] + [Parameter(Mandatory = $true, ParameterSetName = "FourIconSetAddress")] + [Parameter(Mandatory = $true, ParameterSetName = "FiveIconSetAddress")] + $Address , #One of the standard named rules - Top / Bottom / Less than / Greater than / Contains etc [Parameter(Mandatory = $true, ParameterSetName = "NamedRule", Position = 3)] + [Parameter(Mandatory = $true, ParameterSetName = "NamedRuleAddress", Position = 3)] [OfficeOpenXml.ConditionalFormatting.eExcelConditionalFormattingRuleType]$RuleType , #Text colour for matching objects [Alias("ForeGroundColour")] [System.Drawing.Color]$ForeGroundColor, #colour for databar type charts [Parameter(Mandatory = $true, ParameterSetName = "DataBar")] + [Parameter(Mandatory = $true, ParameterSetName = "DataBarAddress")] [Alias("DataBarColour")] [System.Drawing.Color]$DataBarColor, #One of the three-icon set types (e.g. Traffic Lights) [Parameter(Mandatory = $true, ParameterSetName = "ThreeIconSet")] + [Parameter(Mandatory = $true, ParameterSetName = "ThreeIconSetAddress")] [OfficeOpenXml.ConditionalFormatting.eExcelconditionalFormatting3IconsSetType]$ThreeIconsSet, #A four-icon set name [Parameter(Mandatory = $true, ParameterSetName = "FourIconSet")] + [Parameter(Mandatory = $true, ParameterSetName = "FourIconSetAddress")] [OfficeOpenXml.ConditionalFormatting.eExcelconditionalFormatting4IconsSetType]$FourIconsSet, #A five-icon set name [Parameter(Mandatory = $true, ParameterSetName = "FiveIconSet")] + [Parameter(Mandatory = $true, ParameterSetName = "FiveIconSetAddress")] [OfficeOpenXml.ConditionalFormatting.eExcelconditionalFormatting5IconsSetType]$FiveIconsSet, #A value for the condition (e.g. "2000" if the test is 'lessthan 2000') [string]$ConditionValue, @@ -62,7 +84,11 @@ Function Add-ConditionalFormatting { #Strikethrough text of matching items [switch]$StrikeThru ) - + #Allow add conditional formatting to work like Set-Format (with single ADDRESS parameter) split it to get worksheet and Range of cells. + If ($Address -and -not $WorkSheet -and -not $Range) { + $WorkSheet = $Address.Worksheet[0] + $Range = $Address.Address + } If ($ThreeIconsSet) {$rule = $WorkSheet.ConditionalFormatting.AddThreeIconSet($Range , $ThreeIconsSet)} elseif ($FourIconsSet) {$rule = $WorkSheet.ConditionalFormatting.AddFourIconSet( $Range , $FourIconsSet) } elseif ($FiveIconsSet) {$rule = $WorkSheet.ConditionalFormatting.AddFiveIconSet( $Range , $IconType) } diff --git a/Examples/SQL+FillColumns+Pivot/Example.ps1 b/Examples/SQL+FillColumns+Pivot/Example.ps1 new file mode 100644 index 0000000..79b8e8b --- /dev/null +++ b/Examples/SQL+FillColumns+Pivot/Example.ps1 @@ -0,0 +1,88 @@ + ipmo C:\Users\mcp\Documents\GitHub\ImportExcel\ImportExcel.psd1 -Force -Verbose + +$sql = @" + SELECT rootfile.baseName , rootfile.extension , Image.fileWidth AS width , image.fileHeight AS height , + metadata.dateDay , metadata.dateMonth , metadata.dateYear , Image.captureTime AS dateTaken, + metadata.hasGPS , metadata.GPSLatitude , metadata.GPSLongitude , + metadata.focalLength , metadata.flashFired , metadata.ISOSpeedRating AS ISOSpeed, + metadata.Aperture AS apertureValue , metadata.ShutterSpeed AS shutterSpeedValue, + Image.bitdepth , image.colorLabels , + Camera.Value AS cameraModel , LensRef.value AS lensModel + FROM Adobe_images image + JOIN AgLibraryFile rootFile ON rootfile.id_local = image.rootFile + JOIN AgharvestedExifMetadata metadata ON image.id_local = metadata.image + LEFT JOIN AgInternedExifLens LensRef ON LensRef.id_Local = metadata.lensRef + LEFT JOIN AgInternedExifCameraModel Camera ON Camera.id_local = metadata.cameraModelRef +"@ +`` +#Sql Statement gets 20 columns of data from Adobe lightroom database +#Define a pivot table and chart for total pictures with each lens. + +$pt = @{"LensPivot" = @{ "PivotTableName" = "LensPivot"; + "SourceWorkSheet" = "Sheet1" ; + "PivotRows" = "LensModel" ; + "PivotData" = @{"basename" = "Count"} ; + "IncludePivotChart" = $true ; + "NoLegend" = $true ; + "ShowPercent" = $true ; + "ChartType" = "Pie" ; + "ChartTitle" = "Split by Lens" } +} + +#we want to add 3 columns, translate Apperture value and Shutter speed value into familar f/ and seconds notation, and use these and ISO to calculate EV level +$Avalue = {"=IF(P$ROW>6.63,TEXT(ROUND(Sqrt(Power(2,O$ROW)),1),`"`"`"f/`"`"0.0`")," + + "TEXT(ROUND(Sqrt(Power(2,O$ROW)),1),`"`"`"f/`"`"0.0`"))"} +$Svalue = {"=IF(P$ROW>2,TEXT(ROUND(POWER(2,P$ROW),0),`"`"`"1/`"`"0`"`"sec`"`"`"),"+ + "IF(P$ROW>3.32,TEXT(ROUND(1/POWER(2,P$ROW),2),`"0.0`"`"Sec`"`"`"),"+ + "TEXT(ROUND(1/POWER(2,P$ROW),2),`"0`"`"Sec`"`"`")))"} +$evValue = {"=ROUND(P$Row+O$Row-(LOG(N$Row/100,2)),0)" } + +#remove and recreate the file +Remove-Item -Path "~\Documents\temp.xlsx" -ErrorAction SilentlyContinue + +#Open a connection to the ODBC source "LR" (which points to the SQLLite DB for Lightroom), run the SQL query, and drop into Excel - in sheet1, autosizing columns. +$e = Send-SQLDataToExcel -Path "~\Documents\temp.xlsx" -WorkSheetname "Sheet1" -Connection "DSN=LR" -SQL $sql -AutoSize -Passthru + +#Add columns, then format them and hide the ones which aren't of interest. +Set-Column -Worksheet $e.workbook.Worksheets["sheet1"] -Column 21 -Value $Avalue -Heading "Apperture" +Set-Column -Worksheet $e.workbook.Worksheets["sheet1"] -Column 22 -Value $Svalue -Heading "Shutter" +Set-Column -Worksheet $e.workbook.Worksheets["sheet1"] -Column 23 -Value $Evvalue -Heading "Ev" +Set-Format -Address $e.workbook.Worksheets["sheet1" ].Column(21) -HorizontalAlignment Left -AutoFit +Set-Format -Address $e.workbook.Worksheets["sheet1" ].Column(22) -HorizontalAlignment Right -AutoFit +@(5,6,7,13,15,16,17,18) | ForEach-Object { + Set-Format -Address $e.workbook.Worksheets["sheet1" ].Column($_) -Hidden +} + +#Center the column labels. +Set-Format -Address $e.workbook.Worksheets["sheet1" ].Row(1) -HorizontalAlignment Center + +#Format the data as a nice Table, Create the pivot table & chart defined above, show the file in Excel in excel after saving. +Export-Excel -ExcelPackage $e -WorkSheetname "sheet1" -TableName "Table" -PivotTableDefinition $pt -Show + +############################################################ + +Remove-Item .\demo3.xlsx +#Database query to get race wins, Poles and fastest lapes for the 25 best drivers; we already have a connection to the DB in $dbSessions +$session = $DbSessions["f1"] +$SQL = @" + SELECT TOP 25 DriverName, + Count(RaceDate) AS Races, + Count(Win) AS Wins, + Count(Pole) AS Poles, + Count(FastestLap) AS Fastlaps + FROM Results + GROUP BY DriverName + ORDER BY (Count(win)) DESC +"@ + +#Run the query and put the results in workshet "Winners", autosize the columns and hold on to the ExcelPackage object +$Excel = Send-SQLDataToExcel -SQL $sql -Session $session -path .\demo3.xlsx -WorkSheetname "Winners" -AutoSize -Passthru +#Create and format columns for the ratio of Wins to poles and fast laps. +Set-Column -ExcelPackage $Excel -WorkSheetname "Winners" -column 6 -Heading "WinsToPoles" -Value {"=D$row/C$row"} +Set-Column -ExcelPackage $Excel -WorkSheetname "Winners" -column 7 -Heading "WinsToFast" -Value {"=E$row/C$row"} +6..7 | ForEach-Object { + Set-Format -Address $Excel.Workbook.Worksheets["Winners"].column($_) -NumberFormat "0.0%" -AutoFit } +#Define a chart to show the relationship of lest on an XY Grid, create the ranges required in the, add the chart and show the file in Excel in excel after saving. +$chart = New-ExcelChart -NoLegend -ChartType XYScatter -XRange WinsToFast -YRange WinsToPoles -ShowCategory -Column 7 -Width 2000 -Height 700 +Export-Excel -ExcelPackage $Excel -WorkSheetname "Winners" -AutoNameRange -ExcelChartDefinition $chart -Show + diff --git a/Examples/SQL+FillColumns+Pivot/Example2.ps1 b/Examples/SQL+FillColumns+Pivot/Example2.ps1 new file mode 100644 index 0000000..c1e7322 --- /dev/null +++ b/Examples/SQL+FillColumns+Pivot/Example2.ps1 @@ -0,0 +1,22 @@ +ipmo C:\Users\mcp\Documents\GitHub\ImportExcel\ImportExcel.psd1 -Force + +Get-SQL -Session f1 -Excel -Connection C:\Users\mcp\OneDrive\Public\F1\f1Results.xlsx -showtables -Verbose + +del .\demo3.xlsx +$session = $DbSessions["f1"] + +$SQL = "SELECT top 25 DriverName, Count(RaceDate) as Races , + Count(Win) as Wins, Count(Pole) as Poles, Count(FastestLap) as Fastlaps + FROM Results GROUP BY DriverName + order by (count(win)) desc" +$Excel = Send-SQLDataToExcel -SQL $sql -Session $session -path .\demo3.xlsx -WorkSheetname "Winners" -AutoSize -AutoNameRange -BoldTopRow -FreezeTopRow -Passthru + +$ws = $Excel.Workbook.Worksheets["Winners"] + +Set-Row -Worksheet $ws -Heading "Average" -Value {"=Average($columnName`2:$columnName$endrow)"} -NumberFormat "0.0" -Bold +Set-Column -Worksheet $ws -Heading "WinsToPoles" -Value {"=D$row/C$row"} -Column 6 -AutoSize -AutoNameRange +Set-Column -Worksheet $ws -Heading "WinsToFast" -Value {"=E$row/C$row"} -Column 7 -AutoSize -AutoNameRange + +Set-Format -WorkSheet $ws -Range "F2:G50" -NumberFormat "0.0%" +$chart = New-ExcelChart -NoLegend -ChartType XYScatter -XRange WinsToFast -YRange WinsToPoles -Column 7 -Width 2000 -Height 700 -Title "Poles vs fastlaps" +Export-Excel -ExcelPackage $Excel -WorkSheetname "Winners" -ExcelChartDefinition $chart -Show \ No newline at end of file diff --git a/Export-Excel.ps1 b/Export-Excel.ps1 index 63e6222..0090255 100644 --- a/Export-Excel.ps1 +++ b/Export-Excel.ps1 @@ -370,7 +370,7 @@ throw 'Tablename is null or empty.' } elseif ($_[0] -notmatch '[a-z]') { - throw 'Tablename start with invalid character.' + throw 'Tablename starts with an invalid character.' } else { $true @@ -524,10 +524,9 @@ Get-Process excel -ErrorAction Ignore | Stop-Process while (Get-Process excel -ErrorAction Ignore) {} } - Try { $script:Header = $null - + if ($append -and $clearSheet) {throw "You can't use -Append AND -ClearSheet."} if ($KillExcel) { Stop-ExcelProcess } @@ -554,7 +553,7 @@ $pkg = New-Object OfficeOpenXml.ExcelPackage $Path } - + [OfficeOpenXml.ExcelWorksheet]$ws = $pkg | Add-WorkSheet -WorkSheetname $WorkSheetname -NoClobber:$NoClobber -ClearSheet:$ClearSheet #Add worksheet doesn't take any action for -noClobber foreach ($format in $ConditionalFormat ) { $target = "Add$($format.Formatter)" @@ -566,14 +565,16 @@ $headerRange = $ws.Dimension.Address -replace "\d+$","1" #if there is a title or anything else above the header row, specifying StartRow will skip it. if ($StartRow -ne 1) {$headerRange = $headerRange -replace "1","$StartRow"} - $script:Header = $ws.Cells[$headerrange].Value + #$script:Header = $ws.Cells[$headerrange].Value + #using a slightly odd syntax otherwise header ends up as a 2D array + $ws.Cells[$headerRange].Value | foreach -Begin {$Script:header = @()} -Process {$Script:header += $_ } $row = $ws.Dimension.Rows Write-Debug -Message ("Appending: headers are " + ($script:Header -join ", ") + "Start row $row") } elseif($Title) { #Can only add a title if not appending $Row = $StartRow Add-Title - $Row ++ + $Row ++ ; $startRow ++ } else { $Row = $StartRow @@ -652,14 +653,19 @@ End { Try { if ($AutoNameRange) { - $totalRows = $ws.Dimension.Rows + if (-not $script:header) { + $headerRange = $ws.Dimension.Address -replace "\d+$","1" + #if there is a title or anything else above the header row, specifying StartRow will skip it. + if ($StartRow -ne 1) {$headerRange = $headerRange -replace "1","$StartRow"} + #using a slightly odd syntax otherwise header ends up as a 2D array + $ws.Cells[$headerRange].Value | foreach -Begin {$Script:header = @()} -Process {$Script:header += $_ } + } + $totalRows = $ws.Dimension.End.Row $totalColumns = $ws.Dimension.Columns - foreach ($c in 0..($totalColumns - 1)) { $targetRangeName = "$($script:Header[$c])" - - $targetColumn = $c + 1 - $theCell = $ws.Cells[2, $targetColumn, $totalRows, $targetColumn ] + $targetColumn = $c + $StartColumn + $theCell = $ws.Cells[($startrow+1), $targetColumn, $totalRows , $targetColumn ] $ws.Names.Add($targetRangeName, $theCell) | Out-Null if ([OfficeOpenXml.FormulaParsing.ExcelUtilities.ExcelAddressUtil]::IsValidAddress($targetRangeName)) { @@ -669,7 +675,7 @@ } if ($Title) { - $startAddress = "A2" + $startAddress = $ws.Dimension.Start.address -replace "$($ws.Dimension.Start.row)`$", "$($ws.Dimension.Start.row + 1)" } else { $startAddress = $ws.Dimension.Start.Address @@ -685,9 +691,7 @@ if (-not [String]::IsNullOrEmpty($TableName)) { $csr = $StartRow - if ($Title) { - $csr += 1 - } + $csc = $StartColumn $cer = $ws.Dimension.End.Row $cec = $ws.Dimension.End.Column # was $script:Header.Count @@ -764,6 +768,10 @@ $chart = $wsPivot.Drawings.AddChart('PivotChart', $ChartType, $pivotTable) $chart.SetPosition(0, 0, 4, 0) #Changed position to top row, next to a chart which doesn't pivot on columns $chart.SetSize(600, 400) + $chart.DataLabel.ShowCategory = [boolean]$item.value.ShowCategory + $chart.DataLabel.ShowPercent = [boolean]$item.value.ShowPercent + if ([boolean]$item.value.NoLegend) {$chart.Legend.Remove()} + if ($item.value.ChartTitle) {$chart.Title.Text = $item.value.chartTitle} } } } @@ -971,17 +979,22 @@ function New-PivotTableDefinition { param( [Parameter(Mandatory)] - $PivtoTableName, + [Alias("PivtoTableName")]#Previous typo - use alias to avoid breaking scripts + $PivotTableName, $SourceWorkSheet, $PivotRows, [hashtable]$PivotData, $PivotColumns, [Switch]$IncludePivotChart, - [OfficeOpenXml.Drawing.Chart.eChartType]$ChartType = 'Pie' + [OfficeOpenXml.Drawing.Chart.eChartType]$ChartType = 'Pie', + [Switch]$NoLegend, + [Switch]$ShowCategory, + [Switch]$ShowPercent, + [String]$ChartTitle ) $parameters = @{} + $PSBoundParameters - $parameters.Remove('PivtoTableName') + $parameters.Remove('PivotTableName') - @{$PivtoTableName=$parameters} + @{$PivotTableName=$parameters} } \ No newline at end of file diff --git a/ImportExcel.psm1 b/ImportExcel.psm1 index 191de6c..250a659 100644 --- a/ImportExcel.psm1 +++ b/ImportExcel.psm1 @@ -24,11 +24,16 @@ . $PSScriptRoot\New-PSItem.ps1 . $PSScriptRoot\Open-ExcelPackage.ps1 . $PSScriptRoot\Pivot.ps1 +. $PSScriptRoot\Send-SQLDataToExcel.ps1 . $PSScriptRoot\Set-CellStyle.ps1 +. $PSScriptRoot\Set-Column.ps1 +. $PSScriptRoot\Set-Row.ps1 . $PSScriptRoot\SetFormat.ps1 . $PSScriptRoot\TrackingUtils.ps1 . $PSScriptRoot\Update-FirstObjectProperties.ps1 +New-Alias -Name Use-ExcelData -Value "ConvertFrom-ExcelData" + if ($PSVersionTable.PSVersion.Major -ge 5) { . $PSScriptRoot\Plot.ps1 diff --git a/Send-SqlDataToExcel.ps1 b/Send-SqlDataToExcel.ps1 new file mode 100644 index 0000000..241d625 --- /dev/null +++ b/Send-SqlDataToExcel.ps1 @@ -0,0 +1,132 @@ +Function Send-SQLDataToExcel { +<# + .Synopsis + Runs a SQL query and inserts the results into an ExcelSheet, more efficiently than sending it via Export-Excel + .Description + This command takes either an object representing a session with a SQL server or ODBC database, or a connection String to make one. + It the runs a SQL command, and inserts the rows of data returned into a worksheet. + It takes most of the parameters of Export-Excel, but it is more efficient than getting dataRows and piping them into Export-Excel, + data-rows have additional properties which need to be stripped off. + .Example + C:\> Send-SQLDataToExcel -MsSQLserver -Connection localhost -SQL "select name,type,type_desc from [master].[sys].[all_objects]" -Path .\temp.xlsx -WorkSheetname master -AutoSize -FreezeTopRow -AutoFilter -BoldTopRow + Connects to the local SQL server and selects 3 columns from [Sys].[all_objects] and exports then to a sheet named master with some basic header manager + .Example + C:\> $SQL="SELECT top 25 DriverName, Count(RaceDate) as Races, Count(Win) as Wins, Count(Pole) as Poles, Count(FastestLap) as Fastlaps FROM Results GROUP BY DriverName ORDER BY (count(win)) DESC" + C:\> $Connection = 'Driver={Microsoft Excel Driver (*.xls, *.xlsx, *.xlsm, *.xlsb)};DriverId=790;ReadOnly=0;Dbq=C:\users\James\Documents\f1Results.xlsx;' + C:\> Send-SQLDataToExcel -Connection $connection -SQL $sql -path .\demo4.xlsx -WorkSheetname "Winners" -AutoSize -AutoNameRange + + This declares a SQL statement and creates an ODBC connection string to read from an Excel file, it then runs the statement and outputs the resulting data to a new spreadsheet. + .Example + C:\> Send-SQLDataToExcel -path .\demo4.xlsx -WorkSheetname "LR" -Connection "DSN=LR" -sql "SELECT name AS CollectionName FROM AgLibraryCollection Collection ORDER BY CollectionName" + + This example uses an Existing ODBC datasource name "LR" which maps to an adobe lightroom database and gets a list of collection names into a worksheet + + + +#> + param ( + #Database connection string; either DSN=ODBC_Data_Source_Name, a full odbc or SQL Connection string, or the name of a SQL server + [Parameter(ParameterSetName="SQLConnection", Mandatory=$true)] + [Parameter(ParameterSetName="ODBCConnection",Mandatory=$true)] + $Connection, + #A pre-existing database session object + [Parameter(ParameterSetName="ExistingSession",Mandatory=$true)] + [System.Data.Common.DbConnection]$Session, + #Specifies the connection string is for SQL server not ODBC + [Parameter(ParameterSetName="SQLConnection",Mandatory=$true)] + [switch]$MsSQLserver, + #Switches to a specific database on a SQL server + [Parameter(ParameterSetName="SQLConnection")] + [switch]$DataBase, + #The SQL query to run + [Parameter(Mandatory=$true)] + [string]$SQL, + $Path, + [String]$WorkSheetname = 'Sheet1', + [Switch]$KillExcel, + #If Specified, open the file created. + [Switch]$Show, + [String]$Title, + [OfficeOpenXml.Style.ExcelFillStyle]$TitleFillPattern = 'None', + [Switch]$TitleBold, + [Int]$TitleSize = 22, + [System.Drawing.Color]$TitleBackgroundColor, + [String]$Password, + [String[]]$PivotRows, + [String[]]$PivotColumns, + $PivotData, + [Switch]$PivotDataToColumn, + [Hashtable]$PivotTableDefinition, + [Switch]$IncludePivotChart, + [OfficeOpenXml.Drawing.Chart.eChartType]$ChartType = 'Pie', + [Switch]$NoLegend, + [Switch]$ShowCategory, + [Switch]$ShowPercent, + [Switch]$AutoSize, + [Switch]$FreezeTopRow, + [Switch]$FreezeFirstColumn, + [Switch]$FreezeTopRowFirstColumn, + [Int[]]$FreezePane, + [Switch]$AutoFilter, + [Switch]$BoldTopRow, + [Switch]$NoHeader, + [String]$RangeName, + [String]$TableName, + [OfficeOpenXml.Table.TableStyles]$TableStyle = 'Medium6', + [Object[]]$ExcelChartDefinition, + [Switch]$AutoNameRange, + [Object[]]$ConditionalFormat, + [Object[]]$ConditionalText, + [ScriptBlock]$CellStyleSB, + [Int]$StartRow = 1, + [Int]$StartColumn = 1, + #If Specified, return an ExcelPackage object to allow further work to be done on the file. + [Switch]$Passthru + ) + + if ($KillExcel) { + Get-Process excel -ErrorAction Ignore | Stop-Process + while (Get-Process excel -ErrorAction Ignore) {} + } + + #We were either given a session object or a connection string (with, optionally a MSSQLServer parameter) + # If we got -MSSQLServer, create a SQL connection, if we didn't but we got -Connection create an ODBC connection + if ($MsSQLserver) { + if ($connection -notmatch "=") {$Connection = "server=$Connection;trusted_connection=true;timeout=60"} + $Session = New-Object -TypeName System.Data.SqlClient.SqlConnection -ArgumentList $Connection + if ($DataBase) {$Session.ChangeDatabase($DataBase) } + } + elseif ($Connection) { + $Session = New-Object -TypeName System.Data.Odbc.OdbcConnection -ArgumentList $Connection ; $Session.ConnectionTimeout = 30 + } + + #A session was either passed in or just created. If it's a SQL one make a SQL DataAdapter, otherwise make an ODBC one + if ($Session.gettype().name -match "SqlConnection") { + $dataAdapter = New-Object -TypeName System.Data.SqlClient.SqlDataAdapter -ArgumentList ( + New-Object -TypeName System.Data.SqlClient.SqlCommand -ArgumentList $sql, $Session) + } + else { + $dataAdapter = New-Object -TypeName System.Data.Odbc.OdbcDataAdapter -ArgumentList ( + New-Object -TypeName System.Data.Odbc.OdbcCommand -ArgumentList $sql, $Session ) + } + + #Both adapter types output the same kind of table, create one and fill it from the adapter + $dataTable = New-Object -TypeName System.Data.DataTable + $rowCount = $dataAdapter.fill($dataTable) + Write-Verbose "Query returned $rowcount row(s)" + + #ExportExcel user a -NoHeader parameter so that's what we use here, but needs to be the other way around. + $PrintHeaders = -not $NoHeader + if ($Title) {$r = $StartRow +1 } + else {$r = $StartRow} + #Get our Excel sheet and fill it with the data + $excelPackage = Export-Excel -Path $Path -WorkSheetname $WorkSheetname -PassThru + $excelPackage.Workbook.Worksheets[$WorkSheetname].Cells[$r,$StartColumn].LoadFromDataTable($dataTable, $PrintHeaders ) | Out-Null + + #Call export-excel with any parameters which don't relate to the SQL query + "Connection", "Session", "MsSQLserver", "Destination" , "sql" ,"Path" | foreach-object {$null = $PSBoundParameters.Remove($_) } + Export-Excel -ExcelPackage $excelPackage @PSBoundParameters + + #If we were not passed a session close the session we created. + if ($Connection) {$Session.close() } +} diff --git a/Set-Column.ps1 b/Set-Column.ps1 new file mode 100644 index 0000000..f195cf8 --- /dev/null +++ b/Set-Column.ps1 @@ -0,0 +1,139 @@ +Function Set-Column { +<# + .SYNOPSIS + Adds a column to the existing data area in an Excel sheet, fills values and sets formatting + .DESCRIPTION + Set-Column takes a value which is either string containing a value or formula or a scriptblock + which evaluates to a string, and optionally a column number and fills that value down the column. + A column name can be specified and the new column can be made a named range. + The column can be formatted. + .Example + C:> Set-Column -Worksheet $ws -Heading "WinsToFastLaps" -Value {"=E$row/C$row"} -Column 7 -AutoSize -AutoNameRange + Here $WS already contains a worksheet which contains counts of races won and fastest laps recorded by racing drivers (in columns C and E) + Set-Column specifies that Column 7 should have a heading of "WinsToFastLaps" and the data cells should contain =E2/C2 , =E3/C3 + the data celss should become a named range, which will also be "WinsToFastLaps" the column width will be set automatically + +#> +[cmdletbinding()] + Param ( + [Parameter(ParameterSetName="Package",Mandatory=$true)] + [OfficeOpenXml.ExcelPackage]$ExcelPackage, + #Sheet to update + [Parameter(ParameterSetName="Package")] + $Worksheetname = "Sheet1", + [Parameter(ParameterSetName="sheet",Mandatory=$true)] + [OfficeOpenXml.ExcelWorksheet] + $Worksheet, + #Column to fill down - first column is 1. 0 will be interpreted as first unused column + $Column = 0 , + [Int]$StartRow , + #value, formula or script block for to fill in. Script block can use $row, $column [number], $ColumnName [letter(s)], $startRow, $startColumn, $endRow, $endColumn + [parameter(Mandatory=$true)] + $Value , + #Optional column heading + $Heading , + #Number format to apply to cells e.g. "dd/MM/yyyy HH:mm", "£#,##0.00;[Red]-£#,##0.00", "0.00%" , "##/##" , "0.0E+0" etc + [Alias("NFormat")] + $NumberFormat, + #Style of border to draw around the row + [OfficeOpenXml.Style.ExcelBorderStyle]$BorderAround, + #Colour for the text - if none specified it will be left as it it is + [System.Drawing.Color]$FontColor, + #Make text bold + [switch]$Bold, + #Make text italic + [switch]$Italic, + #Underline the text using the underline style in -underline type + [switch]$Underline, + #Should Underline use single or double, normal or accounting mode : default is single normal + [OfficeOpenXml.Style.ExcelUnderLineType]$UnderLineType = [OfficeOpenXml.Style.ExcelUnderLineType]::Single, + #StrikeThrough text + [switch]$StrikeThru, + #Subscript or superscript + [OfficeOpenXml.Style.ExcelVerticalAlignmentFont]$FontShift, + #Font to use - Excel defaults to Calibri + [String]$FontName, + #Point size for the text + [float]$FontSize, + #Change background colour + [System.Drawing.Color]$BackgroundColor, + #Background pattern - solid by default + [OfficeOpenXml.Style.ExcelFillStyle]$BackgroundPattern = [OfficeOpenXml.Style.ExcelFillStyle]::Solid , + #Secondary colour for background pattern + [Alias("PatternColour")] + [System.Drawing.Color]$PatternColor, + #Turn on text wrapping + [switch]$WrapText, + #Position cell contents to left, right or centre ... + [OfficeOpenXml.Style.ExcelHorizontalAlignment]$HorizontalAlignment, + #Position cell contents to top bottom or centre + [OfficeOpenXml.Style.ExcelVerticalAlignment]$VerticalAlignment, + #Degrees to rotate text. Up to +90 for anti-clockwise ("upwards"), or to -90 for clockwise. + [ValidateRange(-90, 90)] + [int]$TextRotation , + #Autofit cells to width + [Alias("AutoFit")] + [Switch]$AutoSize, + #Set cells to a fixed width, ignored if Autosize is specified + [float]$Width, + #Set the inserted data to be a named range (ignored if header is not specified) d + [Switch]$AutoNameRange, + [switch]$PassThru + ) + #if we were passed a package object and a worksheet name , get the worksheet. + if ($ExcelPackage) {$Worksheet = $ExcelPackage.Workbook.Worksheets[$Worksheetname] } + + #In a script block to build a formula, we may want any of corners or the columnname, + #if column and startrow aren't specified, assume first unused column, and first row + if (-not $StartRow) {$startRow = $Worksheet.Dimension.Start.Row } + $StartColumn = $Worksheet.Dimension.Start.Column + $endColumn = $Worksheet.Dimension.End.Column + $endRow = $Worksheet.Dimension.End.Row + if ($Column -lt 2 ) {$Column = $endColumn + 1 } + $ColumnName = [OfficeOpenXml.ExcelCellAddress]::new(1,$column).Address -replace "1","" + + Write-Verbose -Message "Updating Column $ColumnName" + #If there is a heading, insert it and use it as the name for a range (if we're creating one) + if ($Heading) { + $Worksheet.Cells[$StartRow, $Column].Value = $heading + $startRow ++ + if ($AutoNameRange) { $Worksheet.Names.Add( $heading, ($Worksheet.Cells[$startrow, $Column, $endRow, $Column]) ) | Out-Null } + } + #Fill in the data + if ($value) { foreach ($row in ($StartRow.. $endRow)) { + if ($Value -is [scriptblock]) { #re-create the script block otherwise variables from this function are out of scope. + $cellData = & ([scriptblock]::create( $Value )) + Write-Verbose -Message $cellData + } + else { $cellData = $Value} + if ($cellData -match "^=") { $Worksheet.Cells[$Row, $Column].Formula = $cellData } + else { $Worksheet.Cells[$Row, $Column].Value = $cellData } + if ($cellData -is [datetime]) { $Worksheet.Cells[$Row, $Column].Style.Numberformat.Format = 'm/d/yy h:mm' } + }} + #region Apply formatting + if ($Underline) { + $Worksheet.Column( $Column).Style.Font.UnderLine = $true + $Worksheet.Column( $Column).Style.Font.UnderLineType = $UnderLineType + } + if ($Bold) { $Worksheet.Column( $Column).Style.Font.Bold = $true } + if ($Italic) { $Worksheet.Column( $Column).Style.Font.Italic = $true } + if ($StrikeThru) { $Worksheet.Column( $Column).Style.Font.Strike = $true } + if ($FontShift) { $Worksheet.Column( $Column).Style.Font.VerticalAlign = $FontShift } + if ($NumberFormat) { $Worksheet.Column( $Column).Style.Numberformat.Format = $NumberFormat } + if ($TextRotation) { $Worksheet.Column( $Column).Style.TextRotation = $TextRotation } + if ($WrapText) { $Worksheet.Column( $Column).Style.WrapText = $true } + if ($HorizontalAlignment) { $Worksheet.Column( $Column).Style.HorizontalAlignment = $HorizontalAlignment} + if ($VerticalAlignment) { $Worksheet.Column( $Column).Style.VerticalAlignment = $VerticalAlignment } + if ($FontColor) { $Worksheet.Column( $Column).Style.Font.Color.SetColor( $FontColor ) } + if ($BorderRound) { $Worksheet.Column( $Column).Style.Border.BorderAround( $BorderAround ) } + if ($BackgroundColor) { + $Worksheet.Column( $Column).Style.Fill.PatternType = $BackgroundPattern + $Worksheet.Column( $Column).Style.Fill.BackgroundColor.SetColor($BackgroundColor ) + if ($PatternColor) { $Worksheet.Column( $Column).Style.Fill.PatternColor.SetColor( $PatternColor ) } + } + if ($Autosize) { $Worksheet.Column( $Column).AutoFit() } + elseif ($Width) { $Worksheet.Column( $Column).Width = $Width } + #endregion + #return the new data if -passthru was specified. + if ($passThru) { $Worksheet.Column( $Column)} +} \ No newline at end of file diff --git a/Set-Row.ps1 b/Set-Row.ps1 new file mode 100644 index 0000000..f1e43be --- /dev/null +++ b/Set-Row.ps1 @@ -0,0 +1,142 @@ +Function Set-Row { +<# +.Synopsis + Fills values into a row in a Excel spreadsheet +.Description + Set-Row accepts either a Worksheet object or an Excel package object returned by Export-Excel and the name of a sheet, + and inserts the chosen contents into a row of the sheet. + The contents can be a constant "42" , a formula or a script block which is converted into a constant or formula. + The first cell of the row can optional be given a heading. +.Example + Set-row -Worksheet $ws -Heading Total -Value {"=sum($columnName`2:$columnName$endrow)" } + + $Ws contains a worksheet object, and no Row number is specified so Set-Row will select the next row after the end of the data in the sheet + The first cell will contain "Total", and each other cell will contain + =Sum(xx2:xx99) - where xx is the column name, and 99 is the last row of data. + Note the use of `2 to Prevent 2 becoming part of the variable "ColumnName" + The script block can use $row, $column, $ColumnName, $startRow/Column $endRow/Column + + +#> +[cmdletbinding()] + Param ( + #An Excel package object - e.g. from Export-Excel -passthru - requires a sheet name + [Parameter(ParameterSetName="Package",Mandatory=$true)] + [OfficeOpenXml.ExcelPackage]$ExcelPackage, + #the name to update in the package + [Parameter(ParameterSetName="Package")] + $Worksheetname = "Sheet1", + #A worksheet object + [Parameter(ParameterSetName="sheet",Mandatory=$true)] + [OfficeOpenXml.Excelworksheet] + $Worksheet, + #Row to fill right - first row is 1. 0 will be interpreted as first unused row + $Row = 0 , + #Position in the row to start from + [Int]$StartColumn, + #value, formula or script block for to fill in. Script block can use $row, $column [number], $ColumnName [letter(s)], $startRow, $startColumn, $endRow, $endColumn + [parameter(Mandatory=$true)] + $Value, + #Optional Row heading + $Heading , + #Number format to apply to cells e.g. "dd/MM/yyyy HH:mm", "£#,##0.00;[Red]-£#,##0.00", "0.00%" , "##/##" , "0.0E+0" etc + [Alias("NFormat")] + $NumberFormat, + #Style of border to draw around the row + [OfficeOpenXml.Style.ExcelBorderStyle]$BorderAround, + #Colour for the text - if none specified it will be left as it it is + [System.Drawing.Color]$FontColor, + #Make text bold + [switch]$Bold, + #Make text italic + [switch]$Italic, + #Underline the text using the underline style in -underline type + [switch]$Underline, + #Should Underline use single or double, normal or accounting mode : default is single normal + [OfficeOpenXml.Style.ExcelUnderLineType]$UnderLineType = [OfficeOpenXml.Style.ExcelUnderLineType]::Single, + #StrikeThrough text + [switch]$StrikeThru, + #Subscript or superscript + [OfficeOpenXml.Style.ExcelVerticalAlignmentFont]$FontShift, + #Font to use - Excel defaults to Calibri + [String]$FontName, + #Point size for the text + [float]$FontSize, + #Change background colour + [System.Drawing.Color]$BackgroundColor, + #Background pattern - solid by default + [OfficeOpenXml.Style.ExcelFillStyle]$BackgroundPattern = [OfficeOpenXml.Style.ExcelFillStyle]::Solid , + #Secondary colour for background pattern + [Alias("PatternColour")] + [System.Drawing.Color]$PatternColor, + #Turn on text wrapping + [switch]$WrapText, + #Position cell contents to left, right or centre ... + [OfficeOpenXml.Style.ExcelHorizontalAlignment]$HorizontalAlignment, + #Position cell contents to top bottom or centre + [OfficeOpenXml.Style.ExcelVerticalAlignment]$VerticalAlignment, + #Degrees to rotate text. Up to +90 for anti-clockwise ("upwards"), or to -90 for clockwise. + [ValidateRange(-90, 90)] + [int]$TextRotation , + #Set cells to a fixed hieght + [float]$Height, + [switch]$PassThru + ) + + #if we were passed a package object and a worksheet name , get the worksheet. + if ($ExcelPackage) {$Worksheet = $ExcelPackage.Workbook.worksheets[$Worksheetname] } + + #In a script block to build a formula, we may want any of corners or the columnname, + #if row and start column aren't specified assume first unused row, and first column + if (-not $StartColumn) {$StartColumn = $Worksheet.Dimension.Start.Column } + $startRow = $Worksheet.Dimension.Start.Row + 1 + $endColumn = $Worksheet.Dimension.End.Column + $endRow = $Worksheet.Dimension.End.Row + if ($Row -lt 2 ) {$Row = $endRow + 1 } + + Write-Verbose -Message "Updating Row $Row" + #Add a row label + if ($Heading) { + $Worksheet.Cells[$Row, $StartColumn].Value = $Heading + $StartColumn ++ + } + #Fill in the data + if ($value) {foreach ($column in ($StartColumn..$EndColumn)) { + #We might want the column name in a script block + $ColumnName = [OfficeOpenXml.ExcelCellAddress]::new(1,$column).Address -replace "1","" + if ($Value -is [scriptblock] ) { + #re-create the script block otherwise variables from this function are out of scope. + $cellData = & ([scriptblock]::create( $Value )) + Write-Verbose -Message $cellData + } + else{$cellData = $Value} + if ($cellData -match "^=") { $Worksheet.Cells[$Row, $column].Formula = $cellData } + else { $Worksheet.Cells[$Row, $Column].Value = $cellData } + if ($cellData -is [datetime]) { $Worksheet.Cells[$Row, $Column].Style.Numberformat.Format = 'm/d/yy h:mm' } + }} + #region Apply formatting + if ($Underline) { + $worksheet.row( $Row ).Style.Font.UnderLine = $true + $worksheet.row( $Row ).Style.Font.UnderLineType = $UnderLineType + } + if ($Bold) { $worksheet.row( $Row ).Style.Font.Bold = $true } + if ($Italic) { $worksheet.row( $Row ).Style.Font.Italic = $true } + if ($StrikeThru) { $worksheet.row( $Row ).Style.Font.Strike = $true } + if ($FontShift) { $worksheet.row( $Row ).Style.Font.VerticalAlign = $FontShift } + if ($NumberFormat) { $worksheet.row( $Row ).Style.Numberformat.Format = $NumberFormat } + if ($TextRotation) { $worksheet.row( $Row ).Style.TextRotation = $TextRotation } + if ($WrapText) { $worksheet.row( $Row ).Style.WrapText = $true } + if ($HorizontalAlignment) { $worksheet.row( $Row ).Style.HorizontalAlignment = $HorizontalAlignment} + if ($VerticalAlignment) { $worksheet.row( $Row ).Style.VerticalAlignment = $VerticalAlignment } + if ($Height) { $worksheet.row( $Row ).Height = $Height } + if ($FontColor) { $worksheet.row( $Row ).Style.Font.Color.SetColor( $FontColor ) } + if ($BorderRound) { $worksheet.row( $Row ).Style.Border.BorderAround( $BorderAround ) } + if ($BackgroundColor) { + $worksheet.row( $Row ).Style.Fill.PatternType = $BackgroundPattern + $worksheet.row( $Row ).Style.Fill.BackgroundColor.SetColor($BackgroundColor ) + if ($PatternColor) { $worksheet.row( $Row ).Style.Fill.PatternColor.SetColor( $PatternColor ) } + } + #endregion + #return the new data if -passthru was specified. + if ($passThru) {$Worksheet.Row($Row)} +} \ No newline at end of file diff --git a/SetFormat.ps1 b/SetFormat.ps1 index c27daa8..dfe96ff 100644 --- a/SetFormat.ps1 +++ b/SetFormat.ps1 @@ -1,4 +1,4 @@ -Function Set-Format { +Function Set-Format { <# .SYNOPSIS Applies Number, font, alignment and colour formatting to a range of Excel Cells @@ -12,9 +12,15 @@ Function Set-Format { #> Param ( #One or more row(s), Column(s) and/or block(s) of cells to format - [Parameter(ValueFromPipeline = $true)] - [object[]]$Address , - #Number format to apply to cells e.g. "dd/MM/yyyy HH:mm", "£#,##0.00;[Red]-£#,##0.00", "0.00%" , "##/##" , "0.0E+0" etc + [Parameter(ValueFromPipeline = $true,ParameterSetName="Address",Mandatory=$True)] + $Address , + #The worksheet where the format is to be applied + [Parameter(ParameterSetName="SheetAndRange",Mandatory=$True)] + [OfficeOpenXml.ExcelWorksheet]$WorkSheet , + #The area of the worksheet where the format is to be applied + [Parameter(ParameterSetName="SheetAndRange",Mandatory=$True)] + [OfficeOpenXml.ExcelAddress]$Range, + #Number format to apply to cells e.g. "dd/MM/yyyy HH:mm", "£#,##0.00;[Red]-£#,##0.00", "0.00%" , "##/##" , "0.0E+0" etc [Alias("NFormat")] $NumberFormat, #Style of border to draw around the range @@ -56,73 +62,83 @@ Function Set-Format { [ValidateRange(-90, 90)] [int]$TextRotation , #Autofit cells to width (columns or ranges only) - [switch]$AutoFit, - #Set cells to a fixed width (columns or ranges only), ignored if Autofit is specified + [Alias("AutoFit")] + [Switch]$AutoSize, + #Set cells to a fixed width (columns or ranges only), ignored if Autosize is specified [float]$Width, #Set cells to a fixed hieght (rows or ranges only) [float]$Height, #Hide a row or column (not a range) [switch]$Hidden ) + begin { + #Allow Set-Format to take Worksheet and range parameters (like Add Contitional formatting) - convert them to an address + if ($WorkSheet -and $Range) {$Address = $WorkSheet.Cells[$Range] } + } + process { - Foreach ($range in $Address) { + if ($Address -is [Array]) { + [void]$PSBoundParameters.Remove("Address") + $Address | Set-Format @PSBoundParameters + } + else { if ($ResetFont) { - $Range.Style.Font.Color.SetColor("Black") - $Range.Style.Font.Bold = $false - $Range.Style.Font.Italic = $false - $Range.Style.Font.UnderLine = $false - $Range.Style.Font.Strike = $falsee + $Address.Style.Font.Color.SetColor("Black") + $Address.Style.Font.Bold = $false + $Address.Style.Font.Italic = $false + $Address.Style.Font.UnderLine = $false + $Address.Style.Font.Strike = $falsee } if ($Underline) { - $Range.Style.Font.UnderLine = $true - $Range.Style.Font.UnderLineType = $UnderLineType + $Address.Style.Font.UnderLine = $true + $Address.Style.Font.UnderLineType = $UnderLineType } - if ($Bold) {$Range.Style.Font.Bold = $true } - if ($Italic) {$Range.Style.Font.Italic = $true } - if ($StrikeThru) {$Range.Style.Font.Strike = $true } - if ($FontShift) {$Range.Style.Font.VerticalAlign = $FontShift } - if ($FontColor) {$Range.Style.Font.Color.SetColor( $FontColor ) } - if ($BorderRound) {$Range.Style.Border.BorderAround( $BorderAround ) } - if ($NumberFormat) {$Range.Style.Numberformat.Format = $NumberFormat } - if ($TextRotation) {$Range.Style.TextRotation = $TextRotation } - if ($WrapText) {$Range.Style.WrapText = $true } - if ($HorizontalAlignment) {$Range.Style.HorizontalAlignment = $HorizontalAlignment } - if ($VerticalAlignment) {$Range.Style.VerticalAlignment = $VerticalAlignment } + if ($Bold) {$Address.Style.Font.Bold = $true } + if ($Italic) {$Address.Style.Font.Italic = $true } + if ($StrikeThru) {$Address.Style.Font.Strike = $true } + if ($FontShift) {$Address.Style.Font.VerticalAlign = $FontShift } + if ($FontColor) {$Address.Style.Font.Color.SetColor( $FontColor ) } + if ($BorderRound) {$Address.Style.Border.BorderAround( $BorderAround ) } + if ($NumberFormat) {$Address.Style.Numberformat.Format = $NumberFormat } + if ($TextRotation) {$Address.Style.TextRotation = $TextRotation } + if ($WrapText) {$Address.Style.WrapText = $true } + if ($HorizontalAlignment) {$Address.Style.HorizontalAlignment = $HorizontalAlignment } + if ($VerticalAlignment) {$Address.Style.VerticalAlignment = $VerticalAlignment } if ($BackgroundColor) { - $Range.Style.Fill.PatternType = $BackgroundPattern - $Range.Style.Fill.BackgroundColor.SetColor($BackgroundColor) + $Address.Style.Fill.PatternType = $BackgroundPattern + $Address.Style.Fill.BackgroundColor.SetColor($BackgroundColor) if ($PatternColor) { - $range.Style.Fill.PatternColor.SetColor( $PatternColor) + $Address.Style.Fill.PatternColor.SetColor( $PatternColor) } } if ($Height) { - if ($Range -is [OfficeOpenXml.ExcelRow] ) {$Range.Height = $Height } - elseif ($Range -is [OfficeOpenXml.ExcelRange] ) { - ($range.Start.Row)..($range.Start.Row + $range.Rows) | + if ($Address -is [OfficeOpenXml.ExcelRow] ) {$Address.Height = $Height } + elseif ($Address -is [OfficeOpenXml.ExcelRange] ) { + ($Address.Start.Row)..($Address.Start.Row + $Address.Rows) | ForEach-Object {$ws.Row($_).Height = $Height } } - else {Write-Warning -Message ("Can set the height of a row or a range but not a {0} object" -f ($Range.GetType().name)) } + else {Write-Warning -Message ("Can set the height of a row or a range but not a {0} object" -f ($Address.GetType().name)) } } - if ($AutoFit) { - if ($Range -is [OfficeOpenXml.ExcelColumn]) {$Range.AutoFit() } - elseif ($Range -is [OfficeOpenXml.ExcelRange] ) {$Range.AutoFitColumns() } - else {Write-Warning -Message ("Can autofit a column or a range but not a {0} object" -f ($Range.GetType().name)) } + if ($Autosize) { + if ($Address -is [OfficeOpenXml.ExcelColumn]) {$Address.AutoFit() } + elseif ($Address -is [OfficeOpenXml.ExcelRange] ) {$Address.AutoFitColumns() } + else {Write-Warning -Message ("Can autofit a column or a range but not a {0} object" -f ($Address.GetType().name)) } } elseif ($Width) { - if ($Range -is [OfficeOpenXml.ExcelColumn]) {$Range.Width = $Width} - elseif ($Range -is [OfficeOpenXml.ExcelRange] ) { - ($range.Start.Column)..($range.Start.Column + $range.Columns) | + if ($Address -is [OfficeOpenXml.ExcelColumn]) {$Address.Width = $Width} + elseif ($Address -is [OfficeOpenXml.ExcelRange] ) { + ($Address.Start.Column)..($Address.Start.Column + $Address.Columns) | ForEach-Object {$ws.Column($_).Width = $Width} } - else {Write-Warning -Message ("Can set the width of a column or a range but not a {0} object" -f ($Range.GetType().name)) } + else {Write-Warning -Message ("Can set the width of a column or a range but not a {0} object" -f ($Address.GetType().name)) } } if ($Hidden) { - if ($Range -is [OfficeOpenXml.ExcelRow] -or - $Range -is [OfficeOpenXml.ExcelColumn] ) {$Range.Hidden = $True} - else {Write-Warning -Message ("Can hide a row or a column but not a {0} object" -f ($Range.GetType().name)) } + if ($Address -is [OfficeOpenXml.ExcelRow] -or + $Address -is [OfficeOpenXml.ExcelColumn] ) {$Address.Hidden = $True} + else {Write-Warning -Message ("Can hide a row or a column but not a {0} object" -f ($Address.GetType().name)) } } } }