%SYSTEM.SQL.Util
abstract class %SYSTEM.SQL.Util extends %SYSTEM.Help
Method Inventory
- CloseAllGateways()
- GetDefaultCollation()
- GetMapSelectability()
- GetOption()
- GetXDBCConnectionLimit()
- SetDDLIdentifierTranslations()
- SetDefaultCollation()
- SetMapSelectability()
- SetOption()
- SetXDBCConnectionLimit()
Methods
Parameters:
- Set coll=$SYSTEM.SQL.Util.GetDefaultCollation() // get current default collation name for %Library.String datatype in current namespace
Returns:
- the current default collation name for %Library.String datatype
Examples:
Parameters:
- pTablename
- Name of the table to check.
pTablename can be qualified or unqualified. If unqualified, the default schema is applied. - pMapname
- Name of the SQL Map in the table to check the selectable for.
Returns: 1 if the map is selectable, 0 if the map is not selectable. If the table or map does not exist, or there is an invalid input paramater, 0,message will be returned as the map is not selectable or the selectability cannot be determined.
Notes:
- A return of 1 by this function does not necessarily mean the table and map exist, just that the map's selectability has not been set to 0.
- This function checks the selectability for the map in the current namespace only.
If this table is mapped to multiple namespaces, and the index needs to be built in each namespace, SetMapSelectability should be called in each namespace the index is to be built in. GetMapSelectability should be checked in each namespace the table is mapped to.
Example:
- Write $SYSTEM.SQL.Util.GetMapSelectability("Sample.Person","NameIdx")
Sample.Person is part of https://github.com/intersystems/Samples-Data.Opens in a new tab See Downloading SamplesOpens in a new tab.
AdaptiveMode - Returns the configuration setting which determines if adaptive mode is applied.
- 0 = Do not apply adaptive mode.
- 1 = Apply Adaptive Mode (this covers Run Time Plan Choice, automatic parallelized query execution, automatic tuning of untuned tables, Frozen/Upgrade query plans, and more. Please see the product documentation for a complete overview; 1 = Default).
- 0 = Do not allow extrinsic functions in SQL statements through ODBC, JDBC, or Dynamic SQL (Default).
- 1 = Allow extrinsic functions in SQL statements through ODBC, JDBC, or Dynamic SQL.
- 0 = Do not apply ANSI precedence in SQL statements.
- 1 = Apply ANSI precedence in SQL statements (Default).
- 0 = NO AUTO TRANSACTION
- 1 = AUTO COMMIT ON (Default)
- 2 = AUTO COMMIT OFF
- 0 = Do not apply auto hinting for %PARALLEL in SQL statements
- 1 = Apply auto hinting for %PARALLEL in SQL (Default)
- 0 = The class compiler will not perform this check and no error will be returned if the class contains a bitmap index and does not have a positive integer ID type (Default).
- 1 = The class compiler will check to make sure the type of ID of the class is a positive integer if there is a bitmap index defined for the class and the class uses %Storage.SQL.
CachedQueryLockTimeout - Returns the configuration setting for lock timeout length, in seconds, used for Cached Queries when a lock needs to be acquired on Cached Query metadata.
CachedQuerySaveSource - Returns the configuration setting for cached queries source code retention. The default is no source is saved. The setting is on a per-system basis.
- 0 - Source is deleted after the cached query has compiled (Default)
- 1 - Source is retained for cached query classes.
ClientMaxIdleTime - The maximum time (in seconds) that a client may stay idly connected to the server before the server will close the connection.
CollectionProjection - Returns the configuration setting for collection projection. Possible values are:- 0 = Do not project collections as columns if also projected as child table (Default).
- 1 = Project all collections as columns.
DDLDefineBitmapExtent - Returns the configuration setting flag which determines if a class created by a DDL CREATE TABLE statement defines a bitmap extent index for the class.
- 0 = Do not define a Bitmap Extent index for a table created through DDL.
- 1 = Automatically define a Bitmap Extent index for tables created through DDL (Default)
DDLDropTabDelData - Returns the configuration setting flag which determines if a DDL DROP TABLE statement deletes the table's data.
- 0 = DROP TABLE will not delete the table's data when the table is dropped
- 1 = DROP TABLE will delete the table's data when the table is dropped (Default).
DDLFinal - Returns the configuration setting flag which determines if a class created by a DDL CREATE TABLE statement is Final.
- 0 = CREATE TABLE will not define a class as Final
- 1 = CREATE TABLE will define a class as Final (Default)
DDLPKeyNotIDKey - Returns the configuration setting for PRIMARY KEY in DDL also being the IDKey index.
- 0 = Primary Key constraints will also become IDKey indices
- 1 = Primary Key constraints will NOT become IDKey indices (Default)
DDLUseExtentSet - Returns the configuration setting flag which determines if a class created by a DDL CREATE TABLE statement defines the USEEXTENTSET class parameter to a value of 1.
- 0 = CREATE TABLE will define the USEEXTENTSET class parameter with a value of 0
- 1 = CREATE TABLE will define the USEEXTENTSET class parameter with a value of 1 (Default)
DDLUseSequence - Returns the configuration setting flag which determines if a class created by a DDL CREATE TABLE statement uses $Sequence for ID assignment.
- 0 = CREATE TABLE uses $Increment for ID assignment
- 1 = CREATE TABLE uses $Sequence for ID assignment (Default)
DefaultTimePrecision - Returns the configuration setting for default precision for the Time component of the value returned by the GETDATE(), CURRENT_TIME, and CURRENT_TIMESTAMP SQL Scalar functions.
DelimitedIdentifiers - Returns the configuration setting which determines if double quote ("") in an SQL statement is used for delimited (quoted) identifiers or string constants.
- 0 = In an SQL statement, "..." is treated as a string literal
- 1 = In an SQL statement, "..." is treated as an identifier (Default)
ECPSync - Returns whether or not SQL SELECT statements perform a $SYSTEM.ECP.Sync() call in the OPEN code.
- 0 = Do not perform ECP Syncs for Select queries (Default)
- 1 = Perform ECP Syncs for Select queries
FastDistinct - Returnss whether or not SQL DISTINCT is optimized to use indexes.
- 0 = DISTINCT optimization is turned OFF
- 1 = DISTINCT optimization is turned ON (Default)
FilerRefIntegrity - Returnss the configuration setting which determines if Foreign Key Referential Integrity checks are performed in the SQL Filer. Turning off SQL Filer Referential Integrity checking will suppress any SQLCODE -121, -122, -123, and -124 errors.
- 0 = Foreign Key Referential Integrity checks are not performed
- 1 = Foreign Key Referential Integrity checks are performed (Default)
- 0 = IDENTITY cannot be set (Default).
- 1 = IDENTITY can be set.
- 0 = READ UNCOMMITTED (Default).
- 1 = READ COMMITTED
- 3 = READ VERIFIED
ParameterSampling - Returns the configuration setting which determines if parameter sampling is enabled
- 0 = Parameter sampling is disabled (Default).
- 1 = Parameter sampling is enabled.
RetainSQL - Gets the configuration setting which determines if embedded SQL statements are retained as comments in the .INT code version of the routine.
- 0 = SQL text will be not retained as comments in the .INT code.
- 1 = SQL text will be retained as comments in the INT code (Default).
- 0 = Do not apply Run Time Plan Choice in SQL statements.
- 1 = Apply Run Time Plan Choice in SQL statements (Default).
SQLSecurity - Returns the configuration setting which determines if SQL security is enabled.
- 0 = SQL security is OFF.
- 1 = SQL security is ON (Default).
- 0 = Logical (Default).
- 1 = ODBC
- 2 = Display
#SQLCompile Select = Runtime
is specified for the compiled SQL code.
When the SQL statement is compiled in Runtime mode, the mode returned by GetSelectMode will be used at runtime to determine whether Logical(0), ODBC(1), or Display(2) mode is used for the statement. See the documentation for #SQLCompile Select for more information. ServerDisconnectCode - Returns ODBC/JDBC disconnect code. Upon disconnect any ObjectScript code defined in this setting will be executed immediately before the server process Halts. This code will also attempt to be executed anytime the server process encounters an unrecoverable error that causes the server process to Halt. It will not be executed if the server process encounters a Halt in other user defined code, if the process crashes, if the process is stopped, or InterSystems IRIS is stopped or forced down. If no disconnect code is defined for this namespace, "" is returned. The disconnect code is defined on a per-namespace basis. ServerInitCode - Returns ODBC/JDBC/SQL Manager initialization code. This Initialization code is executed at login time when connecting to SQL through ODBC, JDBC, or the SQL Manager. If no initialization code is defined for this namespace, "" is returned. Initialization code is defined on a per-namespace basis.
TCPKeepAlive - Returns the TCP Keep Alive interval (in seconds) for xDBC connections.
ToDateDefaultFormat - Returns the default format for the SQL TO_DATE() function.
Example:
- Write $SYSTEM.SQL.Util.GetOption("AutoCommit")
Parameters:
- Set limit=$SYSTEM.SQL.Util.GetXDBCConnectionLimit()
Returns:
- An %Integer value of the current xDBC connection limit setting for this instance
Notes:
- A value of -1 or "" means no connection limit is currently defined for this instance.
Examples:
This is for filtering/modifying valid SQL identifier characters when translating SQL identifiers into Objects identifiers. When converting an SQL identifier to an Objects Identifier at DDL run time, the characters in the 'from' list will be converted to the characters in the 'to' list. This is done through the ObjectScript $Translate function.
For example:
Parameter:
- from
- A string of characters to translate from
- to
- A string of characters to translate to (by position in the string) Optional. Default is "".
- oldfrom
- Passed By Reference. Contains the previous value of the 'from' setting
- oldto
- Passed By Reference. Contains the previous value of the 'to' setting
- %Status
Parameters:
- newValue
- new default collation name, such as "SQLUPPER"
- systemWide
- 1/0 flag. 1 means set this default collation for %Library.String datatype system wide. 0 means set this default collation for %Library.String datatype for current namespace.
- outValue
- the current (before change to newValue) default collation name for %Library.String datatype
Returns:
- A %Status indicating whether the operation was successful
Examples:
- Set status=$SYSTEM.SQL.Util.SetDefaultCollation("SQLSTRING",1,.oldValue) // set default collation for %Library.String datatype to SQLSTRING systemwide
Parameters:
- pTablename
- Name of the table to check.
pTablename can be qualified or unqualified. If unqualified, the default schema is applied. - pMapname
- Name of the SQL Map(s) in the table to make selectable or not selectable. This can be a comma delimited string list of maps (e.g. "map1" or "map1,map2,map3" or $listtostring($lb("map1","map2"))) or a list of maps (e.g. $lb("map1") or $lb("map1","map2") or $listfromstring("map1,map2,map3")).
- pValue
- 1/0 flag. 1 means make this map Selectable - the SQL Query Optimizer will be able to choose this map. 0 means make this map Not Selectable - the SQL Query Optimizer will NOT be able to consider this map
Returns:
- A %Status indicating whether the operation was successful
Notes:
- This feature is not useful for extent indices (non bitmap). When a non-bitmap extent index is defined, the data map projected to SQL will use both the extent index global and the data map global.
When a non-bitmap extent index is added to a table with existing data, the index must be populated before any queries are run against the table. If not, any queries plans that loop over the data map will return no data.
- There is no check to see if the table and/or map exists. This is so the selectability of the map can be defined for a table/map that does not yet exist.
- This feature sets the selectability for the map in the current namespace only. If this table is mapped to multiple namespaces, and the index needs to be built in each namespace, SetMapSelectability should be called in each namespace the index is to be built in.
- Also, this feature sets the selectability for the map in the current table only. If there is a subclass that inherits the index map, and the index is being rebuilt for the entire extent, SetMapSelectability should be called for each table/map in the extent.
Examples:
- Write $SYSTEM.SQL.Util.SetMapSelectability("Sample.Person","NameIdx",1) // SQL Query Optimizer WILL consider map NameIdx
- Write $SYSTEM.SQL.Util.SetMapSelectability("Sample.Person","NameIdx",0) // SQL Query Optimizer WILL NOT consider map NameIdx
- Write $SYSTEM.SQL.Util.SetMapSelectability("Sample.Person",$lb("NameIdx","SSNKey"),1) // SQL Query Optimizer WILL consider maps NameIdx or SSNKey
- Write $SYSTEM.SQL.Util.SetMapSelectability("Sample.Person","NameIdx,SSNKey",0) // SQL Query Optimizer WILL NOT consider maps NameIdx or SSNKey
AdaptiveMode - Set the configuration setting which determines if adaptive mode is applied.
- pValue = 0, do not apply adaptive mode.
- pValue = 1, apply Adaptive Mode (this covers Run Time Plan Choice, automatic parallelized query execution, automatic tuning of untuned tables, Frozen/Upgrade query plans, and more. Please see the product documentation for a complete overview; 1 = Default).
- You must have the "USE" permission on the %Admin_Manage Resource in order to change this configuration setting.
- Changing this configuration setting will only take effect for this process and new processes starting in InterSystems IRIS after this function is called. Any existing processes will still use the old setting.
- This is a system-wide setting.
AllowExtrinsicFunctions - determines if extrinsic functions are allowed to be used in SQL statements through ODBC, JDBC, and Dynamic SQL.
- pValue = 0, do not allow extrinsic functions in SQL statements through ODBC, JDBC, or Dynamic SQL (Default).
- pValue = 1, allow extrinsic functions in SQL statements through ODBC, JDBC, or Dynamic SQL.
Notes
ANSIPrecedence - determines if ANSI operator precedence is applied.
- pValue = 0, do not apply ANSI precedence in SQL statements.
- pValue = 1, apply ANSI precedence in SQL statements (Default).
Notes
AutoCommit - Sets the AUTO_COMMIT mode for this process.
- pValue = 0, No AutoCommit
- pValue = 1, AutoCommit ON (Default).
- pValue = 2, AutoCommit OFF.
Notes
AutoParallel - Sets the configuration setting which determines if auto hinting %PARALLEL is applied. The default is use of auto hinting %PARALLEL is applied.
- pValue = 0, do not apply auto hinting for %PARALLEL in SQL statements
- pValue = 1, apply auto hinting for %PARALLEL in SQL (Default)
Notes
AutoParallelThreshold - Sets the configuration setting which determines the threshold of auto hinting %PARALLEL.
Once AutoParallel is enabled, use this function to set the threshold for this feature. Increasing the threshold means it would lower the chance for the auto hinting for %PARALLEL to happen
The default value is 3200. This value could be roughly thought of as how many rows in the visited map
- pValue = Auto parallel threshold value (integer). Default is 3200.
Notes
BitmapFriendlyCheck - determine if the compiler should check if the bitmap index is allowed in a %Storage.SQL class.
This setting only applies to classes using %Storage.SQL.
- pValue = 0, If a %Storage.SQL class is defined with an ID that is not a positive integer, it is up to the developer of the class to make sure the index is data is properly stored and retrieved from the global. An INTEGER type means the class must have either no IDKey index, or a single field IDKey index. If the class has a single field IDKey index, the type of the IDKey property must be of SqlCategory="INTEGER" or SqlCategory="NUMERIC" with a SCALE=0 and MINVAL=1 or higher. (Default)
- pValue = 1, During class compilation the compiler will check to make sure the ID of the table is an INTEGER type if there are any bitmap or bitmap extent indices defined
Notes
CachedQueryLockTimeout - Defines the lock timeout length, in seconds, used for Cached Queries when a lock needs to be acquired on Cached Query metadata.
- The setting is on a per system basis.
- pValue = the number of seconds to use for the lock timeout of Cached Query metadata. The default is 120 seconds.
Notes
CachedQuerySaveSource - Defines whether or not the source code for cached queries is retained. The default is no source is saved. The setting is on a per-system basis.
- pValue = 0, Source is deleted after the cached query has compiled (Default)
- pValue = 1, Source is retained for cached query classes. Any new cached queries created by any process will immediately begin saving (or not saving) cached query source. Any existing cached queries will only have source saved if the system was configured to save source at the time the statement was prepared.
Notes
ClientMaxIdleTime - The maximum time (in seconds) that a client may stay idly connected to the server before the server will close the connection.
- pValue = an integer specifying the time, in seconds, that a client connecton may sit idle. 0 indicates no time limit.
- You must have the "USE" permission on the %Admin_Manage Resource in order to change this configuration setting.
- Changing this configuration setting will only take effect for new processes starting in InterSystems IRIS after this function is called. Any existing processes will still use the old setting.
- This is a system-wide setting.
- pValue = 0, Do not project collections as a column if the collection is projected as a child table. (Default)
- pValue = 1, Project all collections as columns.
Notes
CompileModeDeferred -
Set the namespace wide flag which turns on Deferred Compilation mode.
'Deferred Compilation Mode' can be used to improve the performance of 'installation-type' activities. Deferred Compilation Mode will, in most cases, reduce the number of class compilations
that take place during the loading of tables through DDL scripts. When Deferred Compilation Mode is on, classes are not immediately compiled, but put in a compilation queue which will be compiled at a later time when needed.
This is very useful during loading of DDL scripts of the following format:
- CREATE TABLE MyTable ...
- CREATE INDEX MyIndex1 ON MyTable ...
- CREATE INDEX MyIndex2 ON MyTable ...
- CREATE INDEX MyIndex3 ON MyTable ...
- CREATE INDEX MyIndex4 ON MyTable ...
- CREATE INDEX MyIndex5 ON MyTable ...
- CREATE TABLE MyOtherTable ...
- CREATE INDEX MyOtherIndex1 ON MyOtherTable ...
- CREATE INDEX MyOtherIndex2 ON MyOtherTable ...
- CREATE INDEX MyOtherIndex3 ON MyOtherTable ...
- CREATE INDEX MyOtherIndex4 ON MyOtherTable ...
- CREATE INDEX MyOtherIndex5 ON MyOtherTable ...
- ALTER TABLE MyOtherTable ADD FOREIGN KEY MyFKey (MyField) REFERENCES MyTable(MyField)
- INSERT INTO MyTable ...
Running with Deferred Compilation Mode off would require 13 class compilations for the sequence above.
With Deferred Compilation Mode on, only two class compilations are required.
Classes MyTable and MyOtherTable are compiled when the INSERT statement is encountered.
Changing from Deferred to Immediate Compilation Mode will cause any classes in the Deferred Compile Queue to be compiled immediately.
If all class compilations were successful, SQLCODE will return 0. If there were any errors, SQLCODE will equal -400.
Class compilation errors are logged in the ^mtemp2($namespace,"Deferred Compile Mode","Error").
If SQLCODE=-400 you should view this global structure for more precise error messages.
When in Deferred Compilation Mode, any of the following actions will trigger the classes in the Deferred Compilation Queue to be immediately compiled:
- Switch back to immediate compile mode.
- An xDBC Catalog query is called.
- A DML statement is issued (INSERT, SELECT, GRANT, etc)
- CREATE INDEX statement is executed.
- DROP INDEX statement is executed.
- ALTER TABLE to add a required field to a table with a default value.
- ALTER TABLE to modify a field to be required.
Notes
CompileModeImmediate - Set the namespace wide flag which turns on Immediate Compilation mode. Immediate Compile Mode is the default compilation mode. If there are
pending compilations when switching from Deferred/Install Compile Mode, they will be compiled immediately.
Notes
CompileModeInstall - Set the namespace wide flag which turns on Install Compilation mode. This mode should only be used for installation procedures where no data
exists for any of the tables being created. If data exists for the tables definitions being manipulated through DDL statement, use
Deferred Compile Mode instead.
This is very useful during loading of DDL scripts of the following format:
- CREATE TABLE MyTable ...
- CREATE INDEX MyIndex1 ON MyTable ...
- CREATE INDEX MyIndex2 ON MyTable ...
- CREATE INDEX MyIndex3 ON MyTable ...
- CREATE INDEX MyIndex4 ON MyTable ...
- CREATE INDEX MyIndex5 ON MyTable ...
- CREATE TABLE MyOtherTable ...
- CREATE INDEX MyOtherIndex1 ON MyOtherTable ...
- CREATE INDEX MyOtherIndex2 ON MyOtherTable ...
- CREATE INDEX MyOtherIndex3 ON MyOtherTable ...
- CREATE INDEX MyOtherIndex4 ON MyOtherTable ...
- CREATE INDEX MyOtherIndex5 ON MyOtherTable ...
- ALTER TABLE MyOtherTable ADD FOREIGN KEY MyFKey (MyField) REFERENCES MyTable(MyField)
- INSERT INTO MyTable ...
Running with Install Compilation Mode off would require 13 class compilations for the sequence above.
With Install Compilation Mode on, only one class compilation is required.
Classes MyTable and MyOtherTable are compiled when the INSERT statement is encountered.
Changing from Install to Immediate Compilation Mode will cause any classes in the Deferred Compile Queue to be compiled immediately.
If all class compilations were successful, SQLCODE will return 0. If there were any errors, SQLCODE will equal -400.
Class compilation errors are logged in the ^mtemp2($namespace,"Deferred Compile Mode","Error").
If SQLCODE=-400 you should view this global structure for more precise error messages.
When in Install Compilation Mode, any of the following actions will trigger the classes in the Deferred Compilation Queue to be immediately compiled:
- Switch back to immediate compile mode.
- An xDBC Catalog query is called.
- A DML statement is issued (INSERT, SELECT, GRANT, etc)
Notes
CompileModeNocheck - Set the namespace wide flag which turns on Nocheck Compilation mode. This mode is the same as immediate mode except that existing data is not
validated against new constraints. For example, if you add a unique constraint to a table that already has data, Nocheck mode will not validate that
the constraint is valid. This compile mode must be used with extreme caution. You could end up with data integrity problems in your application.
In NOCHECK compile mode, the following constraints are not checked when executing DDL statements:
- If a table is dropped, there are no checks to see if any foreign key constraints in other tables reference this table.
- If a foreign key constraint is added, there are no checks to see if any existing data in the table is valid for the foreign key.
- If a NOT NULL constraint is added to a table with existing data, there is no validation that any existing rows are NOT NULL, nor is there an update of existing rows to assign the field's default value if there is one.
- If a UNIQUE or Primary key constraint is deleted, there is no check to see if a foreign key in this or another table had referenced the key.
Notes
DDLDefineBitmapExtent - Sets the flag which determines if a class created by a DDL CREATE TABLE statement defines a bitmap extent index for the class. This setting only applies to classes created through DDL that do not also define an explicit IDKey index.
- pValue = 0, Do not define a Bitmap Extent index for a table created through DDL.
- pValue = 1, Automatically define a Bitmap Extent index for tables created through DDL (Default).
Notes
DDLDropTabDelData - Sets the flag which determines if a DDL DROP TABLE statement deletes the table's data.
- pValue = 0, DROP TABLE will not delete the table's data when the table is dropped
- pValue = 1, DROP TABLE will delete the table's data when the table is dropped (Default).
Notes
DDLFinal - Sets the flag which determines if a class created by a DDL CREATE TABLE statement is Final.
- pValue = 0, CREATE TABLE will not define a class as Final
- pValue = 1, CREATE TABLE will define a class as Final (Default)
Notes
DDLPKeyNotIDKey - Set configuration setting for PRIMARY KEY in DDL also being the IDKey index. This configuration setting determines if a primary key constraint, specified through DDL, also becomes
the IDKey index in the class definition. Having the primary key index also be an IDKey index generally gives better performance, but it means the Primary key fields cannot be updated.
- pValue = 0, Primary Key constraints will also become IDKey indices
- pValue = 1, Primary Key constraints will NOT become IDKey indices (Default)
Notes
- pValue = 0, CREATE TABLE will define the USEEXTENTSET class parameter with a value of 0
- pValue = 1, CREATE TABLE will define the USEEXTENTSET class parameter with a value of 1 (Default)
Notes
DDLUseSequence - Sets the flag which determines if a class created by a DDL CREATE TABLE statement uses $Sequence for ID assignment.
The storage keyword IDFUNCTION can be defined as INCREMENT or SEQUENCE. This keyword value is used by the class compiler to determine
which system function - $increment or $sequence - is to be used for assigning new ID values for a persistent class using default storage.
The default value for IDFUNCTION is INCREMENT, however, the default behavior for classes defined through DDL is to define IDFUNCTION as SEQUENCE.
- pValue = 0, CREATE TABLE uses $Increment for ID assignment
- pValue = 1, CREATE TABLE uses $Sequence for ID assignment (Default)
Notes
DefaultTimePrecision - Set the Default precision for the Time component of the value returned by the GETDATE(), CURRENT_TIME, and CURRENT_TIMESTAMP SQL Scalar functions.
Input precision to pValue, the number of decimal places for the millisecond portion of the time value. The default is 0, milliseconds are not returned in the values returned by the GETDATE(), CURRENT_TIME, and CURRENT_TIMESTAMP functions.
Notes
- You must have the "USE" permission on the %Admin_Manage Resource in order to change this configuration setting.
- Changing this configuration setting will affect all processes immediately.
- This is a system-wide setting.
- pValue = 0, In an SQL statement, "..." is treated as a string literal
- pValue = 1, In an SQL statement, "..." is treated as an identifier (Default)
Notes
ECPSync - Defines whether or not SQL SELECT statements perform a $SYSTEM.ECP.Sync() call in the OPEN code.
- pValue = 0, Do not perform ECP Syncs for Select queries (Default)
- pValue = 1, Perform ECP Syncs for Select queries
Notes
FastDistinct - Defines whether or not SQL DISTINCT is optimized to use indexes.
If true (the default) many SQL queries involving DISTINCT (and GROUP BY) will run much more efficiently by making better use of indices (if available).
The downside of this is that the values returned by such queries will be collated in the same way they are stored within the index (i.e., results may be in uppercase). Some applications care about the case of values returned by such queries. If "Fast DISTINCT" is set to false (0), the
SQL will revert to the use of uncollated values with regards to DISTINCT behavior.
- pValue = 0, DISTINCT optimization is turned OFF
- pValue = 1, DISTINCT optimization is turned ON (Default)
Notes
FilerRefIntegrity - Set the configuration setting which determines if Foreign Key Referential Integrity checks are performed in the SQL Filer. Turning off SQL Filer Referential Integrity checking will suppress any SQLCODE -121, -122, -123, and -124 errors.
- pValue = 0, Foreign Key Referential Integrity checks are not performed
- pValue = 1, Foreign Key Referential Integrity checks are performed (Default)
Notes
IdentityInsert - Set the IDENTITY_INSERT option for this process. IDENTITY_INSERT controls the ability of the user to specify a value for the IDENTITY property when saving a new object,
a value for the IDENTITY column, or an explicit ROWID value in an SQL INSERT. If IDENTITY_INSERT is false and the user specifies an explicit IDENTITY or ROWID value when saving a new object (ObjectScript)
or inserting a new ROW (SQL) then an error condition is reported.
- pValue = 0, Insert/%Save of Identity field/property is not permitted (Default)
- pValue = 1, Insert/%Save of Identity field/property is permitted
Notes
IsolationMode - Set the Transaction Isolation Mode for this process.
The ISOLATION MODE options permit you to specify whether or not uncommitted changes to the database should be available for read access by a SELECT query.
The READ COMMITTED option states that only those changes that have been committed are available for query access. If requested data has been changed,
but the changes have not been committed (or rolled back), the query waits for transaction completion.
If a lock timeout occurs while waiting for this data to be available, an SQLCODE error is issued. READ COMMITTED is the default ISOLATION MODE.
The READ UNCOMMITTED option states that all changes are immediately available for query access.
The READ VERIFIED option states that all changes are immediately available for query access, but with additional checks to skip rows containing
changed data that no longer match the conditions specified in the query.
- pValue = 0, Read uncomitted (Default)
- pValue = 1, Read comitted
- pValue = 3, Read verified
Notes
LockThreshold - Set the Lock Threshold for locks acquired during filing of rows within a single transaction.
- pValue = the number of row locks to acquire before escalating to a table lock. The default is 1000
Notes
LockTimeout - Set the Lock timeout for locks acquired during the execution of SQL statements.
- pValue = the number of seconds to set the lock timeout to. The default is 10 seconds.
Notes
ProcessLockTimeout - Set the Lock Timeout for locks made during the execution of SQL statements for this process.
- pValue = the number of seconds to set the lock timeout to. The default is 10 seconds.
Notes
ParameterSampling - Set the configuration setting which determines if parameter sampling is enabled
- pValue = 0, disable parameter sampling.
- pValue = 1, enable parameter sampling.
Notes
QueryProcedures - Defines whether or not all class queries project as SQL Stored Procedures regardless of the query's SQLProc value.
- pValue = 0, only class queries with SQLProc = TRUE are projected as stored procedures (Default).
- pValue = 1, all class queries are projected as stored procedures.
Notes
RetainSQL - Set the configuration setting which determines if embedded SQL statements are retained as comments in the .INT
code version of the routine.
- pValue = 0, SQL text will be not retained as comments in the .INT code.
- pValue = 1, SQL text will be retained as comments in the INT code (Default).
Notes
RTPC - Set the configuration setting which determines if Run Time Plan Choice is applied.
- pValue = 0, do not apply Run Time Plan Choice in SQL statements.
- pValue = 1, apply Run Time Plan Choice in SQL statements (Default).
Notes
SQLFunctionArgConversion - Set the system wide flag for controlling if SQL Functions perform ODBCToLogical/DisplayToLogical on SQL Function input arguments.
- pValue = 0, SQL will not convert input arguments for SQL Functions from ODBC/Display to Logical format (Default).
- pValue = 1, SQL will convert input arguments for SQL Functions from ODBC/Display to Logical format if needed.
Notes
SQLSecurity - Set the configuration setting which determines if SQL security is enabled.
If SQL security is ON, all SQL security is active. This means privilege-based table/view security is active. A user may only perform actions on a table or view they have been granted privilege for.
If SQL security is OFF, SQL security is inactive. This means privilege-based table/view security is suppressed. A user may perform actions on a table or view even if they have not been granted privileges to do so.
- pValue = 0, SQL security is OFF.
- pValue = 1, SQL security is ON (Default).
Notes
SelectMode - Set the select mode for this process.
The select mode set by this API is used when #SQLCompile Select = Runtime is specified for the compiled SQL code.
When the SQL statement is compiled in Runtime mode, the mode specified by SetSelectMode will be used at runtime to determine whether Logical(0), ODBC(1), or Display(2) mode is used for the statement.
See the documentation for #SQLCompile Select for more information.
- pValue = 0, Logical mode.
- pValue = 1, ODBC mode.
- pValue = 2, Display mode.
Notes
ServerDisconnectCode - Define ODBC/JDBC disconnect code.
Upon disconnect, any ObjectScript code defined in this setting will be executed immediately before the server process Halts. This code will also attempt to be executed anytime the server process
encounters an unrecoverable error that causes the server process to Halt. It will not be executed if the server process encounters a Halt in other user defined code,
if the process crashes, if the process is stopped, or InterSystems IRIS is stopped or forced down.
- pValue = a single line of ObjectScript to be executed. Call with pValue="" or undefined to delete the disconnect code for this namespace
Notes
ServerInitCode - Returns ODBC/JDBC/SQL Manager initialization code.
This Initialization code is executed at login time when connecting to SQL through ODBC, JDBC, or the SQL Manager.
- pValue = a single line of ObjectScript to be executed when connecting to this namespace. Call with pValue="" or undefined to delete connect code for this namespace
Notes
TCPKeepAlive - Set the TCP Keep Alive interval for xDBC connections.
- pValue = the number of seconds to set the TCP Keep Alive interval to. The default is 300 seconds (5 minutes).
Notes
ToDateDefaultFormat - Gets the default format for the SQL TO_DATE() function.
- pValue = a string value with the default format the TO_DATE function will return.
Notes
Parameters:
- limit
- An integer value for the number of xDBC connections to allow for this instance.
Returns:
- A %Status indicating whether the operation was successful
Notes:
- This feature allows a system administrator to limit the number of xDBC connections for this instance.
When set to a value greater than -1, the value will determine how many xDBC connections can be made.
Setting the value to -1 allows as many collections supported by the license.
Connections for users holding the %Admin_Operate:"U" resource are never restricted from connection, but they do count against the limit.
Examples:
- Set status=$SYSTEM.SQL.Util.SetXDBCConnectionLimit(50) // Allow 50 simultaneous xDBC connections to instance
- Set status=$SYSTEM.SQL.Util.SetXDBCConnectionLimit(-1) // No restrictions for simultaneous xDBC connections to instance