Documentation Home
MySQL 5.5 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 26.9Mb
PDF (A4) - 26.9Mb
PDF (RPM) - 25.3Mb
HTML Download (TGZ) - 6.3Mb
HTML Download (Zip) - 6.3Mb
HTML Download (RPM) - 5.3Mb
Man Pages (TGZ) - 157.6Kb
Man Pages (Zip) - 260.9Kb
Info (Gzip) - 2.6Mb
Info (Zip) - 2.6Mb
Excerpts from this Manual

MySQL 5.5 Reference Manual  /  ...  /  SET Syntax for Variable Assignment

13.7.4.1 SET Syntax for Variable Assignment

SET variable = expr [, variable = expr] ...

variable: {
    user_var_name
  | param_name
  | local_var_name
  | {GLOBAL | @@global.} system_var_name
  | [SESSION | @@session. | @@] system_var_name
}

SET ONE_SHOT system_var_name = expr

SET syntax for variable assignment enables you to assign values to different types of variables that affect the operation of the server or clients:

Older versions of MySQL employed SET OPTION, but this syntax is deprecated in favor of SET without OPTION.

A SET statement that assigns variable values is not written to the binary log, so in replication scenarios it affects only the host on which you execute it. To affect all replication hosts, execute the statement on each host.

The following sections describe SET syntax for setting variables. They use the = assignment operator, but the := assignment operator is also permitted for this purpose.

User-Defined Variable Assignment

User-defined variables are created locally within a session and exist only within the context of that session; see Section 9.4, “User-Defined Variables”.

A user-defined variable is written as @var_name and is assigned an expression value as follows:

SET @var_name = expr;

Examples:

SET @name = 43;
SET @total_tax = (SELECT SUM(tax) FROM taxable_transactions);

As demonstrated by those statements, expr can range from simple (a literal value) to more complex (the value returned by a scalar subquery).

Parameter and Local Variable Assignment

SET applies to parameters and local variables in the context of the stored object within which they are defined. The following procedure uses the increment procedure parameter and counter local variable:

CREATE PROCEDURE p(increment INT)
BEGIN
  DECLARE counter INT DEFAULT 0;
  WHILE counter < 10 DO
    -- ... do work ...
    SET counter = counter + increment;
  END WHILE;
END;
System Variable Assignment

The MySQL server maintains system variables that configure its operation. A system variable can have a global value that affects server operation as a whole, a session value that affects the current session, or both. Many system variables are dynamic and can be changed at runtime using the SET statement to affect operation of the current server instance. (To make a global system variable setting permanent so that it applies across server restarts, you should also set it in an option file.)

If you change a session system variable, the value remains in effect within your session until you change the variable to a different value or the session ends. The change has no effect on other sessions.

If you change a global system variable, the value is remembered and used to initialize the session value for new sessions until you change the variable to a different value or the server exits. The change is visible to any client that accesses the global value. However, the change affects the corresponding session value only for clients that connect after the change. The global variable change does not affect the session value for any current client sessions (not even the session within which the global value change occurs).

Note

Setting a global system variable value always requires special privileges. Setting a session system variable value normally requires no special privileges and can be done by any user, although there are exceptions. For more information, see Section 5.1.8.1, “System Variable Privileges”.

The following discussion describes the syntax options for setting system variables:

  • To assign a value to a global system variable, precede the variable name by the GLOBAL keyword or the @@global. qualifier:

    SET GLOBAL max_connections = 1000;
    SET @@global.max_connections = 1000;
  • To assign a value to a session system variable, precede the variable name by the SESSION or LOCAL keyword, or by the @@session., @@local., or @@ qualifier:

    SET SESSION sql_mode = 'TRADITIONAL';
    SET LOCAL sql_mode = 'TRADITIONAL';
    SET @@session.sql_mode = 'TRADITIONAL';
    SET @@local.sql_mode = 'TRADITIONAL';
    SET @@sql_mode = 'TRADITIONAL';

    If no keyword or modifier is present, SET changes the session variable.

    SET sql_mode = 'TRADITIONAL';

    A client can change its own session variables, but not those of any other client.

To set a global system variable value to the compiled-in MySQL default value or a session system variable to the current corresponding global value, set the variable to the value DEFAULT. For example, the following two statements are identical in setting the session value of max_join_size to the current global value:

SET @@session.max_join_size = DEFAULT;
SET @@session.max_join_size = @@global.max_join_size;

To display system variable names and values:

