From 8aa481d970480132effa70e3275bca578eaeb081 Mon Sep 17 00:00:00 2001 From: "okbob@github.com" Date: Mon, 4 Apr 2022 20:23:54 +0200 Subject: [PATCH v20220916 13/13] documentation Documentation for CREATE VARIABLE, DROP VARIABLE and LET commands. Update of GRANT, REVOKE, DISCARD, ALTER commands related to support of session variables. --- doc/src/sgml/advanced.sgml | 62 +++++ doc/src/sgml/catalogs.sgml | 158 +++++++++++++ doc/src/sgml/config.sgml | 15 ++ doc/src/sgml/event-trigger.sgml | 24 ++ doc/src/sgml/glossary.sgml | 16 ++ doc/src/sgml/plpgsql.sgml | 12 + doc/src/sgml/ref/allfiles.sgml | 4 + .../sgml/ref/alter_default_privileges.sgml | 26 ++- doc/src/sgml/ref/alter_variable.sgml | 179 +++++++++++++++ doc/src/sgml/ref/comment.sgml | 1 + doc/src/sgml/ref/create_variable.sgml | 214 ++++++++++++++++++ doc/src/sgml/ref/discard.sgml | 14 +- doc/src/sgml/ref/drop_variable.sgml | 118 ++++++++++ doc/src/sgml/ref/grant.sgml | 9 + doc/src/sgml/ref/let.sgml | 109 +++++++++ doc/src/sgml/ref/pg_restore.sgml | 11 + doc/src/sgml/ref/revoke.sgml | 7 + doc/src/sgml/reference.sgml | 4 + 18 files changed, 974 insertions(+), 9 deletions(-) create mode 100644 doc/src/sgml/ref/alter_variable.sgml create mode 100644 doc/src/sgml/ref/create_variable.sgml create mode 100644 doc/src/sgml/ref/drop_variable.sgml create mode 100644 doc/src/sgml/ref/let.sgml diff --git a/doc/src/sgml/advanced.sgml b/doc/src/sgml/advanced.sgml index 755c9f1485..c65b2bb336 100644 --- a/doc/src/sgml/advanced.sgml +++ b/doc/src/sgml/advanced.sgml @@ -700,6 +700,68 @@ SELECT name, elevation + + Session Variables + + + Session variables + + + + session variable + introduction + + + + Session variables are database objects that can hold a value. + Session variables, like relations, exist within a schema and their access + is controlled via GRANT and REVOKE + commands. A session variable can be created by the CREATE + VARIABLE command. + + + + The value of a session variable is set with the LET SQL + command. While session variables share properties with tables, their value + cannot be updated with an UPDATE command. The value of a + session variable may be retrieved by the SELECT SQL + command. + +CREATE VARIABLE var1 AS date; +LET var1 = current_date; +SELECT var1; + + + or + + +CREATE VARIABLE public.current_user_id AS integer; +GRANT READ ON VARIABLE public.current_user_id TO PUBLIC; +LET current_user_id = (SELECT id FROM users WHERE usename = session_user); +SELECT current_user_id; + + + + + The value of a session variable is local to the current session. Retrieving + a variable's value returns either a NULL or a default + value, unless its value has been set to something else in the current + session using the LET command. The content of a variable + is not transactional. This is the same as regular variables in PL + languages. + + + + The session variables can be shadowed by column references in a query. When + a query contains identifiers or qualified identifiers that could be used as + both a session variable identifiers and as column identifier, then the + column identifier is preferred every time. Warnings can be emitted when + this situation happens by enabling configuration parameter . + + + + Conclusion diff --git a/doc/src/sgml/catalogs.sgml b/doc/src/sgml/catalogs.sgml index 00f833d210..e5294be4a2 100644 --- a/doc/src/sgml/catalogs.sgml +++ b/doc/src/sgml/catalogs.sgml @@ -369,6 +369,11 @@ pg_user_mapping mappings of users to foreign servers + + + pg_variable + session variables + @@ -9613,4 +9618,157 @@ SCRAM-SHA-256$<iteration count>:&l + + <structname>pg_variable</structname> + + + pg_variable + + + + The table pg_variable provides information about + session variables. + + + + <structname>pg_variable</structname> Columns + + + + + Column Type + + + Description + + + + + + + + oid oid + + + Row identifier + + + + + + varname name + + + Name of the session variable + + + + + + varnamespace oid + (references pg_namespace.oid) + + + The OID of the namespace that contains this variable + + + + + + vartype oid + (references pg_type.oid) + + + The OID of the variable's data type + + + + + + vartypmod int4 + + + vartypmod records type-specific data + supplied at variable creation time (for example, the maximum + length of a varchar column). It is passed to + type-specific input functions and length coercion functions. + The value will generally be -1 for types that do not need vartypmod. + + + + + + varowner oid + (references pg_authid.oid) + + + Owner of the variable + + + + + + varcollation oid + (references pg_collation.oid) + + + The defined collation of the variable, or zero if the variable is + not of a collatable data type. + + + + + + varisnotnull boolean + + + True if the session variable doesn't allow null value. The default value is false. + + + + + + varisimmutable boolean + + + True if the variable is immutable (cannot be modified). The default value is false. + + + + + + vareoxaction char + + + Action performed at end of transaction: + n = no action, d = drop the variable, + r = reset the variable to its default value. + + + + + + vardefexpr pg_node_tree + + + The internal representation of the variable default value + + + + + + varacl aclitem[] + + + Access privileges; see + and + + for details + + + + +
+
+ diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml index 700914684d..939a124e8c 100644 --- a/doc/src/sgml/config.sgml +++ b/doc/src/sgml/config.sgml @@ -10239,6 +10239,21 @@ dynamic_library_path = 'C:\tools\postgresql;H:\my_project\lib;$libdir' + + session_variables_ambiguity_warning (boolean) + + session_variables_ambiguity_warning configuration parameter + + + + + When on, a warning is raised when any identifier in a query could be + used as both a column identifier, routine variable or a session + variable identifier. The default is off. + + + + standard_conforming_strings (boolean) stringsstandard conforming diff --git a/doc/src/sgml/event-trigger.sgml b/doc/src/sgml/event-trigger.sgml index f1235a2c9f..a8f303b474 100644 --- a/doc/src/sgml/event-trigger.sgml +++ b/doc/src/sgml/event-trigger.sgml @@ -405,6 +405,14 @@ - + + ALTER VARIABLE + X + X + - + - + + ALTER VIEW X @@ -693,6 +701,14 @@ - + + CREATE VARIABLE + X + X + - + - + + CREATE VIEW X @@ -981,6 +997,14 @@ - + + DROP VARIABLE + X + X + X + - + + DROP VIEW X diff --git a/doc/src/sgml/glossary.sgml b/doc/src/sgml/glossary.sgml index d6d0a3a814..a46baa0c17 100644 --- a/doc/src/sgml/glossary.sgml +++ b/doc/src/sgml/glossary.sgml @@ -1477,6 +1477,22 @@ + + Session variable + + + A persistent database object that holds a value in session memory. This + memory is not shared across sessions, and after session end, this memory + (the value) is released. The access (read or write) to session variables + is controlled by access rights similarly to other database object access + rights. + + + For more information, see . + + + + Shared memory diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml index d85f89bf30..cf73e44732 100644 --- a/doc/src/sgml/plpgsql.sgml +++ b/doc/src/sgml/plpgsql.sgml @@ -5953,6 +5953,18 @@ $$ LANGUAGE plpgsql STRICT IMMUTABLE; + + + <command>Session variables</command> + + + The PL/pgSQL language has no packages, and + therefore no package variables or package constants. + PostgreSQL has session variables and immutable + session variables. Session variables can be created by CREATE + VARIABLE, as described in . + + diff --git a/doc/src/sgml/ref/allfiles.sgml b/doc/src/sgml/ref/allfiles.sgml index e90a0e1f83..24e30fdd97 100644 --- a/doc/src/sgml/ref/allfiles.sgml +++ b/doc/src/sgml/ref/allfiles.sgml @@ -47,6 +47,7 @@ Complete list of usable sgml source files in this directory. + @@ -99,6 +100,7 @@ Complete list of usable sgml source files in this directory. + @@ -148,6 +150,7 @@ Complete list of usable sgml source files in this directory. + @@ -155,6 +158,7 @@ Complete list of usable sgml source files in this directory. + diff --git a/doc/src/sgml/ref/alter_default_privileges.sgml b/doc/src/sgml/ref/alter_default_privileges.sgml index f1d54f5aa3..354991b849 100644 --- a/doc/src/sgml/ref/alter_default_privileges.sgml +++ b/doc/src/sgml/ref/alter_default_privileges.sgml @@ -50,6 +50,10 @@ GRANT { USAGE | CREATE | ALL [ PRIVILEGES ] } ON SCHEMAS TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ] +GRANT { SELECT | UPDATE | ALL [ PRIVILEGES ] } + ON VARIABLES + TO { [ GROUP ] role_name | PUBLIC } [, ...] [ WITH GRANT OPTION ] + REVOKE [ GRANT OPTION FOR ] { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES | TRIGGER } [, ...] | ALL [ PRIVILEGES ] } @@ -81,6 +85,12 @@ REVOKE [ GRANT OPTION FOR ] ON SCHEMAS FROM { [ GROUP ] role_name | PUBLIC } [, ...] [ CASCADE | RESTRICT ] + +REVOKE [ GRANT OPTION FOR ] + { { SELECT | UPDATE } [, ...] | ALL [ PRIVILEGES ] } + ON VARIABLES + FROM { [ GROUP ] role_name | PUBLIC } [, ...] + [ CASCADE | RESTRICT ] @@ -92,14 +102,14 @@ REVOKE [ GRANT OPTION FOR ] that will be applied to objects created in the future. (It does not affect privileges assigned to already-existing objects.) Currently, only the privileges for schemas, tables (including views and foreign - tables), sequences, functions, and types (including domains) can be - altered. For this command, functions include aggregates and procedures. - The words FUNCTIONS and ROUTINES are - equivalent in this command. (ROUTINES is preferred - going forward as the standard term for functions and procedures taken - together. In earlier PostgreSQL releases, only the - word FUNCTIONS was allowed. It is not possible to set - default privileges for functions and procedures separately.) + tables), sequences, functions, types (including domains) and session + variables can be altered. For this command, functions include aggregates + and procedures. The words FUNCTIONS and + ROUTINES are equivalent in this command. + (ROUTINES is preferred going forward as the standard term + for functions and procedures taken together. In earlier PostgreSQL + releases, only the word FUNCTIONS was allowed. It is not + possible to set default privileges for functions and procedures separately.) diff --git a/doc/src/sgml/ref/alter_variable.sgml b/doc/src/sgml/ref/alter_variable.sgml new file mode 100644 index 0000000000..d2036351e5 --- /dev/null +++ b/doc/src/sgml/ref/alter_variable.sgml @@ -0,0 +1,179 @@ + + + + + ALTER VARIABLE + + + + session variable + altering + + + + ALTER VARIABLE + 7 + SQL - Language Statements + + + + ALTER VARIABLE + + change the definition of a session variable + + + + + +ALTER VARIABLE name OWNER TO { new_owner | CURRENT_ROLE | CURRENT_USER | SESSION_USER } +ALTER VARIABLE name RENAME TO new_name +ALTER VARIABLE name SET SCHEMA new_schema + + + + + Description + + + The ALTER VARIABLE command changes the definition of an + existing session variable. There are several subforms: + + + + OWNER + + + This form changes the owner of the session variable. + + + + + + RENAME + + + This form changes the name of the session variable. + + + + + + SET SCHEMA + + + This form moves the session variable into another schema. + + + + + + + + + Only the owner or a superuser is allowed to alter a session variable. + In order to move a session variable from one schema to another, the user + must also have the CREATE privilege on the new schema (or + be a superuser). + + In order to move the session variable ownership from one role to another, + the user must also be a direct or indirect member of the new + owning role, and that role must have the CREATE privilege + on the session variable's schema (or be a superuser). These restrictions + enforce that altering the owner doesn't do anything you couldn't do by + dropping and recreating the session variable. + + + + + Parameters + + + + + name + + + The name (possibly schema-qualified) of the existing session variable + to alter. + + + + + + new_name + + + The new name for the session variable. + + + + + + new_owner + + + The user name of the new owner of the session variable. + + + + + + new_schema + + + The new schema for the session variable. + + + + + + + + + Examples + + + To rename a session variable: + +ALTER VARIABLE foo RENAME TO boo; + + + + + To change the owner of the session variable boo to + joe: + +ALTER VARIABLE boo OWNER TO joe; + + + + + To change the schema of the session variable boo to + private: + +ALTER VARIABLE boo SET SCHEMA private; + + + + + + Compatibility + + + Session variables and this command in particular are a PostgreSQL extension. + + + + + See Also + + + + + + + + diff --git a/doc/src/sgml/ref/comment.sgml b/doc/src/sgml/ref/comment.sgml index 23d9029af9..50bfec6f28 100644 --- a/doc/src/sgml/ref/comment.sgml +++ b/doc/src/sgml/ref/comment.sgml @@ -65,6 +65,7 @@ COMMENT ON TRANSFORM FOR type_name LANGUAGE lang_name | TRIGGER trigger_name ON table_name | TYPE object_name | + VARIABLE object_name | VIEW object_name } IS 'text' diff --git a/doc/src/sgml/ref/create_variable.sgml b/doc/src/sgml/ref/create_variable.sgml new file mode 100644 index 0000000000..70c87968ce --- /dev/null +++ b/doc/src/sgml/ref/create_variable.sgml @@ -0,0 +1,214 @@ + + + + + CREATE VARIABLE + + + + session variable + defining + + + + CREATE VARIABLE + 7 + SQL - Language Statements + + + + CREATE VARIABLE + define a session variable + + + + +CREATE [ { TEMPORARY | TEMP } ] [ IMMUTABLE ] VARIABLE [ IF NOT EXISTS ] name [ AS ] data_type ] [ COLLATE collation ] + [ NOT NULL ] [ DEFAULT default_expr ] [ { ON COMMIT DROP | ON TRANSACTION END RESET } ] + + + + Description + + + The CREATE VARIABLE command creates a session variable. + Session variables, like relations, exist within a schema and their access is + controlled via GRANT and REVOKE + commands. + + + + The value of a session variable is local to the current session. Retrieving + a session variable's value returns either a NULL or a default value, unless + its value is set to something else in the current session with a LET + command. The content of a session variable is not transactional. This is the + same as regular variables in PL languages. + + + + Session variables are retrieved by the SELECT SQL + command. Their value is set with the LET SQL command. + While session variables share properties with tables, their value cannot be + changed with an UPDATE command. + + + + + Inside a query or an expression, the session variable can be shadowed by + column or by routine's variable or routine argument. Such collisions of + identifiers can be resolved by using qualified identifiers. Session variables + can use schema name, columns can use table aliases, routine variables + can use block labels, and routine arguments can use the routine name. + + + + + + Parameters + + + + IMMUTABLE + + + The assigned value of the session variable can not be changed. + Only if the session variable doesn't have a default value, a single + initialization is allowed using the LET command. Once + done, no further change is allowed until end of transaction + if the session variable was created with clause ON TRANSACTION + END RESET, or until reset of all session variables by + DISCARD VARIABLES, or until reset of all session + objects by command DISCARD ALL. + + + + + + + IF NOT EXISTS + + + Do not throw an error if the name already exists. A notice is issued in + this case. + + + + + + name + + + The name, optionally schema-qualified, of the session variable. + + + + + + data_type + + + The name, optionally schema-qualified, of the data type of the session + variable. + + + + + + COLLATE collation + + + The COLLATE clause assigns a collation to the session + variable (which must be of a collatable data type). If not specified, + the data type's default collation is used. + + + + + + NOT NULL + + + The NOT NULL clause forbids setting the session + variable to a null value. A session variable created as NOT NULL and + without an explicitly declared default value cannot be read until it is + initialized by a LET command. This requires the user to explicitly + initialize the session variable content before reading it, otherwise an + error will be thrown. + + + + + + DEFAULT default_expr + + + The DEFAULT clause can be used to assign a default + value to a session variable. This expression is evaluated when the session + variable is first accessed for reading and had not yet been assigned a value. + + + + + + ON COMMIT DROP, ON TRANSACTION END RESET + + + The ON COMMIT DROP clause specifies the behaviour of a + temporary session variable at transaction commit. With this clause, the + session variable is dropped at commit time. The clause is only allowed + for temporary variables. The ON TRANSACTION END RESET + clause causes the session variable to be reset to its default value when + the transaction is committed or rolled back. + + + + + + + + + Notes + + + Use the DROP VARIABLE command to remove a session + variable. + + + + + Examples + + + Create an date session variable var1: + +CREATE VARIABLE var1 AS date; +LET var1 = current_date; +SELECT var1; + + + + + + + Compatibility + + + The CREATE VARIABLE command is a + PostgreSQL extension. + + + + + See Also + + + + + + + + + diff --git a/doc/src/sgml/ref/discard.sgml b/doc/src/sgml/ref/discard.sgml index bf44c523ca..6f90672afa 100644 --- a/doc/src/sgml/ref/discard.sgml +++ b/doc/src/sgml/ref/discard.sgml @@ -21,7 +21,7 @@ PostgreSQL documentation -DISCARD { ALL | PLANS | SEQUENCES | TEMPORARY | TEMP } +DISCARD { ALL | PLANS | SEQUENCES | TEMPORARY | TEMP | VARIABLES } @@ -75,6 +75,17 @@ DISCARD { ALL | PLANS | SEQUENCES | TEMPORARY | TEMP } + + VARIABLES + + + Resets the value of all session variables. If a variable + is later reused, it is re-initialized to either + NULL or its default value. + + + + ALL @@ -93,6 +104,7 @@ SELECT pg_advisory_unlock_all(); DISCARD PLANS; DISCARD TEMP; DISCARD SEQUENCES; +DISCARD VARIABLES; diff --git a/doc/src/sgml/ref/drop_variable.sgml b/doc/src/sgml/ref/drop_variable.sgml new file mode 100644 index 0000000000..67988b5fcd --- /dev/null +++ b/doc/src/sgml/ref/drop_variable.sgml @@ -0,0 +1,118 @@ + + + + + DROP VARIABLE + + + + session variable + removing + + + + DROP VARIABLE + 7 + SQL - Language Statements + + + + DROP VARIABLE + remove a session variable + + + + +DROP VARIABLE [ IF EXISTS ] name [, ...] [ CASCADE | RESTRICT ] + + + + + Description + + + DROP VARIABLE removes a session variable. + A session variable can only be removed by its owner or a superuser. + + + + + Parameters + + + + IF EXISTS + + + Do not throw an error if the session variable does not exist. A notice is + issued in this case. + + + + + + name + + + The name, optionally schema-qualified, of a session variable. + + + + + + CASCADE + + + Automatically drop objects that depend on the session variable (such as + views), and in turn all objects that depend on those objects + (see ). + + + + + + RESTRICT + + + Refuse to drop the session variable if any objects depend on it. This is + the default. + + + + + + + + Examples + + + To remove the session variable var1: + + +DROP VARIABLE var1; + + + + + Compatibility + + + The DROP VARIABLE command is a + PostgreSQL extension. + + + + + See Also + + + + + + + + + diff --git a/doc/src/sgml/ref/grant.sgml b/doc/src/sgml/ref/grant.sgml index dea19cd348..e2191b7767 100644 --- a/doc/src/sgml/ref/grant.sgml +++ b/doc/src/sgml/ref/grant.sgml @@ -108,6 +108,15 @@ GRANT role_name [, ...] TO variable_name [, ...] + | ALL VARIABLES IN SCHEMA schema_name [, ...] } + TO role_specification [, ...] [ WITH GRANT OPTION ] + [ GRANTED BY role_specification ] + + TO role_specification [, ...] [ WITH GRANT OPTION ] + diff --git a/doc/src/sgml/ref/let.sgml b/doc/src/sgml/ref/let.sgml new file mode 100644 index 0000000000..c5d1e4d962 --- /dev/null +++ b/doc/src/sgml/ref/let.sgml @@ -0,0 +1,109 @@ + + + + + LET + + + + session variable + changing + + + + LET + 7 + SQL - Language Statements + + + + LET + change a session variable's value + + + + +LET session_variable = sql_expression +LET session_variable = DEFAULT + + + + + Description + + + The LET command assigns a value to the specified session + variable. + + + + + + Parameters + + + + session_variable + + + The name of the session variable. + + + + + + sql_expression + + + An SQL expression (can be subquery in parenthesis). The result must + be of castable to the same data type as the session variable (in + implicit or assignment context). + + + + + + DEFAULT + + + Reset the session variable to its default value, if that is defined. + If no explicit default value has been declared, the session variable + is set to NULL. + + + + + + + Example: + +CREATE VARIABLE myvar AS integer; +LET myvar = 10; +LET myvar = (SELECT sum(val) FROM tab); +LET myvar = DEFAULT; + + + + + + Compatibility + + + The LET is a PostgreSQL + extension. + + + + + See Also + + + + + + + + diff --git a/doc/src/sgml/ref/pg_restore.sgml b/doc/src/sgml/ref/pg_restore.sgml index 47bd7dbda0..39cb595647 100644 --- a/doc/src/sgml/ref/pg_restore.sgml +++ b/doc/src/sgml/ref/pg_restore.sgml @@ -106,6 +106,17 @@ PostgreSQL documentation + + + + + + Restore a named session variable only. Multiple session variables may + be specified with multiple switches. + + + + diff --git a/doc/src/sgml/ref/revoke.sgml b/doc/src/sgml/ref/revoke.sgml index 4fd4bfb3d7..0579b4599d 100644 --- a/doc/src/sgml/ref/revoke.sgml +++ b/doc/src/sgml/ref/revoke.sgml @@ -137,6 +137,13 @@ REVOKE [ { ADMIN | INHERIT } OPTION FOR ] | CURRENT_ROLE | CURRENT_USER | SESSION_USER + +REVOKE [ GRANT OPTION FOR ] + { { SELECT | UPDATE } [, ...] | ALL [ PRIVILEGES ] } + ON VARIABLE variable_name [, ...] + | ALL VARIABLES IN SCHEMA schema_name [, ...] } + FROM { [ GROUP ] role_name | PUBLIC } [, ...] + [ CASCADE | RESTRICT ] diff --git a/doc/src/sgml/reference.sgml b/doc/src/sgml/reference.sgml index a3b743e8c1..f5ec3c987b 100644 --- a/doc/src/sgml/reference.sgml +++ b/doc/src/sgml/reference.sgml @@ -75,6 +75,7 @@ &alterType; &alterUser; &alterUserMapping; + &alterVariable; &alterView; &analyze; &begin; @@ -127,6 +128,7 @@ &createType; &createUser; &createUserMapping; + &createVariable; &createView; &deallocate; &declare; @@ -175,6 +177,7 @@ &dropType; &dropUser; &dropUserMapping; + &dropVariable; &dropView; &end; &execute; @@ -183,6 +186,7 @@ &grant; &importForeignSchema; &insert; + &let; &listen; &load; &lock; -- 2.37.0