SFDatabases.Database service/text/sbasic/shared/03/sf_database.xhpDatabase service
SFDatabases.Database service
The Database service provides access to databases either embedded or described in Base documents. This service provides methods to:Get access to data in database tables.Run SELECT queries and perform aggregate functions.Run SQL action statements such as INSERT, UPDATE, DELETE, etc.Each instance of the Database service represents a single database and gives access to its tables, queries and data.This service does not provide access to forms or reports in the Base document that contains the database. To access forms in a Base document, refer to the method FormDocuments of the Base service.All exchanges between this service and the database are done using SQL only.SQL statements may be run in direct or indirect mode. In direct mode the statement is transferred to the database engine without any syntax checking or review.The provided interfaces include simple tables and queries lists, as well as access to database data.To make SQL statements more readable, you may use square brackets "[ ]" to enclose names of tables, queries and fields instead of using other enclosing characters that may be exclusive to certain Relational Database Management Systems (RDBMS). But beware that enclosing characters are mandatory in this context.
Transaction handling
Database service; Transaction handlingBy default the database handles transactions in auto-commit mode, meaning that a commit is done after every SQL statement.Use the SetTransactionMode method to change the default behavior, which allows for manual commits and rollbacks.The methods Commit and Rollback are used to delimit transactions.In %PRODUCTNAME, there are five types of transaction isolation modes, as defined in the com.sun.star.sdbc.TransactionIsolation constant group:
ConstantValueInterpretationNONE0Transaction handling is disabled and the database is set to the default auto-commit mode.READ_UNCOMMITTED1Dirty reads, non-repeatable reads and phantom reads can occur.If a row is changed by a transaction, another transaction will be able to read these changes even if they have not been committed.READ_COMMITTED2Dirty reads are prevented, however non-repeatable reads and phantom reads can occur.This level prevents that rows with uncommitted changes are read.REPEATABLE_READ4Dirty reads and non-repeatable reads are prevented. However, phantom reads can occur.Besides preventing uncommitted data from being read, it also prevents that two read operations in the same transaction return different results.SERIALIZABLE8Dirty reads, non-repeatable reads and phantom reads are prevented.In addition to the constraints of the previous level, it also ensures that the set of records that match a WHERE clause remains unchanged inside the same transaction.
Read the Wikipedia page on Isolation in Database Systems to learn more about transaction integrity.
Service invocation
Before using the Database service the ScriptForge library needs to be loaded or imported:To create a instance of the Database service you can use the CreateScriptService method:
CreateScriptService("SFDatabases.Database", [filename: str], [registrationname], [readonly], [user, [password]]): svc
In the syntax described above you can use either "SFDatabases.Database" or simply "Database" as the first argument of the CreateScriptService method.filename: The name of the Base file. Must be expressed using SF_FileSystem.FileNaming notation.registrationname: The name of a registered database. If filename is provided, this argument should not be used.Conversely, if a registrationname is specified, the filename parameter should not be defined.readonly: Determines if the database will be opened as readonly (Default = True).user, password: Additional connection parameters to the database server.GlobalScope.BasicLibraries.LoadLibrary("ScriptForge")Dim myDatabase as ObjectSet myDatabase = CreateScriptService("Database", "/home/user/Documents/myDB.odb")' Run queries, SQL statements, ...myDatabase.CloseDatabase()from scriptforge import CreateScriptServicemyDatabase = CreateScriptService("Database", "/home/user/Documents/myDB.odb")# Run queries, SQL statements, ...myDatabase.CloseDatabase()
Accessing Databases with the UI Service
It is also possible to access the database associated with a Base document using the ScriptForge.UI service, as shown in the examples below:Dim myDoc As Object, myDatabase As Object, ui As ObjectSet ui = CreateScriptService("UI")Set myDoc = ui.OpenBaseDocument("/home/user/Documents/myDB.odb")' User and password are supplied below, if neededSet myDatabase = myDoc.GetDatabase()' Run queries, SQL statements, ...myDatabase.CloseDatabase()myDoc.CloseDocument()ui = CreateScriptService("UI")doc = ui.OpenBaseDocument("/home/user/Documents/myDB.odb")# User and password are supplied below, if neededmyDatabase = doc.GetDatabase()# Run queries, SQL statements, ...myDatabase.CloseDatabase()doc.CloseDocument()The GetDatabase method used in the example above is part of ScriptForge's Base service.Database Service;QueriesDatabase Service;Tables
Properties
NameReadonlyTypeDescriptionQueriesYesArray of stringsThe list of stored queries.TablesYesArray of stringsThe list of stored tables.XConnectionYesXConnectionThe UNO object representing the current database connection.XMetaDataYesXDatabaseMetaDataThe UNO object representing the metadata describing the database system attributes.
List of Methods in the Database Service
CloseDatabase
Commit
CreateDataset
DAvg
DCount
DMin
DMax
DSum
DLookup
GetRows
OpenFormDocument
OpenQuery
OpenSql
OpenTable
Rollback
RunSql
SetTransactionMode
Closes the current database connection.
db.CloseDatabase()
myDatabase.CloseDatabase() ' BasicmyDatabase.CloseDatabase() # Python Commit --------------------------------------------------------------------------------------------- Database Service;Commit
Commit
Commits all updates done since the previous Commit or Rollback call.This method is ignored if commits are done automatically after each SQL statement, i.e. the database is set to the default auto-commit mode.
db.Commit()
' Set the REPEATABLE_READ transaction levelmyDB.SetTransactionMode(4)myDB.RunSql("UPDATE ...")myDB.Commit()myDB.RunSql("DELETE ...")' Test some condition before committingIf bSomeCondition Then myDB.Commit()Else myDB.Rollback()End If' Restore auto-commit modemyDB.SetTransactionMode()myDB.SetTransactionMode(4)myDB.RunSql("UPDATE ...")myDB.Commit()myDB.RunSql("DELETE ...")if some_condition: myDB.Commit()else: myDB.Rollback()myDB.SetTransactionMode() CreateDataset -------------------------------------------------------------------------------------- Database Service;CreateDataset
CreateDataset
Creates a Dataset service instance based on a table, query or SQL SELECT statement.
db.CreateDataset(sqlcommand: str, opt directsql: bool, opt filter: str, opt orderby: str): svc
sqlcommand: A table name, a query name or a valid SQL SELECT statement. Identifiers may be enclosed with square brackets. This argument is case-sensitive.directsql: Set this argument to True to send the statement directly to the database engine without preprocessing by %PRODUCTNAME (Default = False).filter: Specifies the condition that records must match to be included in the returned dataset. This argument is expressed as a SQL WHERE statement without the "WHERE" keyword.orderby: Specifies the ordering of the dataset as a SQL ORDER BY statement without the "ORDER BY" keyword.The following examples in Basic and Python return a dataset with the records of a table named "Customers".oDataset = myDatabase.CreateDataset("Customers", Filter := "[Name] LIKE 'A'")dataset = myDatabase.CreateDataset("Customers", Filter = "[Name] LIKE 'A'") DFunctions ----------------------------------------------------------------------------------- Database Service;DAvgDatabase Service;DCountDatabase Service;DMaxDatabase Service;DMinDatabase Service;DSum
DAvg, DCount, DMin, DMax, DSum
Computes the given aggregate function on a field or expression belonging to a table.Optionally, a SQL WHERE clause can be specified as a filter that will be applied prior to the aggregate function.
db.DAvg(expression: str, tablename: str, [criteria: str]): any
db.DCount(expression: str, tablename: str, [criteria: str]): any
db.DMin(expression: str, tablename: str, [criteria: str]): any
db.DMax(expression: str, tablename: str, [criteria: str]): any
db.DSum(expression: str, tablename: str, [criteria: str]): any
expression: A SQL expression in which the field names are surrounded with square brackets.tablename: A table name (without square brackets).criteria: A WHERE clause without the "WHERE" keyword, in which field names are surrounded with square brackets.The example below assumes the file Employees.odb has a table named EmployeeData.GlobalScope.BasicLibraries.LoadLibrary("ScriptForge")Dim myDB as VariantSet myDB = CreateScriptService("Database", "/home/user/Databases/Employees.odb")' Counts the number of employees in the tableMsgBox myDB.DCount("[ID]", "EmployeeData")' Returns the sum of all salaries in the tableMsgBox myDB.DSum("[Salary]", "EmployeeData")' Below are some examples of how tables can be filteredMsgBox myDB.DCount("[ID]", "EmployeeData", "[Position] = 'Manager'")MsgBox myDB.DCount("[ID]", "EmployeeData", "[Position] = 'Sales' AND [City] = 'Chicago'")MsgBox myDB.DCount("[ID]", "EmployeeData", "[FirstName] LIKE 'Paul%'")myDB = CreateScriptService("Database", "/home/user/Databases/Employees.odb")bas = CreateScriptService("Basic")bas.MsgBox(myDB.DCount("[ID]", "EmployeeData"))bas.MsgBox(myDB.DSum("[Salary]", "EmployeeData"))bas.MsgBox(myDB.DCount("[ID]", "EmployeeData", "[Position] = 'Manager'"))bas.MsgBox(myDB.DCount("[ID]", "EmployeeData", "[Position] = 'Sales' AND [City] = 'Chicago'"))bas.MsgBox(myDB.DCount("[ID]", "EmployeeData", "[FirstName] LIKE 'Paul%'")) DLookup -------------------------------------------------------------------------------------------- Database Service;DLookup
DLookup
Computes a SQL expression on a single record returned by a WHERE clause defined by the Criteria parameter.If the query returns multiple records, only the first one is considered. Use the OrderClause parameter to determine how query results are sorted.
db.DLookup(expression: str, tablename: str, [criteria:str], [orderclause: str]): any
expression: A SQL expression in which the field names are surrounded with square brackets.tablename: A table name (without square brackets).criteria: A WHERE clause without the "WHERE" keyword, in which field names are surrounded with square brackets.orderclause: An ORDER BY clause without the "ORDER BY" keywords. Field names should be surrounded with square brackets.MsgBox myDB.DLookup("[FirstName]", "EmployeeData", Criteria := "[LastName] LIKE 'Smith'", OrderClause := "[FirstName] DESC")MsgBox myDB.DLookup("[Salary]", "EmployeeData", Criteria := "[ID] = '3'")MsgBox myDB.DLookup("[Quantity] * [Value]", "Sales", Criteria := "[SaleID] = '5014'")bas = CreateScriptService("Basic")bas.MsgBox(myDB.DLookup("[FirstName]", "EmployeeData", criteria = "[LastName] LIKE 'Smith'", orderclause = "[FirstName] DESC"))bas.MsgBox(myDB.DLookup("[Salary]", "EmployeeData", criteria = "[ID] = '3'"))bas.MsgBox(myDB.DLookup("[Quantity] * [Value]", "Sales", criteria = "[SaleID] = '5014'")) GetRows ---------------------------------------------------------------------------------------- Database Service;GetRows
GetRows
Stores the contents of a table or the results of a SELECT query or of an SQL statement in a two-dimensional array. The first index in the array corresponds to the rows and the second index refers to the columns.An upper limit can be specified to the number of returned rows. Optionally column names may be inserted in the first row of the array.The returned array will be empty if no rows are returned and the column headers are not required.
db.GetRows(sqlcommand: str, directsql: bool = False, header: bool = False, maxrows: int = 0): any
sqlcommand: A table or query name (without square brackets) or a SELECT SQL statement.directsql: When True, the SQL command is sent to the database engine without pre-analysis. Default is False. This argument is ignored for tables. For queries, the applied option is the one set when the query was defined.header: When True, the first row of the returned array contains the column headers.maxrows: The maximum number of rows to return. The default is zero, meaning there is no limit to the number of returned rows.Below are a few examples of how the GetRows method can be used:Dim queryResults as Variant' Returns all rows in the table with column headersqueryResults = myDB.GetRows("EmployeeData", Header := True)' Returns the first 50 employee records ordered by the 'FirstName' fieldqueryResults = myDB.GetRows("SELECT * FROM EmployeeData ORDER BY [FirstName]", MaxRows := 50)queryResults = myDB.GetRows("EmployeeData", header = True)queryResults = myDB.GetRows("SELECT * FROM EmployeeData ORDER BY [FirstName]", maxrows = 50) OpenFormDocument ------------------------------------------------------------------------------------- Database service;OpenFormDocument
OpenFormDocument
Opens the specified form document in normal mode. This method returns a FormDocument service instance corresponding to the specified form document.If the form document is already open, the form document window is activated.If the specified form document does not exist, then Nothing is returned.
svc.OpenFormDocument(formdocument: str): svc
formdocument: The name of the FormDocument to be opened, as a case-sensitive string.Most form documents are stored in the root of the Base document and they can be opened simply using their names, as in the example below:Dim oFormDoc As ObjectoFormDoc = myDB.OpenFormDocument("myFormDocument")If form documents are organized in folders, it becomes necessary to include the folder name to specify the form document to be opened, as illustrated in the following example:oFormDoc = myDB.OpenFormDocument("myFolder/myFormDocument")formDoc = myDB.OpenFormDocument("myFormDocument")formDoc = myDB.OpenFormDocument("myFolder/myFormDocument") OpenQuery ------------------------------------------------------------------------------------------- Database Service;OpenQuery
OpenQuery
Opens the Data View window of the specified query and returns an instance of the Datasheet service.If the query could not be opened, then Nothing is returned.
db.OpenQuery(queryname: str): obj
queryname: The name of an existing query as a case-sensitive String.myDatabase.OpenQuery("MyQuery")myDatabase.OpenQuery("MyQuery") OpenSql --------------------------------------------------------------------------------------------- Database Service;OpenSql
OpenSql
Runs a SQL SELECT command, opens a Data View window with the results and returns an instance of the Datasheet service.
db.OpenSql(sql: str, directsql: bool): obj
sql: A string containing a valid SQL SELECT statement. Identifiers may be enclosed by square brackets.directsql: When True, the SQL command is sent to the database engine without pre-analysis (Default = False).myDatabase.OpenSql("SELECT * FROM [Customers] ORDER BY [CITY]")myDatabase.OpenSql("SELECT * FROM [Customers] ORDER BY [CITY]") OpenTable ------------------------------------------------------------------------------------------- Database Service;OpenTable
OpenTable
Opens the Data View window of the specified table and returns an instance of the Datasheet service.
db.OpenTable(tablename: str): obj
tablename: The name of an existing table as a case-sensitive String.myDatabase.OpenTable("MyTable")myDatabase.OpenTable("MyTable") Rollback ------------------------------------------------------------------------------------------- Database Service;Rollback
Rollback
Cancels all changes made to the database since the last Commit or Rollback call.
db.Rollback()
myDB.SetTransactionMode(1)myDB.RunSql("UPDATE ...")' ...If bSomeCondition Then myDB.Rollback()End IfmyDB.SetTransactionMode(1)myDB.RunSql("UPDATE ...")# ...if bSomeCondition: myDB.Rollback() RunSql -------------------------------------------------------------------------------------------- Database Service;RunSql
RunSql
Executes an action query of an SQL statement such as creating a table, as well as inserting, updating and deleting records.The method returns True when successful.The RunSql method is rejected with an error message in case the database was previously opened in read-only mode.
db.RunSql(sqlcommand: str, directsql: bool = False): bool
sqlcommand: A query name (without square brackets) or a SQL statement.directsql: When True, the SQL command is sent to the database engine without pre-analysis. (Default = False). For queries, the applied option is the one set when the query was defined.myDatabase.RunSql("INSERT INTO [EmployeeData] VALUES(25, 'Smith', 'John')", DirectSQL := True)myDatabase.RunSql("INSERT INTO [EmployeeData] VALUES(25, 'Smith', 'John')", directsql = True) SetTransactionMode --------------------------------------------------------------------------------- Database Service;SetTransactionMode
SetTransactionMode
Defines the level of isolation in database transactions.By default databases manage transactions in auto-commit mode, which means that a Commit is automatically performed after every SQL statement.Use this method to manually determine the isolation level of transactions. When a transaction mode other than NONE is set, the script has to explicitly call the Commit method to apply the changes to the database.This method returns True when successful.Changing the transaction mode closes all Dataset instances created from the current database.
db.SetTransactionMode(transactionmode: int = 0): bool
transactionmode: Specifies the transaction mode. This argument must be one of the constants defined in com.sun.star.sdbc.TransactionIsolation (Default = NONE)Read the section Transaction handling above to learn more about the transaction isolation levels used in %PRODUCTNAME.myDB.SetTransactionMode(com.sun.star.sdbc.TransactionIsolation.REPEATABLE_READ)oDataset = myDB.CreateDataset("SELECT ...")' ...' Reset the transaction mode to defaultmyDB.SetTransactionMode()from com.sun.star.sdbc import TransactionIsolationmyDB.SetTransactionMode(TransactionIsolation.REPEATABLE_READ)dataset = myDB.CreateDataset("SELECT ...")# ...myDB.SetTransactionMode()