SFDocuments.Calc service

The SFDocuments library provides a number of methods and properties to facilitate the management and handling of LibreOffice Calc documents.

Some methods are generic for all types of documents and are inherited from the Document service, whereas other methods are specific for the SF_Calc module.

The SF_Calc module is focused on:

Service invocation

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.

In Basic

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.

In Python

    myDoc = CreateScriptService("Calc")
  

    svcUI = CreateScriptService("UI")
    myDoc = svcUI.CreateDocument("Calc")
  

    myDoc = svcUI.OpenDocument(r"C:\Documents\MyFile.ods")
  

    myDoc = CreateScriptService("SFDocuments.Calc", "MyFile.ods")
    myDoc.Dispose()
  
tip

The use of the prefix "SFDocuments." while calling the service is optional.


Definitions

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:

Example:

The example below copies data from document A (opened as read-only and hidden) to document B.

In Basic

    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)
  
In Python

    docA = svcUI.OpenDocument(r"C:\Documents\FileA.ods", hidden = True, readonly = True)
    docB = svcUI.OpenDocument(r"C:\Documents\FileB.ods")
    docB.CopyToRange(docA.Range("SheetX.D4:F8"), "D2:F6")
  

SheetName

Either the sheet name as a string or an object produced by the .Sheet property.

The shortcut "~" (tilde) represents the current sheet.

RangeName

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 in a range (default = the active sheet). Surrounding single quotes and $ signs are allowed but ignored.

tip

Except for the CurrentSelection property, the Calc service considers only single ranges of cells.


Examples of valid ranges

1) '$SheetX'.D2
2) $D$2

A single cell

1) '$SheetX'.D2:F6
2) 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) ~.someRange
2) 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


Properties

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

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

Height

Yes

RangeName As String

Long

The number of rows (>= 1) in the given range

LastCell

Yes

SheetName As String

String

The last used cell in 'A1' format in the given sheet

LastColumn

Yes

SheetName As String

Long

The last used column in the given sheet

LastRow

Yes

SheetName As String

Long

The last used row in the given sheet

Range

Yes

RangeName As String

Object

A range reference that can be used as argument of methods like CopyToRange

Sheet

Yes

SheetName As String

Object

A sheet reference that can be used as argument of methods like CopySheet

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

XSpreadsheet

Yes

SheetName As String

Object

A com.sun.star.sheet.XSpreadsheet UNO object


tip

Visit LibreOffice API Documentation's website to learn more about XCellRange and XSpreadsheet UNO objects.


Methods

List of Methods in the Calc Service

Activate
ClearAll
ClearFormats
ClearValues
CopySheet
CopySheetFromFile
CopyToCell
CopyToRange
DAvg
DCount

DMax
DMin
DSum
Forms
GetColumnName
GetFormula
GetValue
ImportFromCSVFile
ImportFromDatabase
InsertSheet

MoveRange
MoveSheet
Offset
RemoveSheet
RenameSheet
SetArray
SetValue
SetCellStyle
SetFormula
SortRange


Activate

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.

Syntax:

svc.Activate(sheetname: str = ""): bool

Parameters:

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.

Example:

The example below activates the sheet named "Sheet4" in the currently active document.

In Basic

    Dim ui as Variant, oDoc as Object
    Set ui = CreateScriptService("UI")
    Set oDoc = ui.GetDocument(ui.ActiveWindow)
    oDoc.Activate("Sheet4")
  
In Python

    svcUI = CreateScriptService("UI")
    myDoc = svcUI.GetDocument(svcUI.ActiveWindow)
    myDoc.Activate("Sheet4")
  
tip

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.


ClearAll

Clears all the contents and formats of the given range.

Syntax:

svc.ClearAll(range: str)

Parameters:

range: The range to be cleared, as a string.

Example:

In Basic

      oDoc.ClearAll("SheetX.A1:F10")
  
In Python

    myDoc.ClearAll("SheetX.A1:F10")
  

ClearFormats

Clears the formats and styles in the given range.

Syntax:

svc.ClearFormats(range: str)

Parameters:

range: The range whose formats and styles are to be cleared, as a string.

Example:

In Basic

      oDoc.ClearFormats("SheetX.*")
  
In Python

    myDoc.ClearFormats("SheetX.*")
  

ClearValues

Clears the values and formulas in the given range.

Syntax:

svc.ClearValues(range: str)

Parameters:

range: The range whose values and formulas are to be cleared, as a string.

Example:

In Basic

      oDoc.ClearValues("SheetX.A1:F10")
  
In Python

    myDoc.ClearValues("SheetX.A1:F10")
  

CopySheet

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.

Syntax:

svc.CopySheet(sheetname: any, newname: str, [beforesheet: any]): bool

Parameters:

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 behavior is to add the copied sheet at the last position.

Example:

In Basic

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")
  