SET Error Handling

If any variable assignment in a SET statement fails, the entire statement fails and no variables are changed.

SET produces an error under the circumstances described here. Most of the examples show SET statements that use keyword syntax (for example, GLOBAL or SESSION), but the principles are also true for statements that use the corresponding modifiers (for example, @@global. or @@session.).

  • Use of SET (any variant) to set a read-only variable:

    mysql> SET GLOBAL version = 'abc';
    ERROR 1238 (HY000): Variable 'version' is a read only variable
  • Use of GLOBAL to set a variable that has only a session value:

    mysql> SET GLOBAL sql_log_bin = ON;
    ERROR 1231 (42000): Variable 'sql_log_bin' can't be
    set to the value of 'ON'
  • Use of SESSION to set a variable that has only a global value:

    mysql> SET SESSION max_connections = 1000;
    ERROR 1229 (HY000): Variable 'max_connections' is a
    GLOBAL variable and should be set with SET GLOBAL
  • Omission of GLOBAL to set a variable that has only a global value:

    mysql> SET max_connections = 1000;
    ERROR 1229 (HY000): Variable 'max_connections' is a
    GLOBAL variable and should be set with SET GLOBAL
  • The @@global., @@session., and @@ modifiers apply only to system variables. An error occurs for attempts to apply them to user-defined variables, stored procedure or function parameters, or stored program local variables.

  • Not all system variables can be set to DEFAULT. In such cases, assigning DEFAULT results in an error.

  • It is not permitted to assign DEFAULT to user-defined variables, and not supported for stored procedure or function parameters or stored program local variables. This results in an error for user-defined variables, and the results are undefined for parameters or local variables.

Multiple Variable Assignment

A SET statement can contain multiple variable assignments, separated by commas. This statement assigns a value to a user-defined variable and a system variable:

SET @x = 1, SESSION sql_mode = '';

If you set multiple system variables in a single statement, the most recent GLOBAL or SESSION keyword in the statement is used for following assignments that have no keyword specified.

Examples of multiple-variable assignment:

SET GLOBAL sort_buffer_size = 1000000, SESSION sort_buffer_size = 1000000;
SET @@global.sort_buffer_size = 1000000, @@local.sort_buffer_size = 1000000;
SET GLOBAL max_connections = 1000, sort_buffer_size = 1000000;

The @@global., @@session., and @@ modifiers apply only to the immediately following system variable, not any remaining system variables. This statement sets the sort_buffer_size global value to 50000 and the session value to 1000000:

SET @@global.sort_buffer_size = 50000, sort_buffer_size = 1000000;
System Variable References in Expressions

To refer to the value of a system variable in expressions, use one of the @@-modifiers. For example, you can retrieve system variable values in a SELECT statement like this:

SELECT @@global.sql_mode, @@session.sql_mode, @@sql_mode;

A reference to a system variable in an expression as @@var_name (with @@ rather than @@global. or @@session.) returns the session value if it exists and the global value otherwise. This differs from SET @@var_name = expr, which always refers to the session value.

ONE_SHOT Assignment

The SET ONE_SHOT syntax is only for internal use for replication: mysqlbinlog uses SET ONE_SHOT to modify temporarily the values of character set, collation, and time zone variables to reflect at rollforward what they were originally. ONE_SHOT is for internal use only and is deprecated.

ONE_SHOT is intended for use only with the permitted set of variables. It changes the variables as requested, but only for the next non-SET statement. After that, the server resets all character set, collation, and time zone-related system variables to their previous values. Example:

mysql> SET ONE_SHOT character_set_connection = latin5;

mysql> SET ONE_SHOT collation_connection = latin5_turkish_ci;

mysql> SHOW VARIABLES LIKE '%_connection';
+--------------------------+-------------------+
| Variable_name            | Value             |
+--------------------------+-------------------+
| character_set_connection | latin5            |
| collation_connection     | latin5_turkish_ci |
+--------------------------+-------------------+

mysql> SHOW VARIABLES LIKE '%_connection';
+--------------------------+-------------------+
| Variable_name            | Value             |
+--------------------------+-------------------+
| character_set_connection | latin1            |
| collation_connection     | latin1_swedish_ci |
+--------------------------+-------------------+

User Comments
User comments in this section are, as the name implies, provided by MySQL users. The MySQL documentation team is not responsible for, nor do they endorse, any of the information provided here.
Sign Up Login You must be logged in to post a comment.