Updated on 2023-10-23 GMT+08:00

Platform and Client Compatibility

Many platforms use the database system. External compatibility of the database system provides a lot of convenience for platforms.

convert_string_to_digit

Parameter description: Specifies the implicit conversion priority, which determines whether to preferentially convert strings into numbers.

This parameter is a USERSET parameter. Set it based on instructions provided in Table 1.

Value range: Boolean

  • on indicates that strings are preferentially converted into numbers.
  • off indicates that strings are not preferentially converted into numbers.

Default value: on

Adjusting this parameter will change the internal data type conversion rule and cause unexpected behaviors. Exercise caution when performing this operation.

nls_timestamp_format

Parameter description: Specifies the default timestamp format.

This parameter is a USERSET parameter. Set it based on instructions provided in Table 1.

Value range: a string

Default value: DD-Mon-YYYY HH:MI:SS.FF AM

max_function_args

Parameter description: Specifies the maximum number of parameters allowed for a function.

This parameter is a fixed INTERNAL parameter and cannot be modified.

Value range: an integer

Default value: 8192

transform_null_equals

Parameter description: Specifies whether expressions of the form expr = NULL (or NULL = expr) are treated as expr IS NULL. They return true if expr evaluates to the NULL value, and false otherwise.

  • The correct SQL-standard-compliant behavior of expr = NULL is to always return NULL (unknown).
  • Filtered forms in Microsoft Access generate queries that appear to use expr = NULL to test for null values. If you turn this option on, you can use this interface to access the database.

This parameter is a USERSET parameter. Set it based on instructions provided in Table 2.

Value range: Boolean

  • on indicates that expressions of the form expr = NULL (or NULL = expr) are treated as expr IS NULL.
  • off indicates that expr = NULL always returns NULL (unknown).

Default value: off

New users are always confused about the semantics of expressions involving NULL values. Therefore, off is used as the default value.

support_extended_features

Parameter description: Specifies whether extended database features are supported.

This parameter is a POSTMASTER parameter. Set it based on instructions provided in Table 2.

Value range: Boolean

  • on indicates that extended database features are supported.
  • off indicates that extended database features are not supported.

Default value: off

sql_compatibility

Parameter description: Specifies the type of mainstream database with which the SQL syntax and statement behavior of the database is compatible. This parameter is an INTERNAL parameter. It can be viewed but cannot be modified.

Value range: enumerated type

  • A indicates that the database is compatible with the Oracle database.
  • B indicates that the database is compatible with the MySQL database.
  • C indicates that the database is compatible with the Teradata database.
  • PG indicates that the database is compatible with the PostgreSQL database.

Default value: A

  • This parameter can be set only when you run the CREATE DATABASE command to create a database.
  • In the database, this parameter must be set to a specific value. It can be set to A or B and cannot be changed randomly. Otherwise, the setting is not consistent with the database behavior.

behavior_compat_options

Parameter description: Specifies database compatibility behavior. Multiple items are separated by commas (,).

This parameter is a USERSET parameter. Set it based on instructions provided in Table 1.

Value range: a string

Default value: ""

  • Currently, only compatibility configuration items in Table 1 are supported.
  • Multiple items are separated by commas (,), for example, set behavior_compat_options='end_month_calculate,display_leading_zero';.
Table 1 Compatibility configuration items

Configuration Item

Behavior

display_leading_zero

Specifies how floating point numbers are displayed.

  • If this item is not specified, for a decimal number between –1 and 1, the 0 before the decimal point is not displayed. For example, 0.25 is displayed as .25.
  • If this item is specified, for a decimal number between –1 and 1, the 0 before the decimal point is displayed. For example, 0.25 is displayed as 0.25.

end_month_calculate

Specifies the calculation logic of the add_months function.

Assume that the two parameters of the add_months function are param1 and param2, and that the month of param1 and param2 is result.

  • If this item is not specified, and the Day of param1 indicates the last day of a month shorter than result, the Day in the calculation result will equal that in param1. For example:
1
2
3
4
5
openGauss=# select add_months('2018-02-28',3) from sys_dummy;
add_months
---------------------
2018-05-28 00:00:00
(1 row)
  • If this item is specified, and the Day of param1 indicates the last day of a month shorter than result, the Day in the calculation result will equal that in result. For example:
1
2
3
4
5
openGauss=# select add_months('2018-02-28',3) from sys_dummy;
add_months
---------------------
2018-05-31 00:00:00
(1 row)

compat_analyze_sample

Specifies the sampling behavior of the ANALYZE operation.

If this item is specified, the sample collected by the ANALYZE operation will be limited to around 30,000 records, controlling database node memory consumption and maintaining the stability of ANALYZE.

bind_schema_tablespace

Binds a schema with the tablespace with the same name.

If a tablespace name is the same as sche_name, default_tablespace will also be set to sche_name if search_path is set to sche_name.

bind_procedure_searchpath

Specifies the search path of the database object for which no schema name is specified.

If no schema name is specified for a stored procedure, the search is performed in the schema to which the stored procedure belongs.

If the stored procedure is not found, the following operations are performed:

  • If this item is not specified, the system reports an error and exits.
  • If this item is specified, the search continues based on the settings of search_path. If the issue persists, the system reports an error and exits.

correct_to_number

Specifies the compatibility of the to_number() result.

If this item is specified, the result of the to_number() function is the same as that of PG11. Otherwise, the result is the same as that of the O database.

unbind_divide_bound

Specifies the range check on the result of integer division.

If this item is specified, you do not need to check the range of the division result. For example, the result of INT_MIN/(-1) can be INT_MAX+1. If this item is not specified, an out-of-bounds error is reported because the result is greater than INT_MAX.

convert_string_digit_to_numeric

Determines whether to convert columns of the character string type to those of the numeric type before columns of these two types are compared.

return_null_string

Specifies how to display the empty result (empty string '') of the lpad() and rpad() functions.

  • If this item is not specified, the empty string is displayed as NULL.
1
2
3
4
5
openGauss=# select length(lpad('123',0,'*')) from sys_dummy;
length
--------

(1 row)
  • If this item is specified, the empty string is displayed as single quotation marks ('').
1
2
3
4
5
openGauss=# select length(lpad('123',0,'*')) from sys_dummy;
length
--------
0
(1 row)

compat_concat_variadic

Specifies the compatibility of variadic results of the concat() and concat_ws() functions.

If this item is specified and a concat function has a parameter of the variadic type, different result formats in A database and Teradata are retained. If this item is not specified and a concat function has a parameter of the variadic type, same result formats in A database and Teradata are retained, and the results are the same as those in A database. This option has no effect on MY because MY has no variadic type.

merge_update_multi

When MERGE INTO... WHEN MATCHED THEN UPDATE (see MERGE INTO) and INSERT... ON DUPLICATE KEY UPDATE (see INSERT) are used, control the UPDATE behavior if a piece of target data in the target table conflicts with multiple pieces of source data.

If this item is specified and the preceding scenario exists, the system performs multiple UPDATE operations on the conflicting row. If this item is not specified and the preceding scenario exists, an error is reported, that is, the MERGE or INSERT operation fails.

plstmt_implicit_savepoint

Determines whether the execution of an UPDATE statement in a stored procedure has an independent subtransaction.

If this parameter is set, the implicit savepoint is enabled before executing each UPDATE statement in the stored procedure, and the subtransaction is rolled backed to the latest savepoint in the EXCEPTION block by default, ensuring that only the modification of failed statements is rolled back. This option is used to be compatible with the EXCEPTION behavior of the O database.

hide_tailing_zero

Configuration item for numeric display. If this parameter is not set, numeric data is displayed in the specified precision. If this parameter is set, the trailing zero after the decimal point is hidden in all scenarios where numeric values are output, even the precision format is specified.

set behavior_compat_options='hide_tailing_zero';
select cast(123.123 as numeric(15,10));
numeric
---------
123.123
(1 row)

rownum_type_compat

Specifies the ROWNUM type. The default value is BIGINT. After this parameter is specified, the value is changed to NUMERIC.

aformat_null_test

Specifies the logic for checking whether rowtype is not null.