In Python

    myDoc.CopySheet("SheetX", "SheetY")
  

    docA = svcUI.OpenDocument(r"C:\Documents\FileA.ods", hidden = True, readonly = True)
    docB = svcUI.OpenDocument(r"C:\Documents\FileB.ods")
    docB.CopySheet(docA.Sheet("SheetX"), "SheetY")
  
tip

To copy sheets between open documents, use CopySheet. To copy sheets from documents that are closed, use CopySheetFromFile.


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.

Syntax:

svc.CopySheetFromFile(filename: str, sheetname: str, newname: str, [beforesheet: any]): bool

Parameters:

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 behavior is to add the copied sheet at the last position.

Example:

The following example copies "SheetX" from "myFile.ods" and pastes it into the document referred to by "oDoc" as "SheetY" at the first position.

In Basic

    oDoc.CopySheetFromFile("C:\Documents\myFile.ods", "SheetX", "SheetY", 1)
  
In Python

    myDoc.CopySheetFromFile(r"C:\Documents\myFile.ods", "SheetX", "SheetY", 1)
  

CopyToCell

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.

Syntax:

svc.CopyToCell(sourcerange: any, destinationcell: str): str

Parameters:

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.

Example:

In Basic

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()
  
In Python

    docSource = svcUI.OpenDocument(r"C:\Documents\SourceFile.ods", hidden = True, readonly = True)
    docDestination = CreateScriptService("Calc")
    docDestination.CopyToCell(docSource.Range("Sheet1.C2:C4"), "SheetT.A5")
    docSource.CloseDocument()
  
tip

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.


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.

Syntax:

svc.CopyToRange(sourcerange: any, destinationrange: str): str

Parameters:

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.

Example:

In Basic

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")
  
In Python

    doc.CopyToRange("SheetX.A1:F10", "SheetY.C5:J5")
  

    docA = svcUI.OpenDocument(r"C:\Documents\FileA.ods", hidden = True, readonly = True)
    docB = svcUI.OpenDocument(r"C:\Documents\FileB.ods")
    docB.CopyToRange(docA.Range("SheetX.A1:F10"), "SheetY.C5:J5")
  

DAvg, DCount, DMax, DMin and DSum

Apply the functions Average, Count, Max, Min and Sum, respectively, to all the cells containing numeric values on a given range.

Syntax:

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

Parameters:

range: The range to which the function will be applied, as a string.

Example:

The example below applies the Sum function to the range "A1:A1000" of the currently selected sheet:

In Basic

      result = oDoc.DSum("~.A1:A1000")
  
In Python

    result = myDoc.DSum("~.A1:A1000")
  
note

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.


Forms

Depending on the parameters provided this method will return:

Syntax:

svc.Forms(sheetname: str): str[0..*]

svc.Forms(sheetname: str, form: str = ''): svc

svc.Forms(sheetname: str, form: int): svc

Parameters:

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.

Example:

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".

In Basic

    Set FormNames = oDoc.Forms("Sheet1")
    Set FormA = oDoc.Forms("Sheet1", "Form_A")
  
In Python

    form_names = doc.Forms("Sheet1")
    form_A = doc.Forms("Sheet1", "Form_A")
  

GetColumnName

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.

Syntax:

svc.GetColumnName(columnnumber: int): str

Parameters:

columnnumber: The column number as an integer value in the interval 1 ... 1024.

Example:

In Basic

Displays a message box with the name of the third column, which by default is "C".


    MsgBox oDoc.GetColumnName(3)
  
In Python

    sBasic = CreateScriptService("Basic")
    sBasic.MsgBox(myDoc.GetColumnName(3))
  
note

The maximum number of columns allowed on a Calc sheet is 1024.


GetFormula

Get the formula(s) stored in the given range of cells as a single string, a 1D or a 2D array of strings.

Syntax:

svc.GetFormula(range: str): any

Parameters:

range: The range where to get the formulas from, as a string.

Example:

In Basic

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")
  
In Python

    arrFormula = myDoc.GetFormula("~.A1:B3")
  

GetValue

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.

Syntax:

svc.GetValue(range: str): any

Parameters:

range: The range where to get the values from, as a string.

Example:

In Basic

      arrValues = oDoc.GetValue("~.B1:C100")
  
In Python

    arrValues = myDoc.GetValue("~.B1:C100")
  
note

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.


ImportFromCSVFile

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.

Syntax:

svc.ImportFromCSVFile(filename: str, destinationcell: str, [filteroptions: str]): str

Parameters:

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:

Example:

In Basic

    oDoc.ImportFromCSVFile("C:\Temp\myCSVFile.csv", "SheetY.C5")
  
In Python

    myDoc.ImportFromCSVFile(r"C:\Temp\myCSVFile.csv", "SheetY.C5")
  
tip

To learn more about the CSV Filter Options, refer to the Filter Options Wiki page.


ImportFromDatabase

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.

Syntax:

svc.ImportFromDatabase(filename: str = "", registrationname: str = "", destinationcell: str = "", sqlcommand: str = "", directsql: bool): bool

Parameters:

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.

