The SFDocuments shared library provides a number of methods and properties to facilitate the management and handling of Office documents.
The SFDocuments.Calc service is a subclass of the SFDocuments.Document service. All methods and properties defined for the Document service can also be accessed using a Calc service instance.
The Calc service is focused on:
This help page describes methods and properties that are applicable only to Calc documents.
Before using the Calc service the ScriptForge library needs to be loaded or imported:
• Basic macros require to load ScriptForge library using the following statement:
GlobalScope.BasicLibraries.loadLibrary("ScriptForge")
• Python scripts require an import from scriptforge module:
from scriptforge import CreateScriptService
The Calc service is closely related to the UI service of the ScriptForge library. Below are a few examples of how the Calc service can be invoked.
The code snippet below creates a Calc service instance that corresponds to the currently active Calc document.
Set oDoc = CreateScriptService("Calc")
Another way to create an instance of the Calc service is using the UI service. In the following example, a new Calc document is created and oDoc is a Calc service instance:
Dim ui As Object, oDoc As Object
Set ui = CreateScriptService("UI")
Set oDoc = ui.CreateDocument("Calc")
Or using the OpenDocument method from the UI service:
Set oDoc = ui.OpenDocument("C:\Documents\MyFile.ods")
It is also possible to instantiate the Calc service using the CreateScriptService method:
Dim oDoc As Object
Set oDoc = CreateScriptService("SFDocuments.Calc", "MyFile.ods")
In the example above, "MyFile.ods" is the name of an open document window. If this argument is not provided, the active window is considered.
It is recommended to free resources after use:
Set oDoc = oDoc.Dispose()
However, if the document was closed using the CloseDocument method, it becomes unnecessary to free resources using the command described above.
myDoc = CreateScriptService("Calc")
ui = CreateScriptService("UI")
myDoc = ui.CreateDocument("Calc")
myDoc = ui.OpenDocument(r"C:\Documents\MyFile.ods")
myDoc = CreateScriptService("SFDocuments.Calc", "MyFile.ods")
myDoc.Dispose()
The use of the prefix "SFDocuments." while calling the service is optional.
Many methods require a "Sheet" or a "Range" as argument. Single cells are considered a special case of a Range.
Both may be expressed either as a string or as a reference (= object) depending on the situation:
The example below copies data from document A (opened as read-only and hidden) to document B.
Dim oDocA As Object, oDocB As Object
Set oDocA = ui.OpenDocument("C:\Documents\FileA.ods", Hidden := True, ReadOnly := True)
Set oDocB = ui.OpenDocument("C:\Documents\FileB.ods")
oDocB.CopyToRange(oDocA.Range("SheetX.D4:F8"), "D2:F6") 'CopyToRange(source, target)
docA = ui.OpenDocument(r"C:\Documents\FileA.ods", hidden = True, readonly = True)
docB = ui.OpenDocument(r"C:\Documents\FileB.ods")
docB.CopyToRange(docA.Range("SheetX.D4:F8"), "D2:F6")
Either the sheet name as a string or an object produced by the .Sheet property.
The shortcut "~" (tilde) represents the current sheet.
Either a string designating a set of contiguous cells located in a sheet of the current instance or an object produced by the .Range property.
The shortcut "~" (tilde) represents the current selection or the first selected range if multiple ranges are selected.
The shortcut "*" represents all used cells.
The sheet name is optional when defining a range. If no sheet name is provided, then the active sheet is used. Surrounding single quotes and $ signs are allowed but ignored.
When specifying a SheetName as a string, the use of single quotes to enclose the sheet name are required if the name contains blank spaces " " or periods ".".
The examples below illustrate in which cases the use of single quotes is mandatory:
' The use of single quotes is optional
oDoc.clearAll("SheetA.A1:B10")
oDoc.clearAll("'SheetA'.A1:B10")
' The use of single quotes is required
oDoc.clearAll("'Sheet.A'.A1:B10")
Except for the CurrentSelection property, the Calc service considers only single ranges of cells.
Examples of valid ranges | |
---|---|
1) $'SheetX'.D22) $D$2 | A single cell |
1) $'SheetX'.D2:F62) D2:D10 | Single range with multiple cells |
$'SheetX'.* | All used cells in the given sheet |
1) $'SheetX'.A:A (column A)2) 3:5 (rows 3 to 5) | All cells in contiguous columns or rows up to the last used cell |
myRange | A range named "myRange" at spreadsheet level |
1) ~.someRange2) SheetX.someRange | A range name at sheet level |
myDoc.Range("SheetX.D2:F6") | A range within the sheet SheetX in file associated with the myDoc Calc instance |
~.~ or ~ | The current selection in the active sheet |
All the properties generic to any document are implicitly applicable also to Calc documents. For more information, read the Document service Help page.
The properties specifically available for Calc documents are:
Name | Readonly | Argument | Return type | Description |
---|---|---|---|---|
CurrentSelection | No | None | String or array of strings | The single selected range as a string or the list of selected ranges as an array. |
FirstCell | Yes | SheetName or RangeName as String | String | Returns the first used cell in a given range or sheet. |
FirstColumn | Yes | SheetName or RangeName as String | Long | Returns the leftmost column number in a given range or sheet. |
FirstRow | Yes | SheetName or RangeName as String | Long | Returns the topmost row number in a given range or sheet. |
Height | Yes | RangeName As String | Long | The number of rows (>= 1) in the given range. |
LastCell | Yes | SheetName or RangeName as String | String | Returns the last used cell in a given range or sheet. |
LastColumn | Yes | SheetName or RangeName as String | Long | The last used column in a given range or sheet. |
LastRow | Yes | SheetName or RangeName as String | Long | The last used row in a given range or sheet. |
Range | Yes | RangeName As String | Object | A range reference that can be used as argument of methods like CopyToRange. |
Region | Yes | RangeName As String | String | Returns the address of the smallest area that contains the specified range so that the area is surrounded by empty cells or sheet edges. This is equivalent to applying the Ctrl + * shortcut to the given range. |
Sheet | Yes | SheetName As String | Object | A sheet reference that can be used as argument of methods like CopySheet. |
SheetName | Yes | RangeName As String | String | Returns the sheet name of a given range address. |
Sheets | Yes | None | Array of strings | The list with the names of all existing sheets. |
Width | Yes | RangeName As String | Long | The number of columns (>= 1) in the given range. |
XCellRange | Yes | RangeName As String | Object | A com.sun.star.Table.XCellRange UNO object. |
XSheetCellCursor | Yes | RangeName As String | Object | A com.sun.star.sheet.XSheetCellCursor UNO object. After moving the cursor, the resulting range address can be accessed through the AbsoluteName UNO property of the cursor object, which returns a string value that can be used as argument for properties and methods of the Calc service. |
XSpreadsheet | Yes | SheetName As String | Object | A com.sun.star.sheet.XSpreadsheet UNO object. |
Visit Office API Documentation's website to learn more about XCellRange, XSheetCellCursor and XSpreadsheet UNO objects.
Returns a range address as a string based on sheet coordinates, i.e. row and column numbers.
If only a pair of coordinates is given, then an address to a single cell is returned. Additional arguments can specify the bottom-right cell of a rectangular range.
svc.A1Style(row1: int, column1: int, row2: int = 0; column2: int = 0; sheetname: str = "~"): str
row1, column1: Specify the row and column numbers of the top-left cell in the range to be considered. Row and column numbers start at 1.
row2, column2: Specify the row and column numbers of the bottom-right cell in the range to be considered. If these arguments are not provided, or if values smaller than row1 and column1 are given, then the address of the single cell range represented by row1 and column1 is returned.
sheetname: The name of the sheet to be appended to the returned range address. The sheet must exist. The default value is "~" corresponding to the currently active sheet.
The examples below in Basic and Python consider that "Sheet1" is the currently active sheet.
Set oDoc = CreateScriptService("Calc")
addr1 = oDoc.A1Style(1, 1) ' '$Sheet1'.$A$1
addr2 = oDoc.A1Style(2, 2, 3, 6) ' '$Sheet1'.$B$2:$F$3
addr3 = oDoc.A1Style(2, 2, 0, 6) ' '$Sheet1'.$B$2
addr4 = oDoc.A1Style(3, 4, 3, 8, "Sheet2") ' '$Sheet2'.$D$3:$H$3
addr5 = oDoc.A1Style(5, 1, SheetName := "Sheet3") ' '$Sheet3'.$A$5
doc = CreateScriptService("Calc")
addr1 = doc.A1Style(1, 1) # '$Sheet1'.$A$1
addr2 = doc.A1Style(2, 2, 3, 6) # '$Sheet1'.$B$2:$F$3
addr3 = doc.A1Style(2, 2, 0, 6) # '$Sheet1'.$B$2
addr4 = doc.A1Style(3, 4, 3, 8, "Sheet2") # '$Sheet2'.$D$3:$H$3
addr5 = doc.A1Style(5, 1, sheetname="Sheet3") # '$Sheet3'.$A$5
The method A1Style can be combined with any of the many properties and methods of the Calc service that require a range as argument, such as GetValue, GetFormula, ClearAll, etc.
If the argument sheetname is provided, the given sheet is activated and it becomes the currently selected sheet. If the argument is absent, then the document window is activated.
svc.Activate(sheetname: str = ""): bool
sheetname: The name of the sheet to be activated in the document. The default value is an empty string, meaning that the document window will be activated without changing the active sheet.
The example below activates the sheet named "Sheet4" in the currently active document.
Dim ui as Variant, oDoc as Object
Set ui = CreateScriptService("UI")
Set oDoc = ui.GetDocument(ui.ActiveWindow)
oDoc.Activate("Sheet4")
ui = CreateScriptService("UI")
myDoc = ui.GetDocument(ui.ActiveWindow)
myDoc.Activate("Sheet4")
Activating a sheet makes sense only if it is performed on a Calc document. To make sure you have a Calc document at hand you can use the isCalc property of the document object, which returns True if it is a Calc document and False otherwise.
Returns either the list with the names of all chart objects in a given sheet or a single Chart service instance.
svc.Charts(sheetname: str, chartname: str = ""): obj
sheetname: The name of the sheet from which the list of charts is to be retrieved or where the specified chart is located.
chartname: The user-defined name of the chart object to be returned. If the chart does not have a user-defined name, then the internal object name can be used. If this argument is absent, then the list of chart names in the specified sheet is returned.
Use the Navigator sidebar to check the names assigned to charts under the OLE objects category.
The example below shows the number of chart objects in "Sheet1".
Dim arrNames as Object
arrNames = oDoc.Charts("Sheet1")
MsgBox "There are " & UBound(arrNames) + 1 & " charts in Sheet1"
The following example accesses the chart named "MyChart" in "Sheet1" and prints its type.
Dim oChart as Object
oChart = oDoc.Charts("Sheet1", "MyChart")
MsgBox oChart.ChartType
bas = CreateScriptService("Basic")
chart-names = doc.Charts("Sheet1")
bas.MsgBox(f"There are {len(chart-names)} charts in Sheet1")
chart = doc.Charts("Sheet1", "MyChart")
bas.MsgBox(chart.ChartType)
Clears all the contents and formats of the given range.
svc.ClearAll(range: str)
range: The range to be cleared, as a string.
oDoc.ClearAll("SheetX.A1:F10")
myDoc.ClearAll("SheetX.A1:F10")
Clears the formats and styles in the given range.
svc.ClearFormats(range: str)
range: The range whose formats and styles are to be cleared, as a string.
oDoc.ClearFormats("SheetX.*")
myDoc.ClearFormats("SheetX.*")
Clears the values and formulas in the given range.
svc.ClearValues(range: str)
range: The range whose values and formulas are to be cleared, as a string.
oDoc.ClearValues("SheetX.A1:F10")
myDoc.ClearValues("SheetX.A1:F10")
Deletes the columns of a specified range that match a filter expressed as a Calc formula. The filter is applied to each column to decide whether it will be deleted or not.
The deleted column can be limited to the height of the specified range or span to the height of the entire sheet, thus deleting whole columns.
This method returns a string with the range address of the compacted range. If all columns are deleted, then an empty string is returned.
If a range of cells is selected, calling this method will not impact the selection.
svc.CompactLeft(range: str, wholecolumn: bool = False, opt filterformula: str): str
range: The range from which columns will be deleted, as a string.
wholecolumn: If this option is set to True the entire column will be deleted from the sheet. The default value is False, which means that the deleted column will be limited to the height of the specified range.
filterformula: The filter to be applied to each column to determine whether or not it will be deleted. The filter is expressed as a Calc formula that should be applied to the first column. When the formula returns True for a column, that column will be deleted. The default filter deletes all empty columns.
For example, suppose range A1:J200 is selected (height = 200), so the default formula is =(COUNTBLANK(A1:A200)=200). This means that if all 200 cells are empty in the first column (Column A), then the column is deleted. Note that the formula is expressed with respect to the first column only. Internally the CompactLeft method will generalise this formula for all the remaining columns.
' Delete all empty columns in the range G1:L10 from Sheet1
newrange = oDoc.CompactLeft("Sheet1.G1:L10")
' The example below is similar, but the entire column is deleted from the sheet
newrange = oDoc.CompactLeft("Sheet1.G1:L10", WholeColumn := True)
' Deletes all columns where the first row is marked with an "X"
newrange = oDoc.CompactLeft("Sheet1.G1:L10", FilterFormula := "=(G1=""X"")")
' Deletes all columns where the sum of values in the column is odd
newrange = oDoc.CompactLeft("Sheet1.G1:L10", FilterFormula := "=(MOD(SUM(G1:G10);2)=1)")
newrange = myDoc.CompactLeft("Sheet1.G1:L10")
newrange = myDoc.CompactLeft("Sheet1.G1:L10", wholecolumn = True)
newrange = myDoc.CompactLeft("Sheet1.G1:L10", filterformula = '=(G1="X")')
newrange = myDoc.CompactLeft("Sheet1.G1:L10", filterformula = '=(MOD(SUM(G1:G10);2)=1)')
Deletes the rows of a specified range that match a filter expressed as a Calc formula. The filter is applied to each row to decide whether it will be deleted or not.
The deleted rows can be limited to the width of the specified range or span to the width of the entire sheet, thus deleting whole rows.
This method returns a string with the range address of the compacted range. If all rows are deleted, then an empty string is returned.
If a range of cells is selected, calling this method will not impact the selection.
svc.CompactUp(range: str, wholerow: bool = False, opt filterformula: str): str
range: The range from which rows will be deleted, as a string.
wholerow: If this option is set to True the entire row will be deleted from the sheet. The default value is False, which means that the deleted row will be limited to the width of the specified range.
filterformula: The filter to be applied to each row to determine whether or not it will be deleted. The filter is expressed as a Calc formula that should be applied to the first row. When the formula returns True for a row, that row will be deleted. The default filter deletes all empty rows.
For example, suppose range A1:J200 is selected (width = 10), so the default formula is =(COUNTBLANK(A1:J1)=10). This means that if all 10 cells are empty in the first row (Row 1), then the row is deleted. Note that the formula is expressed with respect to the first row only. Internally the CompactUp method will generalise this formula for all the remaining rows.
' Delete all empty rows in the range G1:L10 from Sheet1
newrange = oDoc.CompactUp("Sheet1.G1:L10")
' The example below is similar, but the entire row is deleted from the sheet
newrange = oDoc.CompactUp("Sheet1.G1:L10", WholeRow := True)
' Deletes all rows where the first column is marked with an "X"
newrange = oDoc.CompactUp("Sheet1.G1:L10", FilterFormula := "=(G1=""X"")")
' Deletes all rows where the sum of values in the row is odd
newrange = oDoc.CompactUp("Sheet1.G1:L10", FilterFormula := "=(MOD(SUM(G1:L1);2)=1)")
newrange = myDoc.CompactUp("Sheet1.G1:L10")
newrange = myDoc.CompactUp("Sheet1.G1:L10", wholerow = True)
newrange = myDoc.CompactUp("Sheet1.G1:L10", filterformula = '=(G1="X")')
newrange = myDoc.CompactUp("Sheet1.G1:L10", filterformula = '=(MOD(SUM(G1:L1);2)=1)')
Copies a specified sheet before an existing sheet or at the end of the list of sheets. The sheet to be copied may be contained inside any open Calc document. Returns True if successful.
svc.CopySheet(sheetname: any, newname: str, [beforesheet: any]): bool
sheetname: The name of the sheet to be copied as a string or its reference as an object.
newname: The name of the sheet to insert. The name must not be in use in the document.
beforesheet: The name (string) or index (numeric, starting from 1) of the sheet before which to insert the copied sheet. This argument is optional and the default behaviour is to add the copied sheet at the last position.
The following example makes a copy of the sheet "SheetX" and places it as the last sheet in the current document. The name of the copied sheet is "SheetY".
Dim oDoc as Object
'Gets the Document object of the active window
Set oDoc = CreateScriptService("Calc")
oDoc.CopySheet("SheetX", "SheetY")
The example below copies "SheetX" from "FileA.ods" and pastes it at the last position of "FileB.ods" with the name "SheetY":
Dim oDocA As Object : Set oDocA = ui.OpenDocument("C:\Documents\FileA.ods", Hidden := True, ReadOnly := True)
Dim oDocB As Object : Set oDocB = ui.OpenDocument("C:\Documents\FileB.ods")
oDocB.CopySheet(oDocA.Sheet("SheetX"), "SheetY")
myDoc.CopySheet("SheetX", "SheetY")
docA = ui.OpenDocument(r"C:\Documents\FileA.ods", hidden = True, readonly = True)
docB = ui.OpenDocument(r"C:\Documents\FileB.ods")
docB.CopySheet(docA.Sheet("SheetX"), "SheetY")
To copy sheets between open documents, use CopySheet. To copy sheets from documents that are closed, use CopySheetFromFile.
Copies a specified sheet from a closed Calc document and pastes it before an existing sheet or at the end of the list of sheets of the file referred to by a Document object.
If the file does not exist, an error is raised. If the file is not a valid Calc file, a blank sheet is inserted. If the source sheet does not exist in the input file, an error message is inserted at the top of the newly pasted sheet.
svc.CopySheetFromFile(filename: str, sheetname: str, newname: str, [beforesheet: any]): bool
filename: Identifies the file to open. It must follow the SF-FileSystem.FileNaming notation. The file must not be protected with a password.
sheetname: The name of the sheet to be copied as a string.
newname: The name of the copied sheet to be inserted in the document. The name must not be in use in the document.
beforesheet: The name (string) or index (numeric, starting from 1) of the sheet before which to insert the copied sheet. This argument is optional and the default behaviour is to add the copied sheet at the last position.
The following example copies "SheetX" from "myFile.ods" and pastes it into the document referred to by "oDoc" as "SheetY" at the first position.
oDoc.CopySheetFromFile("C:\Documents\myFile.ods", "SheetX", "SheetY", 1)
myDoc.CopySheetFromFile(r"C:\Documents\myFile.ods", "SheetX", "SheetY", 1)
Copies a specified source range (values, formulas and formats) to a destination range or cell. The method reproduces the behaviour of a Copy/Paste operation from a range to a single cell.
It returns a string representing the modified range of cells. The size of the modified area is fully determined by the size of the source area.
The source range may belong to another open document.
svc.CopyToCell(sourcerange: any, destinationcell: str): str
sourcerange: The source range as a string when it belongs to the same document or as a reference when it belongs to another open Calc document.
destinationcell: The destination cell where the copied range of cells will be pasted, as a string. If a range is given, only its top-left cell is considered.
Next is an example where the source and destination are in the same file:
oDoc.CopyToCell("SheetX.A1:F10", "SheetY.C5")
The example below illustrates how to copy a range from another open Calc document:
Dim ui as Variant : ui = CreateScriptService("UI")
Dim oDocSource As Object, oDocDestination As Object
'Open the source document in the background (hidden)
Set oDocSource = ui.OpenDocument("C:\SourceFile.ods", Hidden := True, ReadOnly := True)
Set oDocDestination = CreateScriptService("Calc")
oDocDestination.CopyToCell(oDocSource.Range("Sheet1.C2:C4"), "SheetT.A5")
'Do not forget to close the source document because it was opened as hidden
oDocSource.CloseDocument()
docSource = ui.OpenDocument(r"C:\Documents\SourceFile.ods", hidden = True, readonly = True)
docDestination = CreateScriptService("Calc")
docDestination.CopyToCell(docSource.Range("Sheet1.C2:C4"), "SheetT.A5")
docSource.CloseDocument()
To simulate a Copy/Paste from a range to a single cell, use CopyToCell. To simulate a Copy/Paste from a range to a larger range (with the same cells being replicated several times), use CopyToRange.
Copies downwards and/or rightwards a specified source range (values, formulas and formats) to a destination range. The method imitates the behaviour of a Copy/Paste operation from a source range to a larger destination range.
The method returns a string representing the modified range of cells.
The source range may belong to another open document.
svc.CopyToRange(sourcerange: any, destinationrange: str): str
sourcerange: The source range as a string when it belongs to the same document or as a reference when it belongs to another open Calc document.
destinationrange: The destination of the copied range of cells, as a string.
Copy within the same document:
oDoc.CopyToRange("SheetX.A1:F10", "SheetY.C5:J5")
' Returns a range string: "$SheetY.$C$5:$J$14"
Copy from one file to another:
Dim oDocA As Object : Set oDocA = ui.OpenDocument("C:\Documents\FileA.ods", Hidden := True, ReadOnly := True)
Dim oDocB As Object : Set oDocB = ui.OpenDocument("C:\Documents\FileB.ods")
oDocB.CopyToRange(oDocA.Range("SheetX.A1:F10"), "SheetY.C5:J5")
doc.CopyToRange("SheetX.A1:F10", "SheetY.C5:J5")
docA = ui.OpenDocument(r"C:\Documents\FileA.ods", hidden = True, readonly = True)
docB = ui.OpenDocument(r"C:\Documents\FileB.ods")
docB.CopyToRange(docA.Range("SheetX.A1:F10"), "SheetY.C5:J5")
Creates a new chart object showing the data in the specified range. The returned chart object can be further manipulated using the Chart service.
svc.CreateChart(chartname: str, sheetname: str, range: str, columnheader: bool = False, rowheader: bool = False): obj
chartname: The user-defined name of the chart to be created. The name must be unique in the same sheet.
sheetname: The name of the sheet where the chart will be placed.
range: The range to be used as the data source for the chart. The range may refer to any sheet of the Calc document.
columnheader: When True, the topmost row of the range is used as labels for the category axis or the legend (Default = False).
rowheader: When True, the leftmost column of the range is used as labels for the category axis or the legend. (Default = False).
The examples below in Basic and Python create a chart using the data contained in the range "A1:B5" of "Sheet1" and place the chart in "Sheet2".
Set oChart = oDoc.CreateChart("MyChart", "Sheet2", "Sheet1.A1:B5", RowHeader := True)
oChart.ChartType = "Donut"
chart = doc.CreateChart("MyChart", "Sheet2", "Sheet1.A1:B5", rowheader=True)
chart.ChartType = "Donut"
Refer to the help page about ScriptForge's Chart service to learn more how to further manipulate chart objects. It is possible to change properties as the chart type, chart and axes titles and chart position.
Creates a new pivot table with the properties defined by the arguments passed to the method.
A name must be provided for the pivot table. If a pivot table with the same name already exists in the targeted sheet, it will be replaced without warning.
This method returns a string containing the range where the new pivot table was placed.
svc.CreatePivotTable(pivottablename: str, sourcerange: str, targetcell: str, datafields: str[0..*], rowfields: str[0..*], columnfields: str[0..*], filterbutton: bool = true, rowtotals: bool = true, columntotals: bool = true): str
pivottablename: The user-defined name of the new pivot table.
sourcerange: The range containing the raw data, as a string. It is assumed that the first row contains the field names that are used by the pivot table.
targetcell: The top-left cell where the new pivot table will be placed. If a range is specified, only its top-left cell is considered.
datafields: It can be either a single string or an array containing strings that define field names and functions to be applied. When an array is specified, it must follow the syntax Array("FieldName[;Function]", ...).
The allowed functions are: Sum, Count, Average, Max, Min, Product, CountNums, StDev, StDevP, Var, VarP and Median. Function names must be provided in English. When all values are numerical, Sum is the default function, otherwise the default function is Count.
rowfields: A single string or an array with the field names that will be used as the pivot table rows.
columnfields: A single string or an array with the field names that will be used as the pivot table columns.
filterbutton: Determines whether a filter button will be displayed above the pivot table (Default = True).
rowtotals: Specifies if a separate column for row totals will be added to the pivot table (Default = True).
columntotals Specifies if a separate row for column totals will be added to the pivot table (Default = True)
Dim vData As Variant, oDoc As Object, ui As Object, sTable As String, sPivot As String
Set ui = CreateScriptService("UI")
Set oDoc = ui.CreateDocument("Calc")
vData = Array(Array("Item", "State", "Team", "2002", "2003", "2004"), -
Array("Books", "Michigan", "Jean", 14788, 30222, 23490), -
Array("Candy", "Michigan", "Jean", 26388, 15641, 32849), -
Array("Pens", "Michigan", "Jean", 16569, 32675, 25396), -
Array("Books", "Michigan", "Volker", 21961, 21242, 29009), -
Array("Candy", "Michigan", "Volker", 26142, 22407, 32841))
sTable = oDoc.SetArray("A1", vData)
sPivot = oDoc.CreatePivotTable("PT1", sTable, "H1", -
Array("2002", "2003;count", "2004;average"), - ' Three data fields
"Item", - ' A single row field
Array("State", "Team"), False) ' Two column fields
ui = CreateScriptService("UI")
doc = ui.CreateDocument("Calc")
vData = [["Item", "State", "Team", "2002", "2003", "2004"],
["Books", "Michigan", "Jean", 14788, 30222, 23490],
["Candy", "Michigan", "Jean", 26388, 15641, 32849],
["Pens", "Michigan", "Jean", 16569, 32675, 25396)],
["Books", "Michigan", "Volker", 21961, 21242, 29009],
["Candy", "Michigan", "Volker", 26142, 22407, 32841]]
sTable = doc.SetArray("A1", vData)
sPivot = doc.CreatePivotTable("PT1", sTable, "H1",
["2002", "2003;count", "2004;average"],
"Item",
["State", "Team"], False)
To learn more about Pivot Tables in Office Calc, read the Pivot Table help page.
Apply the functions Average, Count, Max, Min and Sum, respectively, to all the cells containing numeric values on a given range.
svc.DAvg(range: str): float
svc.DCount(range: str): float
svc.DMax(range: str): float
svc.DMin(range: str): float
svc.DSum(range: str): float
range: The range to which the function will be applied, as a string.
The example below applies the Sum function to the range "A1:A1000" of the currently selected sheet:
result = oDoc.DSum("~.A1:A1000")
result = myDoc.DSum("~.A1:A1000")
Cells in the given range that contain text will be ignored by all of these functions. For example, the DCount method will not count cells with text, only numerical cells.
Exports the specified range as an image or PDF file.
This method returns True if the destination file was successfully saved.
Hidden rows or columns in the specified range are not exported to the destination file.
svc.ExportRangeToFile(range: str, filename: str, imagetype: str = "pdf", overwrite: bool = False): bool
range: A sheet name or a cell range to be exported, as a string.
filename: The name of the file to be saved. It must follow the SF-FileSystem.FileNaming notation.
imagetype: Identifies the destination file type. Possible values are "jpeg", "pdf" (default) and "png".
overwrite: When set to True, the destination file may be overwritten (Default = False).
' Exports the entire sheet as a PDF file
oDoc.ExportRangeToFile("SheetX", "C:\Temp\image.pdf")
' Exports the range as a PNG file and overwrites the destination file if it exists
oDoc.ExportRangeToFile("SheetX.A1:D10", "C:\Temp\image.png", "png", Overwrite := True)
doc.ExportRangeToFile("SheetX", r"C:\Temp\image.pdf")
doc.ExportRangeToFile("SheetX.A1:D10", r"C:\Temp\image.png", "png", overwrite = True)
Depending on the parameters provided this method will return:
svc.Forms(sheetname: str): str[0..*]
svc.Forms(sheetname: str, form: str = ''): svc
svc.Forms(sheetname: str, form: int): svc
sheetname: The name of the sheet, as a string, from which the form will be retrieved.
form: The name or index corresponding to a form stored in the specified sheet. If this argument is absent, the method will return a list with the names of all forms available in the sheet.
In the following examples, the first line gets the names of all forms stored in "Sheet1" and the second line retrieves the Form object of the form named "Form-A" which is stored in "Sheet1".
Set FormNames = oDoc.Forms("Sheet1")
Set FormA = oDoc.Forms("Sheet1", "Form-A")
form-names = doc.Forms("Sheet1")
form-A = doc.Forms("Sheet1", "Form-A")
Converts a column number ranging between 1 and 1024 into its corresponding letter (column 'A', 'B', ..., 'AMJ'). If the given column number is outside the allowed range, a zero-length string is returned.
svc.GetColumnName(columnnumber: int): str
columnnumber: The column number as an integer value in the interval 1 ... 1024.
Displays a message box with the name of the third column, which by default is "C".
MsgBox oDoc.GetColumnName(3)
bas = CreateScriptService("Basic")
bas.MsgBox(myDoc.GetColumnName(3))
The maximum number of columns allowed on a Calc sheet is 1024.
Get the formula(s) stored in the given range of cells as a single string, a 1D or a 2D array of strings.
svc.GetFormula(range: str): any
range: The range where to get the formulas from, as a string.
The following example returns a 3 by 2 array with the formulas in the range "A1:B3" (3 rows by 2 columns):
arrFormula = oDoc.GetFormula("~.A1:B3")
arrFormula = myDoc.GetFormula("~.A1:B3")
Get the value(s) stored in the given range of cells as a single value, a 1D array or a 2D array. All values are either doubles or strings.
svc.GetValue(range: str): any
range: The range where to get the values from, as a string.
arrValues = oDoc.GetValue("~.B1:C100")
arrValues = myDoc.GetValue("~.B1:C100")
If a cell contains a date, the number corresponding to that date will be returned. To convert numeric values to dates in Basic scripts, use the Basic CDate builtin function. In Python scripts, use the CDate function from the Basic service.
Imports the contents of a CSV-formatted text file and places it on a given destination cell.
The destination area is cleared of all contents and formats before inserting the contents of the CSV file. The size of the modified area is fully determined by the contents of the input file.
The method returns a string representing the modified range of cells.
svc.ImportFromCSVFile(filename: str, destinationcell: str, [filteroptions: str]): str
filename: Identifies the file to open. It must follow the SF-FileSystem.FileNaming notation.
destinationcell: The destination cell to insert the imported data, as a string. If instead a range is given, only its top-left cell is considered.
filteroptions: The arguments for the CSV input filter. The default filter makes following assumptions:
oDoc.ImportFromCSVFile("C:\Temp\myCSVFile.csv", "SheetY.C5")
myDoc.ImportFromCSVFile(r"C:\Temp\myCSVFile.csv", "SheetY.C5")
To learn more about the CSV Filter Options, refer to the CSV Filter Options help page.
Imports the contents of a database table, query or resultset, i.e. the result of a SELECT SQL command, inserting it on a destination cell.
The destination area is cleared of all contents and formats before inserting the imported contents. The size of the modified area is fully determined by the contents in the table or query.
The method returns True when the import was successful.
svc.ImportFromDatabase(filename: str = "", registrationname: str = "", destinationcell: str = "", sqlcommand: str = "", directsql: bool): bool
filename: Identifies the file to open. It must follow the SF-FileSystem.FileNaming notation.
registrationname: The name to use to find the database in the databases register. This argument is ignored if a filename is provided.
destinationcell: The destination of the imported data, as a string. If a range is given, only its top-left cell is considered.
sqlcommand: A table or query name (without surrounding quotes or square brackets) or a SELECT SQL statement in which table and field names may be surrounded by square brackets or quotes to improve its readability.
directsql: When True, the SQL command is sent to the database engine without pre-analysis. Default is False. The argument is ignored for tables. For queries, the applied option is the one set when the query was defined.
oDoc.ImportFromDatabase("C:\Temp\myDbFile.odb", , "SheetY.C5", "SELECT * FROM [Employees] ORDER BY [LastName]")
myDoc.ImportFromDatabase(r"C:\Temp\myDbFile.odb", , "SheetY.C5", "SELECT * FROM [Employees] ORDER BY [LastName]")
Inserts a new empty sheet before an existing sheet or at the end of the list of sheets.
svc.InsertSheet(sheetname: str, [beforesheet: any]): bool
sheetname: The name of the new sheet.
beforesheet: The name (string) or index (numeric, starting from 1) of the sheet before which to insert the new sheet. This argument is optional and the default behaviour is to insert the sheet at the last position.
The following example inserts a new empty sheet named "SheetX" and places it before "SheetY":
oDoc.InsertSheet("SheetX", "SheetY")
myDoc.InsertSheet("SheetX", "SheetY")
Moves a specified source range to a destination range of cells. The method returns a string representing the modified range of cells. The dimension of the modified area is fully determined by the size of the source area.
svc.MoveRange(source: str, destination: str): str
source: The source range of cells, as a string.
destination: The destination cell, as a string. If a range is given, its top-left cell is considered as the destination.
oDoc.MoveRange("SheetX.A1:F10", "SheetY.C5")
myDoc.MoveRange("SheetX.A1:F10", "SheetY.C5")
Moves an existing sheet and places it before a specified sheet or at the end of the list of sheets.
svc.MoveSheet(sheetname: str, [beforesheet: any]): bool
sheetname: The name of the sheet to move. The sheet must exist or an exception is raised.
beforesheet: The name (string) or index (numeric, starting from 1) of the sheet before which the original sheet will be placed. This argument is optional and the default behaviour is to move the sheet to the last position.
The example below moves the existing sheet "SheetX" and places it before "SheetY":
oDoc.MoveSheet("SheetX", "SheetY")
myDoc.MoveSheet("SheetX", "SheetY")
Returns a new range (as a string) offset by a certain number of rows and columns from a given range.
This method has the same behaviour as the homonymous Calc's Offset function.
svc.Offset(reference: str, rows: int = 0, columns: int = 0, [height: int], [width: int]): str
reference: The range, as a string, that the method will use as reference to perform the offset operation.
rows: The number of rows by which the initial range is offset upwards (negative value) or downwards (positive value). Use 0 (default) to stay in the same row.
columns: The number of columns by which the initial range is offset to the left (negative value) or to the right (positive value). Use 0 (default) to stay in the same column.
height: The vertical height for an area that starts at the new range position. Omit this argument when no vertical resizing is needed.
width: The horizontal width for an area that starts at the new range position. Omit this argument when no horizontal resizing is needed.
Arguments rows and columns must not lead to zero or negative start row or column.
Arguments height and width must not lead to zero or negative count of rows or columns.
oDoc.Offset("A1", 2, 2)
'SheetX.$C$3 (A1 moved by two rows and two columns down)
oDoc.Offset("A1", 2, 2, 5, 6)
'SheetX.$C$3:$H$7 (A1 offset by two rows and columns with width of 5 rows and 6 columns)
myDoc.Offset("A1", 2, 2)
myDoc.Offset("A1", 2, 2, 5, 6)
Opens a non-modal dialogue box that can be used to select a range in the document and returns a string containing the selected range.
This method opens the same dialogue box that is used by Office when the Shrink button is pressed. For example, the Tools - Goal Seek dialogue box has a Shrink button to the right of the Formula cell field.
This method does not change the current selection.
svc.OpenRangeSelector(opt title: str, opt selection: str, singlecell: bool = False, closeafterselect: bool = True): str
title: The title of the dialog, as a string.
selection: An optional range that is initially selected when the dialog is displayed.
singlecell: When True (default) only single-cell selection is allowed. When False range selection is allowed.
closeafterselect: When True (default) the dialog is closed immediately after the selection is made. When False the user can change the selection as many times as needed and then manually close the dialog.
Dim sRange as String
sRange = oDoc.OpenRangeSelector(Title := "Select a range")
sRange = myDoc.OpenRangeSelector(title = "Select a range")
Returns the input string after substituting its token characters by their values in a given range.
This method does not change the current selection.
This method can be used to quickly extract specific parts of a range name, such as the sheet name or first cell column and row, and use them to compose a new range address.
svc.Printf(inputstr: str, range: str, tokencharacter: str = "%"): str
inputstr: The string containing the tokens that will be replaced by the corresponding values in range.
range: A RangeName from which values will be extracted. If it contains a sheet name, the sheet must exist.
tokencharacter: Character used to identify tokens. By default "%" is the token character. The following tokens are accepted:
The example below extracts each element of the RangeName defined in sRange and uses them to compose a message.
Dim sRange as String, sInputStr as String
sRange = "Sheet1.A1:E10"
sInputStr = "Sheet name: %S" & Chr(10) & -
"First row: %R1" & Chr(10) & -
"First column %C1" & Chr(10) & -
"Last row %R2" & Chr(10) & -
"Last column %C2"
MsgBox oDoc.Printf(sInputStr, sRange)
The Printf method can be combined with SetFormula to create formulas over multiple cells. For instance, consider a table with numeric values in the range "A1:E10" from which formulas are to be created to sum the values in each row and place the results in the range "F1:F10":
Dim sFormula as String, sRange as String
sRange = "A1:E10"
' Note the use of the "$" character
sFormula = "=SUM($%C1%R1:$%C2%R1)"
oDoc.SetFormula("F1:F10", oDoc.Printf(sFormula, sRange))
sRange = "Sheet1.A1:E10"
sInputStr = "Sheet name: %S\n" \
"First row: %R1\n" \
"First column %C1\n" \
"Last row %R2\n" \
"Last column %C2"
bas = CreateScriptService("Basic")
bas.MsgBox(myDoc.Printf(sInputStr, sRange))
sRange = "A1:E10
sFormula = "=SUM($%C1%R1:$%C2%R1)"
myDoc.SetFormula("F1:F10", myDoc.Printf(sFormula, sRange))
This method sends the contents of the given sheet to the default printer or to the printer defined by the SetPrinter method of the Document service.
Returns True if the sheet was successfully printed.
svc.PrintOut(opt sheetname: str, pages: str = "", copies: num = 1): bool
sheetname: The sheet to print, default is the active sheet.
pages: The pages to print as a string, like in the user interface. Example: "1-4;10;15-18". Default is all pages.
copies: The number of copies. Default is 1.
If oDoc.PrintOut("SheetX", "1-4;10;15-18", Copies := 2) Then
' ...
End If
if doc.PrintOut('SheetX', copies=3, pages='45-88'):
# ...
Removes an existing sheet from the document.
svc.RemoveSheet(sheetname: str): bool
sheetname: The name of the sheet to remove.
oDoc.RemoveSheet("SheetY")
myDoc.RemoveSheet("SheetY")
Renames the given sheet and returns True if successful.
svc.RenameSheet(sheetname: str, newname: str): bool
sheetname: The name of the sheet to rename.
newname: the new name of the sheet. It must not exist yet.
This example renames the active sheet to "SheetY":
oDoc.RenameSheet("~", "SheetY")
mydoc.RenameSheet("~", "SheetY")
Stores the given value starting from a specified target cell. The updated area expands itself from the target cell or from the top-left corner of the given range to accommodate the size of the input value argument. Vectors are always expanded vertically.
The method returns a string representing the modified area as a range of cells.
svc.SetArray(targetcell: str, value: any): str
targetcell: The cell or a range as a string from where to start to store the given value.
value: A scalar, a vector or an array (in Python, one or two-dimensional lists and tuples) with the new values to be stored from the target cell or from the top-left corner of the range if targetcell is a range. The new values must be strings, numeric values or dates. Other types will cause the corresponding cells to be emptied.
The following example uses the builtin DimArray function to create an array and then store it in cell "A1":
Dim arrData as Variant
arrData = DimArray(2, 1)
arrData(0, 0) = 1 : arrData(1, 0) = 2 : arrData(2, 0) = 3
arrData(0, 1) = "One" : arrData(1, 1) = "Two" : arrData(2, 1) = "Three"
oDoc.SetArray("Sheet1.A1", arrData)
This example uses the RangeInit method of the ScriptForge Array service to create an array with values that are then stored from cell "A1" and downwards.
'Fill 1st column with values from 1 to 1000
oDoc.SetArray("Sheet1.A1", SF-Array.RangeInit(1, 1000))
arrData = ((1, "One"), (2, "Two"), (3, "Three"))
myDoc.SetArray("Sheet1.A1", arrData)
myDoc.SetArray("Sheet1.A1", tuple(i + 1 for i in range(1000)))
To dump the full contents of an array in a sheet, use SetArray. To dump the contents of an array only within the boundaries of the targeted range of cells, use SetValue.
Stores the given value in the specified range. The size of the modified area is equal to the size of the target range.
The method returns a string representing the modified area as a range of cells.
svc.SetValue(targetrange: str, value: any): str
targetrange: The range where to store the given value, as a string.
value: A scalar, a vector or an array with the new values for each cell of the range. The new values must be strings, numeric values or dates. Other types will cause the corresponding cells to be emptied.
The full range is updated and the remainder of the sheet is left unchanged. If the size of value is smaller than the size of targetrange, then the remaining cells will be emptied.
If the size of value is larger than the size of targetrange, then value is only partially copied until it fills the size of targetrange.
Vectors are expanded vertically, except if targetrange has a height of exactly 1 row.
oDoc.SetValue("A1", 2)
'Below the Value array is smaller than the TargetRange (remaining cells are emptied)
oDoc.SetValue("A1:F1", Array(1, 2, 3))
'Below the Value and TargetRange have the same size
oDoc.SetValue("A1:D2", SF-Array.AppendRow(Array(1, 2, 3, 4), Array(5, 6, 7, 8)))
If you want to fill a single row with values, you can use the Offset function. In the example below, consider that arrData is a one-dimensional array:
Dim firstCell As String : firstCell = "A1"
Dim lenArray As Integer : lenArray = UBound(arrData) - LBound(arrData) + 1
Dim newRange As String : newRange = oDoc.Offset(firstCell, width = lenArray)
oDoc.SetValue(newRange, arrData)
myDoc.SetValue("A1", 2)
myDoc.SetValue("A1:F1", (1, 2, 3))
myDoc.SetValue("A1:D2", ((1, 2, 3, 4), (5, 6, 7, 8)))
firstCell = "A1"
newRange = doc.Offset(firstCell, width = len(arrData))
doc.SetValue(newRange, arrData)
Applies the specified cell style to the given target range. The full range is updated and the remainder of the sheet is left untouched. If the cell style does not exist, an error is raised.
The method returns a string representing the modified area as a range of cells.
svc.SetCellStyle(targetrange: str, style: str): str
targetrange: The range to which the style will be applied, as a string.
style: The name of the cell style to apply.
oDoc.SetCellStyle("A1:J1", "Heading 1")
oDoc.SetCellStyle("A2:J100", "Neutral")
myDoc.SetCellStyle("A1:J1", "Heading 1")
myDoc.SetCellStyle("A2:J100", "Neutral")
Inserts the given (array of) formula(s) in the specified range. The size of the modified area is equal to the size of the range.
The method returns a string representing the modified area as a range of cells.
svc.SetFormula(targetrange: str, formula: any): str
targetrange: The range to insert the formulas, as a string.
formula: A string, a vector or an array of strings with the new formulas for each cell in the target range.
The full range is updated and the remainder of the sheet is left unchanged.
If the given formula is a string, the unique formula is pasted along the whole range with adjustment of the relative references.
If the size of formula is smaller than the size of targetrange, then the remaining cells are emptied.
If the size of formula is larger than the size of targetrange, then the formulas are only partially copied until it fills the size of targetrange.
Vectors are always expanded vertically, except if targetrange has a height of exactly 1 row.
oDoc.SetFormula("A1", "=A2")
'Horizontal vector, partially empty
oDoc.SetFormula("A1:F1", Array("=A2", "=B2", "=C2+10"))
'D2 contains the formula "=H2"
oDoc.SetFormula("A1:D2", "=E1")
myDoc.SetFormula("A1", "=A2")
myDoc.SetFormula("A1:F1", ("=A2", "=B2", "=C2+10"))
myDoc.SetFormula("A1:D2", "=E1")
Moves a given range of cells downwards by inserting empty rows. The current selection is not affected.
Depending on the value of the wholerow argument the inserted rows can either span the width of the specified range or span all columns in the row.
This method returns a string representing the new location of the initial range.
If the shifted range exceeds the sheet edges, then nothing happens.
svc.ShiftDown(range: str, wholerow: bool = False, opt rows: int): str
range: The range above which rows will be inserted, as a string.
wholerow: If set to False (default), then the width of the inserted rows will be the same as the width of the specified range. Otherwise, the inserted row will span all columns in the sheet.
rows: The number of rows to be inserted. The default value is the height of the original range. The number of rows must be a positive number.
' Moves the range "A3:D3" down by one row; affects only columns A to D
oDoc.ShiftDown("A3:D3")
' The inserted row spans all columns in the sheet
oDoc.ShiftDown("A3:D3", WholeRow := True)
' Moves the range "A3:D3" down by five rows
oDoc.ShiftDown("A3:D3", Rows := 5)
' Moves the range "A3:D10" down by two rows and shows the new location of the original range
Dim sNewRange as String
sNewRange = oDoc.ShiftDown("A3:D10", Rows := 2)
MsgBox sNewRange ' $Sheet1.$A$5:$D$12
myDoc.ShiftDown("A3:D3")
myDoc.ShiftDown("A3:D3", wholerow = True)
myDoc.ShiftDown("A3:D3", rows = 5)
sNewRange = myDoc.ShiftDown("A3:D10", rows = 2)
bas = CreateScriptService("Basic")
bas.MsgBox(sNewRange)
Deletes the leftmost columns of a given range and moves to the left all cells to the right of the affected range. The current selection is not affected.
Depending on the value of the wholecolumn argument the deleted columns can either span the height of the specified range or span all rows in the column.
This method returns a string representing the location of the remaining portion of the initial range. If all cells in the original range have been deleted, then an empty string is returned.
svc.ShiftLeft(range: str, wholecolumn: bool = False, opt columns: int): str
range: The range from which cells will be deleted, as a string.
wholecolumn: If set to False (default), then the height of the deleted columns will be the same as the height of the specified range. Otherwise, the deleted columns will span all rows in the sheet.
columns: The number of columns to be deleted from the specified range. The default value is the width of the original range, which is also the maximum value of this argument.
' Deletes the range "B3:B6"; moves left all cells to the right
oDoc.ShiftLeft("B3:B6")
' Deletes the first column in the range "A3:D6"
oDoc.ShiftLeft("A3:D6", Columns := 1)
' The deleted columns (A to D) spans all rows in the sheet
oDoc.ShiftLeft("A3:D6", WholeColumn := True)
myDoc.ShiftLeft("B3:B6")
myDoc.ShiftLeft("A3:D6", Columns = 1)
myDoc.ShiftLeft("A3:D6", WholeColumn = True)
Deletes the topmost rows of a given range and moves upwards all cells below the affected range. The current selection is not affected.
Depending on the value of the wholerow argument the deleted rows can either span the width of the specified range or span all columns in the row.
This method returns a string representing the location of the remaining portion of the initial range. If all cells in the original range have been deleted, then an empty string is returned.
svc.ShiftUp(range: str, wholerow: bool = False, opt rows: int): str
range: The range from which cells will be deleted, as a string.
wholerow: If set to False (default), then the width of the deleted rows will be the same as the width of the specified range. Otherwise, the deleted row will span all columns in the sheet.
rows: The number of rows to be deleted from the specified range. The default value is the height of the original range, which is also the maximum value of this argument.
' Deletes the range "A3:D3"; moves all cells below it by one row up
oDoc.ShiftUp("A3:D3")
' Deletes the first row in the range "A3:D6"
oDoc.ShiftUp("A3:D6", Rows := 1)
' The deleted rows spans all columns in the sheet
oDoc.ShiftUp("A3:D6", WholeRow := True)
myDoc.ShiftUp("A3:D3")
myDoc.ShiftUp("A3:D6", rows = 1)
myDoc.ShiftUp("A3:D6", wholerow = True)
Moves a given range of cells to the right by inserting empty columns. The current selection is not affected.
Depending on the value of the wholecolumn argument the inserted columns can either span the height of the specified range or span all rows in the column.
This method returns a string representing the new location of the initial range.
If the shifted range exceeds the sheet edges, then nothing happens.
svc.ShiftRight(range: str, wholecolumn: bool = False, opt columns: int): str
range: The range which will have empty columns inserted to its left, as a string.
wholecolumn: If set to False (default), then the height of the inserted columns will be the same as the height of the specified range. Otherwise, the inserted columns will span all rows in the sheet.
columns: The number of columns to be inserted. The default value is the width of the original range.
' Moves the range "A3:A6" right by one column; affects only rows 3 to 6
oDoc.ShiftRight("A3:A6")
' Moves the range "A3:A6" right by five columns
oDoc.ShiftRight("A3:A6", Columns := 5)
' The inserted column spans all rows in the sheet
oDoc.ShiftRight("A3:A6", WholeColumn := True)
myDoc.ShiftRight("A3:A6")
myDoc.ShiftRight("A3:A6", columns = 5)
myDoc.ShiftRight("A3:A6", wholecolumn = True)
Sorts the given range based on up to 3 columns/rows. The sorting order may vary by column/row. It returns a string representing the modified range of cells. The size of the modified area is fully determined by the size of the source area.
svc.SortRange(range: str, sortkeys: any, sortorder: any = "ASC", destinationcell: str = "", containsheader: bool = False, casesensitive: bool = False, sortcolumns: bool = False): str
range: The range to be sorted, as a string.
sortkeys: A scalar (if 1 column/row) or an array of column/row numbers starting from 1. The maximum number of keys is 3.
sortorder: A scalar or an array of strings containing the values "ASC" (ascending), "DESC" (descending) or "" (which defaults to ascending). Each item is paired with the corresponding item in sortkeys. If the sortorder array is shorter than sortkeys, the remaining keys are sorted in ascending order.
destinationcell: The destination cell of the sorted range of cells, as a string. If a range is given, only its top-left cell is considered. By default the source Range is overwritten.
containsheader: When True, the first row/column is not sorted.
casesensitive: Only for string comparisons. Default = False
sortcolumns: When True, the columns are sorted from left to right. Default = False : rows are sorted from top to bottom.
'Sort range based on columns A (ascending) and C (descending)
oDoc.SortRange("A2:J200", Array(1, 3), Array("ASC", "DESC"), CaseSensitive := True)
myDoc.SortRange("A2:J200", (1, 3), ("ASC", "DESC"), casesensitive = True)
All ScriptForge Basic routines or identifiers that are prefixed with an underscore character "-" are reserved for internal use. They are not meant be used in Basic macros or Python scripts.