When this parameter is set, if one column in a row is not empty, true is returned for checking whether rowtype is not null. When this parameter is not set, if all columns in a row are not empty, true is returned for checking whether rowtype is not null. This parameter has no influence on checking whether rowtype is not null.

aformat_regexp_match

Determines the matching behavior of regular expression functions.

When this parameter is set and sql_compatibility is set to A or B, the options supported by the flags parameter of the regular expression are changed as follows:
  1. . By default, the character '\n' cannot be matched.
  2. When flags contains the n option, the character '\n' can be matched.
  3. The regexp_replace(source, pattern replacement) function replaces all matching substrings.
  4. regexp_replace(source, pattern, replacement, flags) returns null when the value of flags is '' or null.

Otherwise, the meanings of the options supported by the flags parameter of the regular expression are as follows:

  1. . By default, the character '\n' can be matched.
  2. The n option in flags indicates that the multi-line matching mode is used.
  3. The regexp_replace(source, pattern replacement) function replaces only the first matched substring.
  4. If the value of flags is '' or null, the return value of regexp_replace(source, pattern, replacement, flags) is the character string after replacement.

compat_cursor

Determines the compatibility behavior of implicit cursor states. If this parameter is set and the O compatibility mode is used, the effective scope of implicit cursor states (SQL%FOUND, SQL%NOTFOUND, SQL%ISOPNE, and SQL%ROWCOUNT) are extended from only the currently executed function to all subfunctions invoked by this function.

proc_outparam_override

Determines the overloading of output parameters of a stored procedure. After this parameter is enabled, the stored procedure can be properly created and invoked even if only the output parameters of the stored procedure are different. Currently, this parameter can be used only when gsql and JDBC are used to connect to the database. If this parameter is enabled for other tools to connect to the database, stored procedures with the output parameters cannot be invoked.

proc_implicit_for_loop_variable

Determines the behavior of the FOR_LOOP query statement in a stored procedure. When this parameter is set, if rec has been defined in the FOR rec IN query LOOP statement, the defined rec variable is not reused and a new variable is created. Otherwise, the defined rec variable is reused and no new variable is created.

allow_procedure_compile_check

Determines the compilation check of the SELECT and OPEN CURSOR statements in a stored procedure. If this parameter is set, when the SELECT, OPEN CURSOR FOR, CURSOR%rowtype, or for rec in statement is executed in a stored procedure, the stored procedure cannot be created if the queried table does not exist, and the compilation check of the trigger function is not supported. If the queried table exists, the stored procedure is successfully created.

Note: When creating a function in the encrypted state, you need to disable allow_procedure_compile_check.

char_coerce_compat

Determines the behavior when char(n) types are converted to other variable-length string types. By default, spaces at the end are omitted when the char(n) type is converted to other variable-length string types. After this parameter is enabled, spaces at the end are not omitted during conversion. In addition, if the length of the char(n) type exceeds the length of other variable-length string types, an error is reported. This parameter is valid only when the sql_compatibility parameter is set to A. After this parameter is enabled, spaces at the end are not omitted in implicit conversion, explicit conversion, or conversion by calling the text(bpchar) function.

truncate_numeric_tail_zero

Configuration item for numeric display. If this parameter is not set, numeric data is displayed in the default precision. When this parameter is set, the trailing zeros after the decimal point is hidden in all numeric output scenarios except to_char(numeric, format).

plsql_security_definer

After this parameter is enabled, the definer permission is used by default when a stored procedure is created.

array_count_compat

Controls the array.count function. If the parameter is enabled, the function returns 0. Otherwise, the function returns NULL.

disable_emptystr2null

Disables the function of converting an empty string to null by default for the text, clob, blob, and raw character string types.

plsql_compile_check_options

Parameter description: Specifies database compatibility behavior. Multiple items are separated by commas (,).

This parameter is a USERSET parameter. Set it based on instructions provided in Table 1.

Value range: a string

Default value: ""

  • Currently, only compatibility configuration items in Table 1 are supported.
  • Multiple items are separated by commas (,), for example, set plsql_compile_check_options='for_loop,outparam';.
Table 2 Compatibility configuration items

