Updated on 2024-06-03 GMT+08:00

GUC Parameter Usage

A database provides many GUC parameters. Changing these parameters will affect the behavior of the database system. Before modifying these parameters, learn the impact of these parameters on the database. Otherwise, unexpected results may occur.

Precautions

  • If the value range of a parameter is a string, the string should comply with the path and file naming conventions of the OS running the target database.
  • If the maximum value of a parameter is INT_MAX, the maximum parameter value varies by OS. INT_MAX indicates the maximum value of the INT data type. The value is 2147483647.
  • If the maximum value of a parameter is DBL_MAX (maximum value of the FLOAT data type), the maximum parameter value varies by OS.
  • Some GUC parameters affect the selection of functions and operators, compilation of stored procedures, and generation of execution plans. As a result, views, default values of function parameters, compilation products of stored procedures, and plan cache are affected. Due to these mechanisms, subsequent GUC parameter changes may not affect these behaviors.
    • View: When defining a view, the database generates rewriting rules based on the GUC parameter status. Subsequent operations on the view directly follow the corresponding rules without being affected by GUC parameters (which affect the generation of rewriting rules).
    • Default value of a function parameter: For a function parameter, a function is selected as the default parameter value based on the GUC parameter status when the function parameter is created and the OID of the function that is used as the default value is recorded in the corresponding system catalog (pg_proc). When this function parameter is executed later, the function OID recorded in the system catalog will be used as the default value, and the value is not affected by GUC parameters.
    • Compilation product of a stored procedure: When compiling a stored procedure, the database generates a compilation product based on the GUC parameter status. When executing the stored procedure, the database directly uses the compilation product without being affected by GUC parameters (which affect the generation of compilation products).
    • Plan cache: When executing an SQL statement, the database generates an execution plan based on the GUC parameter status. If the plan is cached, the SQL statement will be executed according to the plan without being affected by GUC parameters (which affect the generation of execution plans).

    The following table lists the GUC parameters that exert influence. You can view the function of each GUC parameter.

    GUC Parameter

    Enabled

    Disabled

    Impact

    Example

    convert_string_to_digit

    Character strings are preferentially converted to numbers.

    Character strings cannot be preferentially converted to numbers.

    Views, default values of function parameters, stored procedure compilation products, and plan cache.

    CREATE or REPLACE FUNCTION test(c numeric) RETURN text package
    AS
    BEGIN
    RETURN 'test(c numeric)';
    END;
    /
    CREATE or REPLACE FUNCTION test(c varchar2) RETURN text package
    AS
    BEGIN
    RETURN 'test(c varchar2)';
    END;
    /
    
    SET convert_string_to_digit=on;
    CREATE or REPLACE VIEW test_view AS SELECT test('123'::text);
    
    SELECT test('123'::text);
    test
    -----------------
    test(c numeric)
    (1 row)
    
    SELECT * FROM test_view;
    test
    -----------------
    test(c numeric)
    (1 row)
    
    -- Disable the parameter.
    SET convert_string_to_digit=off;
    
    SELECT test('123'::text);
    test
    ------------------
    test(c varchar2)
    (1 row)
    
    -- The view behavior is inconsistent with the direct function calling behavior.
    SELECT * FROM test_view;
    test
    -----------------
    test(c numeric)
    (1 row))

    set behavior_compat_options = 'current_sysdate';

    The SYSDATE function obtains the current OS time. (The current_sysdate function is used at the bottom layer.)

    The SYSDATE function obtains the current database time. (The sysdate function is used at the bottom layer.)

    Views, default values of function parameters, stored procedure compilation products, and plan cache.

    SET behavior_compat_options = 'current_sysdate';
    CREATE or REPLACE VIEW test_view_SYSDATE AS SELECT SYSDATE AS test;
    SELECT * FROM test_view_SYSDATE;-- Returns the current OS time.
    SELECT SYSDATE;--Returns the current OS time.
    -- Disable the parameter.
    SET behavior_compat_options = '';
    -- The view behavior is inconsistent with the direct function calling behavior.
    SELECT * FROM test_view_SYSDATE;-- Returns the current OS time.
    SELECT SYSDATE;--Returns the current database time.

    set a_format_version='10c';

    set a_format_dev_version='s1';

    • NVL2 is supported.
    • Some system functions are added. For details, see the disabled system functions supported by the a_format_disable_func parameter.
    • The CASE WHEN return type is changed.
    • Constructors of the set type are prior to functions.
    • Implicit conversion from timestamp to timestamptz is supported.

    The functions supported when the parameter is enabled are not supported.

    Views, default values of function parameters, stored procedure compilation products, and plan cache.

    SET a_format_version='10c';
    SET a_format_dev_version='s1';
    
    CREATE OR REPLACE VIEW test_view_nvl2 AS SELECT nvl2(1,2,3) AS test;
    SELECT * FROM test_view_nvl2;
    test
    ------
    2
    (1 row)
    
    RESET a_format_dev_version;
    
    SELECT * FROM test_view_nvl2;
    test
    ------
    2
    (1 row)

    set a_format_version='10c';

    set a_format_dev_version='s2';

    • CURRENT_TIMESTAMP '(' FCONST ')' is supported.
    • DBTIMEZONE is supported.
    • LNNVL is supported.
    • CURRENT_DATE (when a_format_date_timestamp is set to off): returns the date and time (timestamp).
    • Some system functions are added. For details, see the disabled system functions supported by the a_format_disable_func parameter.

    The functions supported when the parameter is enabled are not supported.

    Views, default values of function parameters, stored procedure compilation products, and plan cache.

    SET a_format_version='10c';
    SET a_format_dev_version='s2';
    
    CREATE or REPLACE VIEW test_view_LNNVL AS SELECT LNNVL(123=123) AS test;
    SELECT * FROM test_view_LNNVL;
    
    RESET a_format_dev_version;
    
    SELECT * FROM test_view_LNNVL;

    set a_format_version='10c';

    set a_format_dev_version='s4';

    Some system functions are added. For details, see the disabled system functions supported by the a_format_disable_func parameter.

    The functions supported when the parameter is enabled are not supported.

    Views, default values of function parameters, stored procedure compilation products, and plan cache.

    -

    set a_format_version='10c';

    set a_format_dev_version='s5';

    • Some system functions are added. For details, see the disabled system functions supported by the a_format_disable_func parameter.
    • Composite constructors are prior to functions.

    The functions supported when the parameter is enabled are not supported.

    Views, default values of function parameters, stored procedure compilation products, and plan cache.

    --The composite type constructor is prior to functions.
    CREATE TYPE tt AS  (
    val1 int,
    val2 int
    );
    CREATE OR REPLACE FUNCTION tt(va int, vb int)
    RETURN int IS
    ret int;
    BEGIN
    ret := va;
    RETURN ret;
    END;
    /
    
    SET a_format_version='10c';
    SET a_format_dev_version='s5';
    
    -- Assign a value to the tt variable.
    CREATE OR REPLACE FUNCTION test0
    RETURN int IS
    va  tt;
    ret int;
    BEGIN
    va := tt(1,2);
    RAISE INFO 'tt: %' ,va;
    ret := 9;
    RETURN ret;
    END;
    /
    
    SELECT test0();
    INFO:  tt: (1,2)
    test0
    -------
    9
    (1 row)
    
    SET a_format_version='';
    SET a_format_dev_version='';
    
    SELECT test0();
    INFO:  tt: (1,2)
    test0
    -------
    9
    (1 row)
    
    -- Assign a value to the tt variable.
    CREATE OR REPLACE FUNCTION test0
    RETURN int IS
    va  tt;
    ret int;
    BEGIN
    va := tt(1,2);
    RAISE INFO 'tt: %' ,va;
    ret := 9;
    RETURN ret;
    END;
    /
    
    select test0();
    ERROR:  cannot assign non-composite value to a row variable

    set behavior_compat_options = 'enable_bpcharlikebpchar_compare';

    The bpcharlikebpchar and bpcharnlikebpchar operators are enabled.

    The bpcharlikebpchar and bpcharnlikebpchar operators are disabled.

    Views, stored procedure compilation products, and plan cache

    CREATE TABLE op_test (
    col BPCHAR(2) DEFAULT NULL
    );
    CREATE INDEX op_index ON op_test(col);
    
    INSERT INTO op_test VALUES ('a');
    INSERT INTO op_test VALUES ('1');
    INSERT INTO op_test VALUES ('11');
    INSERT INTO op_test VALUES ('12');
    INSERT INTO op_test VALUES ('sd');
    INSERT INTO op_test VALUES ('aa');
    
    SET behavior_compat_options = 'enable_bpcharlikebpchar_compare';
    
    EXPLAIN (COSTS OFF) SELECT * FROM op_test WHERE col LIKE col::BPCHAR ORDER BY col;
    QUERY PLAN
    ------------------------------
    Sort
    Sort Key: col
    ->  Seq Scan on op_test
    Filter: (col ~~ col)
    (4 rows)
    
    CREATE OR REPLACE VIEW test_view_bpchar AS SELECT * FROM op_test WHERE col LIKE col::BPCHAR ORDER BY col;
    
    EXPLAIN SELECT * FROM test_view_bpchar;
    QUERY PLAN
    ----------------------------------------------------------------
    Sort  (cost=34.48..34.50 rows=10 width=12)
    Sort Key: op_test.col
    ->  Seq Scan on op_test  (cost=0.00..34.31 rows=10 width=12)
    Filter: (col OPERATOR(pg_catalog.~~) col)
    (4 rows)
    
    SET behavior_compat_options = '';
    
    EXPLAIN (COSTS OFF) SELECT * FROM op_test WHERE col LIKE col::BPCHAR ORDER BY col;
    QUERY PLAN
    --------------------------------------
    Sort
    Sort Key: col
    ->  Seq Scan on op_test
    Filter: (col ~~ (col)::text)
    (4 rows)
    
    EXPLAIN SELECT * FROM test_view_bpchar;
    QUERY PLAN
    ----------------------------------------------------------------
    Sort  (cost=34.48..34.50 rows=10 width=12)
    Sort Key: op_test.col
    ->  Seq Scan on op_test  (cost=0.00..34.31 rows=10 width=12)
    Filter: (col OPERATOR(pg_catalog.~~) col)
    (4 rows)
    
    -- Rebuild a view when the parameter is disabled.
    CREATE OR REPLACE VIEW test_view_bpchar AS SELECT * FROM op_test WHERE col LIKE col::BPCHAR ORDER BY col;
    
    explain select * from test_view_bpchar;
    QUERY PLAN
    ----------------------------------------------------------------
    Sort  (cost=39.34..39.37 rows=10 width=12)
    Sort Key: op_test.col
    ->  Seq Scan on op_test  (cost=0.00..39.17 rows=10 width=12)
    Filter: (col ~~ (col)::text)
    (4 rows)

    set b_format_version='5.7';

    set b_format_dev_version='s1';

    • CURDATE, CURRENT_TIME, CURRENT_TIMESTAMP, LOCALTIME, and LOCALTIMESTAMP NOW return the statement execution time.
    • SYSDATE returns the function execution time.

    The functions return the transaction start time.

    Views, default values of function parameters, stored procedure compilation products, and plan cache.

    -

    set b_format_version='5.7';

    set b_format_dev_version='s1';

    The behaviors of the DB_JSOBJ, LAST_DAY_FUNC, EXTRACT, TIMESTAMPDIFF, and SUBSTRING functions are changed to be the same as those of MySQL.

    Restores the default behavior.

    Views, default values of function parameters, stored procedure compilation products, and plan cache.

    -

    set behavior_compat_options = 'bind_procedure_searchpath';

    • Specifies the search path of the database objects in a stored procedure for which no schema name is specified.
    • If no schema name is specified for a stored procedure, the schema to which the stored procedure belongs is searched preferentially.

    Restores the default behavior.

    Stored procedure compilation products.

    -

    set behavior_compat_options = 'enable_out_param_override';

    Determines the overloading of output parameters of a stored procedure.

    Restores the default behavior.

    Stored procedure compilation products.

    -

    enable_bitmapscan

    The bitmapscan operator is selected.

    The bitmapscan operator is not selected.

    Plan cache.

    SET enable_auto_explain=true;
    SET auto_explain_level=notice;
    CREATE TABLE t1( a int, b int, c int,d varchar)WITH(storage_type=ustore);
    CREATE TABLE t2( a int, b int, c int,d varchar)WITH(storage_type=ustore);
    INSERT INTO t1 SELECT i,10*random()*i,i%20,'atr'||i from generate_series(1,1000) i;
    CREATE INDEX index1 ON t1(a);
    
    SET enable_bitmapscan=on;
    SET enable_seqscan=off;
    SET enable_indexscan=off;
    CREATE OR REPLACE PROCEDURE proc_while_loop()
    AS
    DECLARE
    i int :=1;
    BEGIN
    WHILE i < 5 LOOP
    INSERT INTO t2 SELECT * FROM t1 WHERE a = i ;
    i:=i+1;
    END LOOP;
    END;
    /
    CALL proc_while_loop();
    SET enable_bitmapscan=off;
    CALL proc_while_loop();
    SET enable_bitmapscan=on;
    CALL proc_while_loop();

    enable_indexscan

    The indexscan operator is selected.

    The indexscan operator is not selected.

    Plan cache.

    SET enable_auto_explain=true;
    SET auto_explain_level=notice;
    CREATE TABLE t1( a int, b int, c int,d varchar)WITH(storage_type=ustore);
    CREATE TABLE t2( a int, b int, c int,d varchar)WITH(storage_type=ustore);
    INSERT INTO t1 SELECT i,10*random()*i,i%20,'atr'||i from generate_series(1,1000) i;
    CREATE INDEX index1 on t1(a);
    SET enable_bitmapscan=off;
    SET enable_seqscan=off;
    CREATE OR REPLACE PROCEDURE proc_while_loop()
    AS
    DECLARE
    i int :=1;
    BEGIN
    WHILE i < 5 LOOP
    insert into t2 select * from t1 where a = i ;
    i:=i+1;
    END LOOP;
    END;
    /
    CALL proc_while_loop();
    SET enable_indexscan=off;
    CALL proc_while_loop();

    query_Dop

    Users can specify the degree of query parallelism. If the SMP function is enabled, the system uses the specified degree of parallelism.

    The default value is 1, which indicates that parallel query is disabled.

    Plan cache.

    SET enable_auto_explain=true;
    SET auto_explain_level=notice;
    CREATE TABLE t1( a int, b int, c int,d varchar)WITH(storage_type=ustore);
    CREATE TABLE t2( a int, b int, c int,d varchar)WITH(storage_type=ustore);
    INSERT INTO t1 SELECT i,10*random()*i,i%20,'atr'||i from generate_series(1,1000) i;
    CREATE INDEX index1 ON t1(a);
    SET enable_bitmapscan=f;
    CREATE OR REPLACE PROCEDURE proc_while_loop()
    AS
    DECLARE
    i int :=1;
    BEGIN
    WHILE i < 5 LOOP
    INSERT INTO t2 SELECT /*+ indexscan(t1 index1) */* FROM t1 WHERE a = i ;
    i:=i+1;
    END LOOP;
    END;
    /
    SET enable_auto_explain=true;
    SET auto_explain_level=notice;
    SET client_min_messages=log;
    SET query_dop=4;
    SET sql_beta_feature='enable_plsql_smp';
    CALL proc_while_loop();
    SET enable_force_Smp=on;
    CALL proc_while_loop();
    SET query_Dop=6;
    CALL proc_while_loop();

    set plan_cache_mode = force_generic_plan

    In PBE mode, the gplan is forcibly executed.

    In PBE mode, the gplan is not forcibly executed.

    Plan cache.

    SET enable_auto_explain=true;
    SET auto_explain_level=notice;
    CREATE TABLE t1( a int, b int, c int,d varchar)WITH(storage_type=ustore);
    CREATE TABLE t2( a int, b int, c int,d varchar)WITH(storage_type=ustore);
    INSERT INTO t1 SELECT i,10*random()*i,i%20,'atr'||i from generate_series(1,1000) i;
    CREATE INDEX index1 ON t1(a);
    SET enable_bitmapscan=on;
    SET enable_seqscan=off;
    SET enable_indexscan=off;
    CREATE OR REPLACE PROCEDURE proc_while_loop()
    AS
    DECLARE
    i int :=1;
    BEGIN
    WHILE i < 5 LOOP
    insert into t2 select * from t1 where a = i ;
    i:=i+1;
    END LOOP;
    END;
    /
    CALL proc_while_loop();
    SET plan_cache_mode = force_generic_plan;
    PREPARE aa AS SELECT proc_while_loop();
    EXECUTE aa;
    SET enable_bitmapscan=off;
    EXECUTE aa;

    a_format_date_timestamp

    CURRENT_DATE returns the timestamp when the current SQL statement is started.

    CURRENT_DATE returns the date or date and time when the transaction is started.

    Views, default values of function parameters, stored procedure compilation products, and plan cache.

    SET a_format_date_timestamp=on;
    CREATE OR REPLACE PROCEDURE proc_while_loop()
    AS
    DECLARE
    i date;
    BEGIN
    i:=current_date;
    raise info 'step2:%',TO_CHAR(current_date, 'MM-DD-YYYY HH24:MI:SS');
    END;
    /
    CALL proc_while_loop();
    SET a_format_date_timestamp=off;
    CALL proc_while_loop();

    adjust_systemview_priority

    Views with the same name preferentially access user-defined views.

    Views with the same name preferentially access system views.

    Default value of parameters in the views

    CREATE DATABASE database_test DBCOMPATIBILITY = 'ORA';
    SELECT datname,datcompatibility,dattimezone FROM pg_database;
    \c database_test
    CREATE TABLE t1(c int);
    CREATE VIEW dual AS SELECT * FROM t1;
    SHOW adjust_systemview_priority;
    SELECT * FROM dual;
    SET adjust_systemview_priority = on;
    SELECT * FROM dual;