Example:

In Basic

    oDoc.ImportFromDatabase("C:\Temp\myDbFile.odb", , "SheetY.C5", "SELECT * FROM [Employees] ORDER BY [LastName]")
  
In Python

    myDoc.ImportFromDatabase(r"C:\Temp\myDbFile.odb", , "SheetY.C5", "SELECT * FROM [Employees] ORDER BY [LastName]")
  

InsertSheet

Inserts a new empty sheet before an existing sheet or at the end of the list of sheets.

Syntax:

svc.InsertSheet(sheetname: str, [beforesheet: any]): bool

Parameters:

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 behavior is to insert the sheet at the last position.

Example:

The following example inserts a new empty sheet named "SheetX" and places it before "SheetY":

In Basic

    oDoc.InsertSheet("SheetX", "SheetY")
  
In Python

    myDoc.InsertSheet("SheetX", "SheetY")
  

MoveRange

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.

Syntax:

svc.MoveRange(source: str, destination: str): str

Parameters:

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.

Example:

In Basic

    oDoc.MoveRange("SheetX.A1:F10", "SheetY.C5")
  
In Python

    myDoc.MoveRange("SheetX.A1:F10", "SheetY.C5")
  

MoveSheet

Moves an existing sheet and places it before a specified sheet or at the end of the list of sheets.

Syntax:

svc.MoveSheet(sheetname: str, [beforesheet: any]): bool

Parameters:

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 behavior is to move the sheet to the last position.

Example:

The example below moves the existing sheet "SheetX" and places it before "SheetY":

In Basic

    oDoc.MoveSheet("SheetX", "SheetY")
  
In Python

    myDoc.MoveSheet("SheetX", "SheetY")
  

Offset

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 behavior as the homonymous Calc's Offset function.

Syntax:

svc.Offset(reference: str, rows: int = 0, columns: int = 0, [height: int], [width: int]): str

Parameters:

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.

Example:

In Basic

    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)
  
In Python

    myDoc.Offset("A1", 2, 2)
    myDoc.Offset("A1", 2, 2, 5, 6)
  

RemoveSheet

Removes an existing sheet from the document.

Syntax:

svc.RemoveSheet(sheetname: str): bool

Parameters:

sheetname: The name of the sheet to remove.

Example:

In Basic

    oDoc.RemoveSheet("SheetY")
  
In Python

    myDoc.RemoveSheet("SheetY")
  

RenameSheet

Renames the given sheet and returns True if successful.

Syntax:

svc.RenameSheet(sheetname: str, newname: str): bool

Parameters:

sheetname: The name of the sheet to rename.

newname: the new name of the sheet. It must not exist yet.

Example:

This example renames the active sheet to "SheetY":

In Basic

    oDoc.RenameSheet("~", "SheetY")
  
In Python

    mydoc.RenameSheet("~", "SheetY")
  

SetArray

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.

Syntax:

svc.SetArray(targetcell: str, value: any): str

Parameters:

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.

Example:

In Basic

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))
  
In Python

    arrData = ((1, "One"), (2, "Two"), (3, "Three"))
    myDoc.SetArray("Sheet1.A1", arrData)
  

    myDoc.SetArray("Sheet1.A1", tuple(i + 1 for i in range(1000)))
  
tip

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.


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.

Syntax:

svc.SetValue(targetrange: str, value: any): str

Parameters:

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.

Example:

In Basic

    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)
  
In Python

    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)
  

SetCellStyle

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.

Syntax:

svc.SetCellStyle(targetrange: str, style: str): str

Parameters:

targetrange: The range to which the style will be applied, as a string.

style: The name of the cell style to apply.

Example:

In Basic

    oDoc.SetCellStyle("A1:J1", "Heading 1")
    oDoc.SetCellStyle("A2:J100", "Neutral")
  
In Python

    myDoc.SetCellStyle("A1:J1", "Heading 1")
    myDoc.SetCellStyle("A2:J100", "Neutral")
  

SetFormula

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.

Syntax:

svc.SetFormula(targetrange: str, formula: any): str

Parameters:

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.

Example:

In Basic

    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")
  
In Python

    myDoc.SetFormula("A1", "=A2")
    myDoc.SetFormula("A1:F1", ("=A2", "=B2", "=C2+10"))
    myDoc.SetFormula("A1:D2", "=E1")
  

SortRange

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.

Syntax:

svc.SortRange(range: str, sortkeys: any, sortorder: any = "ASC", destinationcell: str = "", containsheader: bool = False, casesensitive: bool = False, sortcolumns: bool = False): str

Parameters:

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.

Example:

In Basic

    'Sort range based on columns A (ascending) and C (descending)
    oDoc.SortRange("A2:J200", Array(1, 3), Array("ASC", "DESC"), CaseSensitive := True)
  
In Python

    myDoc.SortRange("A2:J200", (1, 3), ("ASC", "DESC"), casesensitive = True)
  
warning

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.


Please support us!