Configuration Item

Behavior

for_loop

Determines the behavior of the FOR_LOOP query statement in a stored procedure. When this parameter is set, if rec has been defined in the FOR rec IN query LOOP statement, the defined rec variable is not reused and a new variable is created. Otherwise, the defined rec variable is reused and no new variable is created. (It is the same as proc_implicit_for_loop_variable and will be incorporated later.)

outparam

When the output parameter overloading condition is met, the output parameters are checked. If the output parameters are constant, an error is reported.

a_format_version

Parameter description: Specifies the database platform compatibility configuration item. The value of this parameter is an enumerated string.

This parameter is a USERSET parameter. Set it based on instructions provided in Table 1.

Value range: a string

Default value: ""

  • Currently, only compatibility configuration items in Table 1 are supported.
  • Set a character string for the compatibility configuration item, for example, set a_format_version='10c'.
Table 3 Compatibility configuration items

Configuration Item

Compatibility Behavior Control

10c

Compatible version of platform A

a_format_dev_version

Parameter description: Specifies the database platform minor version compatibility configuration item. The value of this parameter is an enumerated string.

This parameter is a USERSET parameter. Set it based on instructions provided in Table 1.

Value range: a string

Default value: ""

  • Currently, only compatibility configuration items in Table 1 are supported.
  • Set a character string for the compatibility configuration item, for example, set a_format_dev_version='s1'.
Table 4 Compatibility configuration items

Configuration Item

Compatibility Behavior Control

s1

Compatible minor version of platform A, which affects functions: (

TRUNC(date, fmt),ROUND(date, fmt),NVL2,LPAD,RPAD,ADD_MONTHS,MONTHS_BETWEEN,REGEXP_REPLACE

,REGEXP_COUNT,TREAT,EMPTY_CLOB,INSTRB

)

After this parameter is enabled, the int casted from text can be rounded off.

plpgsql.variable_conflict

Parameter description: Sets the priority of using stored procedure variables and table columns with the same name.

This parameter is a USERSET parameter. Set it based on instructions provided in Table 2.

Value range: a string

  • error indicates that a compilation error is reported when the name of a stored procedure variable is the same as that of a table column.
  • use_variable indicates that if the name of a stored procedure variable is the same as that of a table column, the variable is used preferentially.
  • use_column indicates that if the name of a stored procedure variable is the same as that of a table column, the column name is used preferentially.

Default value: error

td_compatible_truncation

Parameter description: Specifies whether to enable features compatible with a Teradata database. You can set this parameter to on when connecting to a database compatible with the Teradata database, so that when you perform the INSERT operation, overlong strings are truncated based on the allowed maximum length before being inserted into char- and varchar-type columns in the target table. This ensures all data is inserted into the target table without errors reported.

The string truncation function cannot be used if the INSERT statement includes a foreign table.

If inserting multi-byte character data (such as Chinese characters) to database with the character set byte encoding (such as SQL_ASCII or LATIN1), and the character data crosses the truncation position, the string is truncated based on its bytes instead of characters. Unexpected result will occur in tail after the truncation. If you want correct truncation result, you are advised to adopt encoding set such as UTF8, which has no character data crossing the truncation position.

This parameter is a USERSET parameter. Set it based on instructions provided in Table 2.

Value range: Boolean

  • on indicates that overlong strings are truncated.
  • off indicates that overlong strings are not truncated.

Default value: off

uppercase_attribute_name

Parameter description: Specifies whether to return column names in uppercase to the client. This parameter is used only in the ORA-compatible mode and centralized environment.

This parameter is a USERSET parameter. Set it based on instructions provided in Table 2.

Value range: Boolean

  • on indicates that column names are returned to the client in uppercase.
  • off indicates that column names are not returned to the client in uppercase.

Default value: off

lastval_supported

Parameter description: Specifies whether the lastval function can be used.

This parameter is a POSTMASTER parameter. Set it based on instructions provided in Table 1.

Value range: Boolean

  • on indicates that the lastval function can be used and the nextval function cannot be pushed down.
  • off indicates that the lastval function cannot be used and the nextval function can be pushed down.

Default value: off