F.48. pg_variables — functions for working with variables of various types #
The pg_variables
module provides functions for working with variables of various types. The created variables are only available in the current user session.
F.48.1. Installation #
The pg_variables
extension is included into Postgres Pro. Once you have Postgres Pro installed, you must execute the CREATE EXTENSION command to enable pg_variables
, as follows:
CREATE EXTENSION pg_variables;
F.48.2. Usage #
The pg_variables
module provides several functions for creating, reading, and managing variables of scalar, record, and array types. See the following sections for function descriptions and syntax:
Section F.48.3.1 describes functions for scalar variables.
Section F.48.3.2 describes functions for collections of record variables.
Section F.48.3.3 describes functions for array variables.
Section F.48.3.4 describes functions for general collection variables.
Section F.48.3.6 lists functions you can use to manage all variables in your current session.
For detailed usage examples, see Section F.48.5.
F.48.2.1. Using Transactional Variables #
By default, the created variables are non-transactional. Once successfully set, a variable exists for the whole session, regardless of rollbacks, if any. For example:
SELECT pgv_set('vars', 'int1', 101); BEGIN; SELECT pgv_set('vars', 'int2', 102); ROLLBACK; SELECT * FROM pgv_list() order by package, name; package | name | is_transactional ---------+------+------------------ vars | int1 | f vars | int2 | f
If you would like to use variables that support transactions and savepoints, pass the optional is_transactional
flag as the last parameter when creating this variable:
BEGIN; SELECT pgv_set('vars', 'trans_int', 101, true); SAVEPOINT sp1; SELECT pgv_set('vars', 'trans_int', 102, true); ROLLBACK TO sp1; COMMIT; SELECT pgv_get('vars', 'trans_int', NULL::int); pgv_get --------- 101
You must use the is_transactional
flag every time you change the value of a transactional variable using pgv_set()
or pgv_insert()
functions. Otherwise, an error occurs. Other functions do not require this flag.
SELECT pgv_insert('pack', 'var_record', row(123::int, 'text'::text), true); SELECT pgv_insert('pack', 'var_record', row(456::int, 'another text'::text)); ERROR: variable "var_record" already created as TRANSACTIONAL SELECT pgv_delete('pack', 'var_record', 123::int);
If the pgv_free()
or pgv_remove()
function calls are rolled back, the affected transactional variables will be restored, unlike non-transactional variables, which are removed permanently. For example:
SELECT pgv_set('pack', 'var_reg', 123); SELECT pgv_set('pack', 'var_trans', 456, true); BEGIN; SELECT pgv_free(); ROLLBACK; SELECT * FROM pgv_list(); package | name | is_transactional ---------+-----------+------------------ pack | var_trans | t
F.48.3. Functions #
F.48.3.1. Scalar Variables #
The following functions support scalar variables:
Function | Returns |
---|---|
pgv_set(package text, name text, value anynonarray, is_transactional bool default false) | void |
pgv_get(package text, name text, var_type anynonarray, strict bool default true) | anynonarray |
To use the pgv_get()
function, you must first create a package and a variable using the pgv_set()
function. If the specified package or variable does not exist, an error occurs:
SELECT pgv_get('vars', 'int1', NULL::int); ERROR: unrecognized package "vars"
SELECT pgv_get('vars', 'int1', NULL::int); ERROR: unrecognized variable "int1"
pgv_get()
function checks the variable type. If the specified type does not match the type of the variable, an error is raised:
SELECT pgv_get('vars', 'int1', NULL::text); ERROR: variable "int1" requires "integer" value
F.48.3.2. Collections of Records #
The following functions support collections of record variables:
Function | Returns | Description |
---|---|---|
pgv_insert(package text, name text, r record, is_transactional bool default false) | void | Inserts a record into a collection variable for the specified package. If the package or variable does not exist, it is created automatically. The first column of r is the primary key. If a record with the same primary key already exists or this collection variable has a different structure, an error is raised. |
pgv_update(package text, name text, r record) | boolean | Updates a record with the corresponding primary key (the first column of r is the primary key). Returns true if the record was found. If this collection variable has a different structure, an error is raised. |
pgv_delete(package text, name text, value anynonarray) | boolean | Deletes a record with the corresponding primary key (the first column of r is the primary key). Returns true if the record was found and false otherwise. |
pgv_select(package text, name text) | set of records | Returns the collection variable records. |
pgv_select(package text, name text, value anynonarray) | record | Returns the record with the corresponding primary key (the first column of r is a primary key). |
pgv_select(package text, name text, value anyarray) | set of records | Returns the collection variable records with the corresponding primary keys (the first column of r is a primary key). |
To use pgv_update()
, pgv_delete()
and pgv_select()
functions, you must first create a package and a variable using the pgv_insert()
function. The variable type and the record type must be the same; otherwise, an error occurs.
F.48.3.3. Arrays #
The following functions support array variables:
Function | Returns |
---|---|
pgv_set(package text, name text, value anyarray, is_transactional bool default false) | void |
pgv_get(package text, name text, var_type anyarray, strict bool default true) | anyarray |
Usage instructions for these functions are the same as those provided in Section F.48.3.1 for scalar variables.
F.48.3.4. General Collections #
The following functions support general collection variables:
Function | Returns | Description |
---|---|---|
| void | Sets a value for the element with the key key of the collection variable name in the package package . If the package or variable does not exist, it is created automatically. Inside one collection, only keys of the same type are allowed. The key argument can have either int or text type. If an element with the specified key already exists, its value is set to the new one. is_transactional shows whether the new variable is transactional and equals false by default. So if the variable already exists, it must be transactional/non-transactional as indicated by is_transactional , otherwise an error is raised. If the collection already exists and its value type does not match the type of the new value, an error is also raised. |
| anyelement | Returns the value of the element with the key key of the collection variable name in the package package . If there is no element with the specified key in this collection, returns NULL. The key argument can have either int or text type. If the package or variable does not exist, an error is raised. If the specified variable is not a collection, an error is also raised. The val_type argument is required to properly determine the return type. |
| void | Removes the element with the key key from the collection variable name in the package package . If there is no element with the specified key in this collection, does nothing. The key argument can have either int or text type. If the package or variable does not exist, an error is raised. If the specified variable is not a collection, an error is also raised. |
Important
Collections initialized with pgv_set_elem()
and with pgv_insert()
are not considered compatible.
F.48.3.5. Iterators #
The following functions are provided to use iterators to traverse collection variables. These functions work with collections initialized with both pgv_set_elem()
and pgv_insert()
.
Function | Returns | Description |
---|---|---|
pgv_first(package text, name text, key_type anyelement) | anyelement | Returns the first key from the collection variable. Collections are sorted by the key in ascending order. key_type is required to determine the return value. If the name passed is the name of a non-collection variable, an error is raised. |
pgv_last(package text, name text, key_type anyelement) | anyelement | Returns the last key from the collection variable. Collections are sorted by the key in ascending order. key_type is required to determine the return value. If the name passed is the name of a non-collection variable, an error is raised. |
pgv_next(package text, name text, key anyelement) | anyelement | Returns the next key from the collection variable. The key passed may not exist in the collection. Returns NULL if used for the last key in the collection. Collections are sorted by the key in ascending order. If the name passed is the name of a non-collection variable, an error is raised. |
pgv_prior(package text, name text, key anyelement) | anyelement | Returns the previous key from the collection variable. The key passed may not exist in the collection. Returns NULL if used for the first key in the collection. Collections are sorted by the key in ascending order. If the name passed is the name of a non-collection variable, an error is raised. |
pgv_count(package text, name text) | integer | Returns the number of elements in the collection. If the name passed is the name of a non-collection variable, an error is raised. |
F.48.3.6. Miscellaneous Functions #
Function | Returns | Description |
---|---|---|
pgv_exists(package text, name text) | bool | Returns true if the specified package and variable exist and false otherwise. |
pgv_exists(package text) | bool | Returns true if the specified package exists and false otherwise. |
pgv_remove(package text, name text) | void | Removes the variable with the specified name. The specified package and variable must exist; otherwise, an error is raised. |
pgv_remove(package text) | void | Removes the specified package and all the corresponding variables. The specified package must exist; otherwise, an error is raised. |
pgv_free() | void | Removes all packages and variables. |
pgv_list() | table(package text, name text, is_transactional bool) | Displays all the available variables and the corresponding packages, as well as whether each variable is transactional. |
pgv_stats() | table(package text, allocated_memory bigint) | Returns the list of assigned packages and the amount of memory used by variables, in bytes. If you are using transactional variables, this list also includes all deleted packages that still may be restored by a ROLLBACK . This function only supports Postgres Pro 9.6 or higher. |
F.48.3.7. Deprecated Functions #
F.48.3.7.1. Integer Variables #
The following functions are deprecated. Use generic functions for scalar variables instead.
Function | Returns |
---|---|
pgv_set_int(package text, name text, value int, is_transactional bool default false) | void |
pgv_get_int(package text, name text, strict bool default true) | int |
F.48.3.7.2. Text Variables #
The following functions are deprecated. Use generic functions for scalar variables instead.
Function | Returns |
---|---|
pgv_set_text(package text, name text, value text, is_transactional bool default false) | void |
pgv_get_text(package text, name text, strict bool default true) | text |
F.48.3.7.3. Numeric Variables #
The following functions are deprecated. Use generic functions for scalar variables instead.
Function | Returns |
---|---|
pgv_set_numeric(package text, name text, value numeric, is_transactional bool default false) | void |
pgv_get_numeric(package text, name text, strict bool default true) | numeric |
F.48.3.7.4. Timestamp Variables #
The following functions are deprecated. Use generic functions for scalar variables instead.
Function | Returns |
---|---|
pgv_set_timestamp(package text, name text, value timestamp, is_transactional bool default false) | void |
pgv_get_timestamp(package text, name text, strict bool default true) | timestamp |
F.48.3.7.5. Timestamp with timezone Variables #
The following functions are deprecated. Use generic functions for scalar variables instead.
Function | Returns |
---|---|
pgv_set_timestamptz(package text, name text, value timestamptz, is_transactional bool default false) | void |
pgv_get_timestamptz(package text, name text, strict bool default true) | timestamptz |
F.48.3.7.6. Date Variables #
The following functions are deprecated. Use generic functions for scalar variables instead.
Function | Returns |
---|---|
pgv_set_date(package text, name text, value date, is_transactional bool default false) | void |
pgv_get_date(package text, name text, strict bool default true) | date |
F.48.3.7.7. Jsonb Variables #
The following functions are deprecated. Use generic functions for scalar variables instead.
Function | Returns |
---|---|
pgv_set_jsonb(package text, name text, value jsonb, is_transactional bool default false) | void |
pgv_get_jsonb(package text, name text, strict bool default true) | jsonb |
F.48.4. Important Notes #
F.48.4.1. Collations in Collections #
Collections are stored in ascending order. In the case of text
keys, you need a collation to determine the order of elements. If no collation is specified when inserting the first element of a collection, the default collation is used. Otherwise, the specified collation is used.
F.48.4.2. Cursors for Set-Returning Functions #
All set-returning functions except pgv_select(package, variable)
fix their return results at first FETCH
from the cursor and are not affected by further data manipulation.
The results of pgv_select(package, variable)
are received dynamically and are affected by transactions/changes in the collection. For pgv_select()
called for a transactional collection, cursors look at the snapshot of the collection when the first FETCH
was executed, but consider changes that were made in that transaction and in committed subtransactions.
F.48.5. Examples #
Define scalar variables using the pgv_set()
function, and then return their values using the pgv_get()
function:
SELECT pgv_set('vars', 'int1', 101); SELECT pgv_set('vars', 'int2', 102); SELECT pgv_set('vars', 'text1', 'text variable'::text); SELECT pgv_get('vars', 'int1', NULL::int); pgv_get ------------- 101 SELECT pgv_get('vars', 'int2', NULL::int); pgv_get ------------- 102 SELECT pgv_get('vars', 'text1', NULL::text); pgv_get --------------- text variable
Let's assume we have the tab
table and examine several examples of using record variables:
CREATE TABLE tab (id int, t varchar); INSERT INTO tab VALUES (0, 'str00'), (1, 'str11');
You can use the following functions to work with record variables:
SELECT pgv_insert('vars', 'r1', tab) FROM tab; SELECT pgv_select('vars', 'r1'); pgv_select ------------ (1,str11) (0,str00) SELECT pgv_select('vars', 'r1', 1); pgv_select ------------ (1,str11) SELECT pgv_select('vars', 'r1', 0); pgv_select ------------ (0,str00) SELECT pgv_select('vars', 'r1', ARRAY[1, 0]); pgv_select ------------ (1,str11) (0,str00) SELECT pgv_delete('vars', 'r1', 1); SELECT pgv_select('vars', 'r1'); pgv_select ------------ (0,str00)
Consider the behavior of a transactional variable var_text
when changed before and after savepoints:
SELECT pgv_set('pack', 'var_text', 'before transaction block'::text, true); BEGIN; SELECT pgv_set('pack', 'var_text', 'before savepoint'::text, true); SAVEPOINT sp1; SELECT pgv_set('pack', 'var_text', 'savepoint sp1'::text, true); SAVEPOINT sp2; SELECT pgv_set('pack', 'var_text', 'savepoint sp2'::text, true); RELEASE sp2; SELECT pgv_get('pack', 'var_text', NULL::text); pgv_get --------------- savepoint sp2 ROLLBACK TO sp1; SELECT pgv_get('pack', 'var_text', NULL::text); pgv_get ------------------ before savepoint ROLLBACK; SELECT pgv_get('pack', 'var_text', NULL::text); pgv_get -------------------------- before transaction block
If you create a variable after BEGIN
or SAVEPOINT
statements and than rollback to the previous state, the transactional variable is removed:
BEGIN; SAVEPOINT sp1; SAVEPOINT sp2; SELECT pgv_set('pack', 'var_int', 122, true); RELEASE SAVEPOINT sp2; SELECT pgv_get('pack', 'var_int', NULL::int); pgv_get --------- 122 ROLLBACK TO sp1; SELECT pgv_get('pack','var_int', NULL::int); ERROR: unrecognized variable "var_int" COMMIT;
List the available packages and variables:
SELECT * FROM pgv_list() ORDER BY package, name; package | name | is_transactional ---------+----------+------------------ pack | var_text | t vars | int1 | f vars | int2 | f vars | r1 | f vars | text1 | f
Get the amount of memory used by variables, in bytes:
SELECT * FROM pgv_stats() ORDER BY package; package | allocated_memory ---------+------------------ pack | 16384 vars | 32768
Delete the specified variables or packages:
SELECT pgv_remove('vars', 'int1'); SELECT pgv_remove('vars');
Delete all packages and variables:
SELECT pgv_free();
These examples show usage of collection variables and iterator functions:
sql SELECT pgv_set_elem('pack', 'var', 1, 1); SELECT pgv_set_elem('pack', 'var', 5, 5); SELECT pgv_set_elem('pack', 'var', 10, 10); SELECT pgv_first('pack', 'var', NULL::int); pgv_first ----------- 1 SELECT pgv_last('pack', 'var', NULL::int); pgv_last ---------- 10 SELECT pgv_next('pack', 'var', pgv_first('pack', 'var', NULL::int)); pgv_next ---------- 5 SELECT pgv_prior('pack', 'var', pgv_last('pack', 'var', NULL::int)); pgv_prior ----------- 5 SELECT pgv_prior('pack', 'var', pgv_first('pack', 'var', NULL::int)); pgv_prior ----------- SELECT pgv_next('pack', 'var', pgv_last('pack', 'var', NULL::int)); pgv_prior ----------- SELECT pgv_next('pack', 'var', 3); pgv_next ---------- 5 SELECT pgv_prior('pack', 'var', 3); pgv_prior ----------- 1 SELECT pgv_get_elem('pack', 'var', pgv_last('pack', 'var', NULL::int), NULL::int); pgv_get_elem -------------- 10 SELECT pgv_remove_elem('pack', 'var', pgv_last('pack', 'var', NULL::int)); pgv_remove_elem ----------------- SELECT pgv_get_elem('pack', 'var', pgv_last('pack', 'var', NULL::int), NULL::int); pgv_get_elem -------------- 5 (1 row)
These examples show how the collation affects the order of elements in a collection. They also show how to iterate over a whole collection with PL/pgSQL loops:
sql SELECT pgv_set_elem('pack', 'var1', 'а' COLLATE "ru_RU", 'а'::text); SELECT pgv_set_elem('pack', 'var1', 'д' COLLATE "ru_RU", 'д'::text); SELECT pgv_set_elem('pack', 'var1', 'е' COLLATE "ru_RU", 'е'::text); SELECT pgv_set_elem('pack', 'var1', 'ё' COLLATE "ru_RU", 'ё'::text); SELECT pgv_set_elem('pack', 'var1', 'ж' COLLATE "ru_RU", 'ж'::text); SELECT pgv_set_elem('pack', 'var1', 'я' COLLATE "ru_RU", 'я'::text); DO $$ DECLARE iter text; BEGIN iter := pgv_first('pack', 'var1', NULL::text); WHILE iter IS NOT NULL LOOP RAISE NOTICE '%', pgv_get_elem('pack', 'var1', iter, NULL::text); iter := pgv_next('pack', 'var1', iter); END LOOP; END; $$; NOTICE: а NOTICE: д NOTICE: е NOTICE: ё NOTICE: ж NOTICE: я SELECT pgv_set_elem('pack', 'var2', 'а' COLLATE "C", 'а'::text); SELECT pgv_set_elem('pack', 'var2', 'д' COLLATE "C", 'д'::text); SELECT pgv_set_elem('pack', 'var2', 'е' COLLATE "C", 'е'::text); SELECT pgv_set_elem('pack', 'var2', 'ё' COLLATE "C", 'ё'::text); SELECT pgv_set_elem('pack', 'var2', 'ж' COLLATE "C", 'ж'::text); SELECT pgv_set_elem('pack', 'var2', 'я' COLLATE "C", 'я'::text); DO $$ DECLARE iter text; BEGIN iter := pgv_first('pack', 'var2', NULL::text); WHILE iter IS NOT NULL LOOP RAISE NOTICE '%', pgv_get_elem('pack', 'var2', iter, NULL::text); iter := pgv_next('pack', 'var2', iter); END LOOP; END; $$; NOTICE: а NOTICE: д NOTICE: е NOTICE: ж NOTICE: я NOTICE: ё
F.48.6. Authors #
Postgres Professional, Moscow, Russia