You can set system variables to ensure that the behaviors of OceanBase Database meet the service requirements. This topic describes how to modify system variables of a tenant.
You can use the SET statement to modify system variables of a tenant.
A session-level variable takes effect only on the current session.
A global variable does not take effect on the current session and takes effect only on sessions established upon re-login.
Notice
To set global variables for a MySQL tenant, you must have the
SUPERorALTER SYSTEMprivilege. To set global variables for an Oracle tenant, you must have theALTER SYSTEMprivilege. Make sure that you have the required privileges before you set global variables. For more information about user privileges, see Overview.
The system variable ob_query_timeout is used as an example in the following sections. This system variable specifies the timeout period for SQL queries, in microseconds. When you run a big data query, you can increase the value of the system variable ob_query_timeout to avoid an execution failure caused by query timeout.
Modify a session-level system variable
Log in to a user tenant of a cluster as an administrator or regular user.
For example, to log in to the
mq_t1tenant, run the following command:obclient -h172.30.xx.xx -P2883 -uroot@mq_t1#cluster -p**** -AQuery a session-level system variable of the tenant.
obclient [(none)]> SHOW VARIABLES LIKE 'ob_query_timeout';The query result is as follows:
+------------------+----------+ | Variable_name | Value | +------------------+----------+ | ob_query_timeout | 10000000 | +------------------+----------+ 1 row in setExecute the
SETstatement to modify the value of a session-level system variable.MySQL modeOracle modeIn MySQL mode, you can modify the value of a session-level system variable in the following ways:
obclient [oceanbase]> SET ob_query_timeout = 20000000;or
obclient [oceanbase]> SET ob_query_timeout := 20000000;In Oracle mode, you can modify the value of a session-level system variable in the following ways:
obclient [SYS]> SET ob_query_timeout = 20000000;or
obclient [SYS]> ALTER SESSION SET ob_query_timeout = 20000000;Query the modification result.
obclient [(none)]> SHOW VARIABLES WHERE variable_name LIKE 'ob_query_timeout';The query result is as follows:
+------------------+----------+ | Variable_name | Value | +------------------+----------+ | ob_query_timeout | 20000000 | +------------------+----------+ 1 row in set
Modify a global system variable
Log in to a user tenant of the cluster as an administrator.
Note
In MySQL mode, the default administrator is the
rootuser. In Oracle mode, the default administrator is theSYSuser.For example, to log in to the
mq_t1tenant, run the following command:obclient -h172.30.xx.xx -P2883 -uroot@mq_t1#cluster -p**** -AQuery a global variable of the tenant.
obclient [(none)]> SHOW GLOBAL VARIABLES WHERE variable_name LIKE 'ob_query_timeout';The query result is as follows:
+------------------+----------+ | Variable_name | Value | +------------------+----------+ | ob_query_timeout | 10000000 | +------------------+----------+ 1 row in setExecute the
SETstatement to modify the value of a global variable.MySQL modeOracle modeIn MySQL mode, you can modify the value of a global system variable in the following ways:
obclient [oceanbase]> SET GLOBAL ob_query_timeout = 20000000;or
obclient [oceanbase]> SET GLOBAL ob_query_timeout := 20000000;In Oracle mode, you can modify the value of a global system variable in the following ways:
obclient [SYS]> SET GLOBAL ob_query_timeout = 20000000;or
obclient [SYS]> ALTER SYSTEM SET ob_query_timeout = 20000000;Query the modification result.
obclient [(none)]> SHOW GLOBAL VARIABLES WHERE variable_name LIKE 'ob_query_timeout'; +------------------+----------+ | Variable_name | Value | +------------------+----------+ | ob_query_timeout | 20000000 | +------------------+----------+ 1 row in setAfter the modification, you can execute the following statement to query the
DBA_OB_SYS_VARIABLESview for the modification status and default value of theob_query_timeoutvariable:obclient [oceanbase]> SELECT * FROM oceanbase.DBA_OB_SYS_VARIABLES WHERE NAME='ob_query_timeout';The query result is as follows:
+----------------------------+----------------------------+------------------+----------+-----------+-----------+------------------+----------------------------------+---------------+-----------+ | CREATE_TIME | MODIFY_TIME | NAME | VALUE | MIN_VALUE | MAX_VALUE | SCOPE | INFO | DEFAULT_VALUE | ISDEFAULT | +----------------------------+----------------------------+------------------+----------+-----------+-----------+------------------+----------------------------------+---------------+-----------+ | 2023-12-08 14:00:20.583506 | 2023-12-12 11:51:46.237099 | ob_query_timeout | 20000000 | | | GLOBAL | SESSION | Query timeout in microsecond(us) | 10000000 | NO | +----------------------------+----------------------------+------------------+----------+-----------+-----------+------------------+----------------------------------+---------------+-----------+ 1 row in set
Modify a Boolean variable
For a variable whose value is ON or OFF in the output of the SHOW VARIABLES statement, you can set its value in the following ways:
SET foreign_key_checks = ON;
SET foreign_key_checks = TRUE;
SET foreign_key_checks = 1;
SET GLOBAL foreign_key_checks = OFF;
SET GLOBAL foreign_key_checks = FALSE;
SET GLOBAL foreign_key_checks = 0;
Note
ON/OFF, TRUE/FALSE, and 1/0 are equivalent for Boolean variables.
References
For more information about system variables, see the following topics: