From 4cd09045eee95fbed4eb4ee3c39e6ea83503e682 Mon Sep 17 00:00:00 2001
From: Ryan Kuo <8740013+taroface@users.noreply.github.com>
Date: Wed, 8 May 2024 17:27:48 -0400
Subject: [PATCH] updates to UDF, stored procs, and PL/pgSQL functionality
(#18495)
* UDfs support DEFAULT values
* EXIT labels; WHEN conditions; minor rephrasing
* PL/pgSQL nested blocks
* OUT/INOUT params; routines calling routines
* add STRICT clause for SELECT INTO and RETURNING INTO
* explicit transactions within PL/pgSQL stored procs
* update feature limitations
---
.../plpgsql-feature-limitations.md | 10 +-
.../udf-stored-proc-limitations.md | 2 +-
.../_includes/v24.1/misc/session-vars.md | 1 +
src/current/v23.2/set-transaction.md | 2 +-
src/current/v24.1/create-function.md | 76 +++++++
src/current/v24.1/create-procedure.md | 61 ++++++
src/current/v24.1/default-value.md | 4 +-
src/current/v24.1/plpgsql.md | 190 ++++++++++++++++--
src/current/v24.1/set-transaction.md | 2 +-
src/current/v24.1/stored-procedures.md | 1 +
src/current/v24.1/user-defined-functions.md | 6 +-
11 files changed, 326 insertions(+), 29 deletions(-)
diff --git a/src/current/_includes/v24.1/known-limitations/plpgsql-feature-limitations.md b/src/current/_includes/v24.1/known-limitations/plpgsql-feature-limitations.md
index 076b86d0aa5..953bb475587 100644
--- a/src/current/_includes/v24.1/known-limitations/plpgsql-feature-limitations.md
+++ b/src/current/_includes/v24.1/known-limitations/plpgsql-feature-limitations.md
@@ -1,10 +1,8 @@
-- PL/pgSQL blocks cannot be nested. [#114775](https://github.com/cockroachdb/cockroach/issues/114775)
- PL/pgSQL arguments cannot be referenced with ordinals (e.g., `$1`, `$2`). [#114701](https://github.com/cockroachdb/cockroach/issues/114701)
-- `FOR` loops, including `FOR` cursor loops, `FOR` query loops, and `FOREACH` loops, are not supported. [#105246](https://github.com/cockroachdb/cockroach/issues/105246)
-- `RETURN NEXT` and `RETURN QUERY` statements are not supported. [#117744](https://github.com/cockroachdb/cockroach/issues/117744)
-- `EXIT` and `CONTINUE` labels and conditions are not supported. [#115271](https://github.com/cockroachdb/cockroach/issues/115271)
-- `CASE` statements are not supported. [#117744](https://github.com/cockroachdb/cockroach/issues/117744)
-- `PERFORM`, `EXECUTE`, `GET DIAGNOSTICS`, and `NULL` statements are not supported for PL/pgSQL. [#117744](https://github.com/cockroachdb/cockroach/issues/117744)
+- The following statements are not supported:
+ - `FOR` loops, including `FOR` cursor loops, `FOR` query loops, and `FOREACH` loops. [#105246](https://github.com/cockroachdb/cockroach/issues/105246)
+ - `RETURN NEXT` and `RETURN QUERY`. [#117744](https://github.com/cockroachdb/cockroach/issues/117744)
+ - `PERFORM`, `EXECUTE`, `GET DIAGNOSTICS`, and `CASE`. [#117744](https://github.com/cockroachdb/cockroach/issues/117744)
- PL/pgSQL exception blocks cannot catch [transaction retry errors]({% link {{ page.version.version }}/transaction-retry-error-reference.md %}). [#111446](https://github.com/cockroachdb/cockroach/issues/111446)
- `RAISE` statements cannot be annotated with names of schema objects related to the error (i.e., using `COLUMN`, `CONSTRAINT`, `DATATYPE`, `TABLE`, or `SCHEMA`). [#106237](https://github.com/cockroachdb/cockroach/issues/106237)
- `RAISE` statements message the client directly, and do not produce log output. [#117750](https://github.com/cockroachdb/cockroach/issues/117750)
diff --git a/src/current/_includes/v24.1/known-limitations/udf-stored-proc-limitations.md b/src/current/_includes/v24.1/known-limitations/udf-stored-proc-limitations.md
index 120ddc3b95f..0ff2a43cd90 100644
--- a/src/current/_includes/v24.1/known-limitations/udf-stored-proc-limitations.md
+++ b/src/current/_includes/v24.1/known-limitations/udf-stored-proc-limitations.md
@@ -2,7 +2,7 @@
- User-defined functions are not currently supported in:
- Expressions (column, index, constraint) in tables. [#87699](https://github.com/cockroachdb/cockroach/issues/87699)
- Views. [#87699](https://github.com/cockroachdb/cockroach/issues/87699)
- - Other user-defined functions. [#93049](https://github.com/cockroachdb/cockroach/issues/93049)
+- User-defined functions cannot call themselves recursively. [#93049](https://github.com/cockroachdb/cockroach/issues/93049)
- [Common table expressions]({% link {{ page.version.version }}/common-table-expressions.md %}) (CTE), recursive or non-recursive, are not supported in [user-defined functions]({% link {{ page.version.version }}/user-defined-functions.md %}) (UDF). That is, you cannot use a `WITH` clause in the body of a UDF. [#92961](https://github.com/cockroachdb/cockroach/issues/92961)
- The `setval` function cannot be resolved when used inside UDF bodies. [#110860](https://github.com/cockroachdb/cockroach/issues/110860)
{% endif %}
diff --git a/src/current/_includes/v24.1/misc/session-vars.md b/src/current/_includes/v24.1/misc/session-vars.md
index 4ba32c59e3e..a8be2430bcd 100644
--- a/src/current/_includes/v24.1/misc/session-vars.md
+++ b/src/current/_includes/v24.1/misc/session-vars.md
@@ -51,6 +51,7 @@
| `optimizer_use_lock_op_for_serializable` | If `on`, the optimizer uses a `Lock` operator to construct query plans for `SELECT` statements using the [`FOR UPDATE` and `FOR SHARE`]({% link {{ page.version.version }}/select-for-update.md %}) clauses. This setting only affects `SERIALIZABLE` transactions. `READ COMMITTED` transactions are evaluated with the `Lock` operator regardless of the setting. | `off` | Yes | Yes |
| `optimizer_use_multicol_stats` | If `on`, the optimizer uses collected multi-column statistics for cardinality estimation. | `on` | No | Yes |
| `optimizer_use_not_visible_indexes` | If `on`, the optimizer uses not visible indexes for planning. | `off` | No | Yes |
+| `plpgsql_use_strict_into` | If `on`, PL/pgSQL [`SELECT ... INTO` and `RETURNING ... INTO` statements]({% link {{ page.version.version }}/plpgsql.md %}#assign-a-result-to-a-variable) behave as though the `STRICT` option is specified. This causes the SQL statement to error if it does not return exactly one row. | `off` | Yes | Yes |
| `pg_trgm.similarity_threshold` | The threshold above which a [`%`]({% link {{ page.version.version }}/functions-and-operators.md %}#operators) string comparison returns `true`. The value must be between `0` and `1`. For more information, see [Trigram Indexes]({% link {{ page.version.version }}/trigram-indexes.md %}). | `0.3` | Yes | Yes |
| `prefer_lookup_joins_for_fks` | If `on`, the optimizer prefers [`lookup joins`]({% link {{ page.version.version }}/joins.md %}#lookup-joins) to [`merge joins`]({% link {{ page.version.version }}/joins.md %}#merge-joins) when performing [`foreign key`]({% link {{ page.version.version }}/foreign-key.md %}) checks. | `off` | Yes | Yes |
| `reorder_joins_limit` | Maximum number of joins that the optimizer will attempt to reorder when searching for an optimal query execution plan.
For more information, see [Join reordering]({% link {{ page.version.version }}/cost-based-optimizer.md %}#join-reordering). | `8` | Yes | Yes |
diff --git a/src/current/v23.2/set-transaction.md b/src/current/v23.2/set-transaction.md
index b957aefaa04..c7794ae9451 100644
--- a/src/current/v23.2/set-transaction.md
+++ b/src/current/v23.2/set-transaction.md
@@ -5,7 +5,7 @@ toc: true
docs_area: reference.sql
---
-The `SET TRANSACTION` [statement]({% link {{ page.version.version }}/sql-statements.md %}) sets the transaction priority, access mode, and "as of" timestamp after you [`BEGIN`]({% link {{ page.version.version }}/begin-transaction.md %}) it but before executing the first statement that manipulates a database.
+The `SET TRANSACTION` [statement]({% link {{ page.version.version }}/sql-statements.md %}) sets the transaction priority, access mode, "as of" timestamp, and isolation level. These are applied after you [`BEGIN`]({% link {{ page.version.version }}/begin-transaction.md %}) the transaction and before executing the first statement that manipulates a database.
{{site.data.alerts.callout_info}}
{% include {{ page.version.version }}/sql/use-the-default-transaction-priority.md %}
diff --git a/src/current/v24.1/create-function.md b/src/current/v24.1/create-function.md
index f88e368119d..11a00b5d8fc 100644
--- a/src/current/v24.1/create-function.md
+++ b/src/current/v24.1/create-function.md
@@ -194,6 +194,82 @@ SELECT last_rider();
(1 row)
~~~
+### Create a function that uses `OUT` and `INOUT` parameters
+
+The following statement uses a combination of `OUT` and `INOUT` parameters to modify a provided value and output the result. An `OUT` parameter returns a value, while an `INOUT` parameter passes an input value and returns a value.
+
+{% include_cached copy-clipboard.html %}
+~~~ sql
+CREATE OR REPLACE FUNCTION double_triple(INOUT double INT, OUT triple INT) AS
+ $$
+ BEGIN
+ double := double * 2;
+ triple := double * 3;
+ END;
+ $$ LANGUAGE PLpgSQL;
+~~~
+
+{% include_cached copy-clipboard.html %}
+~~~ sql
+SELECT double_triple(1);
+~~~
+
+~~~
+ double_triple
+-----------------
+ (2,6)
+~~~
+
+The `CREATE FUNCTION` statement does not need a `RETURN` statement because this is added implicitly for a function with `OUT` parameters:
+
+{% include_cached copy-clipboard.html %}
+~~~ sql
+SHOW CREATE FUNCTION double_triple;
+~~~
+
+~~~
+ function_name | create_statement
+----------------+---------------------------------------------------------------------------
+ double_triple | CREATE FUNCTION public.double_triple(INOUT double INT8, OUT triple INT8)
+ | RETURNS RECORD
+ | VOLATILE
+ | NOT LEAKPROOF
+ | CALLED ON NULL INPUT
+ | LANGUAGE plpgsql
+ | AS $$
+ | BEGIN
+ | double := double * 2;
+ | triple := double * 3;
+ | END;
+ | $$
+~~~
+
+### Create a function that invokes a function
+
+The following statement defines a function that invokes the [`double_triple` example function](#create-a-function-that-uses-out-and-inout-parameters).
+
+{% include_cached copy-clipboard.html %}
+~~~ sql
+CREATE OR REPLACE FUNCTION f(input_value INT)
+ RETURNS RECORD
+ AS $$
+ BEGIN
+ RETURN double_triple(input_value);
+ END;
+ $$ LANGUAGE PLpgSQL;
+~~~
+
+{% include_cached copy-clipboard.html %}
+~~~ sql
+SELECT f(1);
+~~~
+
+~~~
+ f
+---------
+ (2,6)
+~~~
+
### Create a function that uses a loop
{% include {{ page.version.version }}/sql/udf-plpgsql-example.md %}
diff --git a/src/current/v24.1/create-procedure.md b/src/current/v24.1/create-procedure.md
index 767ca831ed7..7bdf233dd02 100644
--- a/src/current/v24.1/create-procedure.md
+++ b/src/current/v24.1/create-procedure.md
@@ -68,6 +68,67 @@ NOTICE: (1,foo)
CALL
~~~
+### Create a stored procedure that uses `OUT` and `INOUT` parameters
+
+The following example uses a combination of `OUT` and `INOUT` parameters to modify a provided value and output the result. An `OUT` parameter returns a value, while an `INOUT` parameter passes an input value and returns a value.
+
+{% include_cached copy-clipboard.html %}
+~~~ sql
+CREATE OR REPLACE PROCEDURE double_triple(INOUT double INT, OUT triple INT) AS
+ $$
+ BEGIN
+ double := double * 2;
+ triple := double * 3;
+ END;
+ $$ LANGUAGE PLpgSQL;
+~~~
+
+When calling a procedure, you need to supply placeholder values for any `OUT` parameters. A `NULL` value is commonly used. When [calling a procedure from another routine](#create-a-stored-procedure-that-calls-a-procedure), you should declare variables that will store the results of the `OUT` parameters.
+
+{% include_cached copy-clipboard.html %}
+~~~ sql
+CALL double_triple(1, NULL);
+~~~
+
+~~~
+ double | triple
+---------+---------
+ 2 | 6
+~~~
+
+### Create a stored procedure that calls a procedure
+
+The following example defines a procedure that calls the [`double_triple` example procedure](#create-a-stored-procedure-that-uses-out-and-inout-parameters). The `triple_result` variable is assigned the result of the `OUT` parameter, while the `double_input` variable both provides the input and stores the result of the `INOUT` parameter.
+
+{{site.data.alerts.callout_info}}
+A procedure with `OUT` parameters can only be [called from a PL/pgSQL routine]({% link {{ page.version.version }}/plpgsql.md %}#call-a-procedure).
+{{site.data.alerts.end}}
+
+{% include_cached copy-clipboard.html %}
+~~~ sql
+CREATE OR REPLACE PROCEDURE p(double_input INT) AS
+ $$
+ DECLARE
+ triple_result INT;
+ BEGIN
+ CALL double_triple(double_input, triple_result);
+ RAISE NOTICE 'Doubled value: %', double_input;
+ RAISE NOTICE 'Tripled value: %', triple_result;
+ END
+ $$ LANGUAGE PLpgSQL;
+~~~
+
+{% include_cached copy-clipboard.html %}
+~~~ sql
+CALL p(1);
+~~~
+
+~~~
+NOTICE: Doubled value: 2
+NOTICE: Tripled value: 6
+CALL
+~~~
+
### Create a stored procedure that uses conditional logic
The following example uses [PL/pgSQL conditional statements]({% link {{ page.version.version }}/plpgsql.md %}#write-conditional-statements):
diff --git a/src/current/v24.1/default-value.md b/src/current/v24.1/default-value.md
index fbb7fb2db08..61cdbed5a66 100644
--- a/src/current/v24.1/default-value.md
+++ b/src/current/v24.1/default-value.md
@@ -1,6 +1,6 @@
---
title: Default Value Constraint
-summary: The Default Value constraint specifies a value to populate a column with if none is provided.
+summary: The DEFAULT constraint specifies a value to populate a column with if none is provided.
toc: true
docs_area: reference.sql
---
@@ -9,7 +9,7 @@ The `DEFAULT` value [constraint]({% link {{ page.version.version }}/constraints.
## Details
-- The [data type]({% link {{ page.version.version }}/data-types.md %}) of the Default Value must be the same as the data type of the column.
+- The [data type]({% link {{ page.version.version }}/data-types.md %}) of the `DEFAULT` value must be the same as the data type of the column.
- The `DEFAULT` value constraint only applies if the column does not have a value specified in the [`INSERT`]({% link {{ page.version.version }}/insert.md %}) statement. You can still insert a `NULL` into an optional (nullable) column by explicitly inserting `NULL`. For example, `INSERT INTO foo VALUES (1, NULL);`.
## Syntax
diff --git a/src/current/v24.1/plpgsql.md b/src/current/v24.1/plpgsql.md
index 82b1b176f0d..3985eed1480 100644
--- a/src/current/v24.1/plpgsql.md
+++ b/src/current/v24.1/plpgsql.md
@@ -40,6 +40,23 @@ At the highest level, a PL/pgSQL block looks like the following:
END
~~~
+PL/pgSQL blocks can be nested. An optional label can be placed above each block. Block labels can be targeted by [`EXIT` statements](#exit-and-continue-statements).
+
+~~~ sql
+[ <> ]
+ [ DECLARE
+ declarations ]
+ BEGIN
+ statements
+ [ <> ]
+ [ DECLARE
+ declarations ]
+ BEGIN
+ statements
+ END;
+ END
+~~~
+
When you create a function or procedure, you can enclose the entire PL/pgSQL block in dollar quotes (`$$`). Dollar quotes are not required, but are easier to use than single quotes, which require that you escape other single quotes that are within the function or procedure body.
{% include_cached copy-clipboard.html %}
@@ -61,8 +78,7 @@ For complete examples, see [Create a user-defined function using PL/pgSQL](#crea
### Declare a variable
-`DECLARE` specifies all variable definitions that are used in the function or procedure body.
-
+`DECLARE` specifies all variable definitions that are used in a block.
~~~ sql
DECLARE
variable_name [ CONSTANT ] data_type [ := expression ];
@@ -71,7 +87,7 @@ DECLARE
- `variable_name` is an arbitrary variable name.
- `data_type` can be a supported [SQL data type]({% link {{ page.version.version }}/data-types.md %}), [user-defined type]({% link {{ page.version.version }}/create-type.md %}), or the PL/pgSQL `REFCURSOR` type, when declaring [cursor](#declare-cursor-variables) variables.
- `CONSTANT` specifies that the variable cannot be [reassigned](#assign-a-result-to-a-variable), ensuring that its value remains constant within the block.
-- `expression` is an [expression](https://www.postgresql.org/docs/16/plpgsql-expressions.html) that provides an optional default value for the variable.
+- `expression` is an [expression](https://www.postgresql.org/docs/16/plpgsql-expressions.html) that provides an optional default value for the variable. Default values are evaluated every time a block is entered in a function or procedure.
For example:
@@ -105,14 +121,14 @@ For information about opening and using cursors, see [Open and use cursors](#ope
### Assign a result to a variable
-Use the PL/pgSQL `INTO` clause to assign a result of a [`SELECT`]({% link {{ page.version.version }}/select-clause.md %}) or mutation ([`INSERT`]({% link {{ page.version.version }}/insert.md %}), [`UPDATE`]({% link {{ page.version.version }}/update.md %}), [`DELETE`]({% link {{ page.version.version }}/delete.md %})) statement to a specified variable:
+Use the PL/pgSQL `INTO` clause to assign a result of a [`SELECT`]({% link {{ page.version.version }}/select-clause.md %}) or mutation ([`INSERT`]({% link {{ page.version.version }}/insert.md %}), [`UPDATE`]({% link {{ page.version.version }}/update.md %}), [`DELETE`]({% link {{ page.version.version }}/delete.md %})) statement to a specified variable. The optional `STRICT` clause specifies that the statement must return exactly one row; otherwise, the function or procedure will error. This behavior can be enabled by default using the [`plpgsql_use_strict_into`]({% link {{ page.version.version }}/session-variables.md %}#plpgsql-use-strict-into) session setting.
~~~ sql
-SELECT expression INTO target FROM ...;
+SELECT expression INTO [ STRICT ] target FROM ...;
~~~
~~~ sql
-[ INSERT | UPDATE | DELETE ] ... RETURNING expression INTO target;
+[ INSERT | UPDATE | DELETE ] ... RETURNING expression INTO [ STRICT ] target;
~~~
- `expression` is an [expression](https://www.postgresql.org/docs/16/plpgsql-expressions.html) that defines the result to be assigned to the variable.
@@ -146,7 +162,7 @@ NOTICE: New Row: 2
CALL
~~~
-The following [user-defined function]({% link {{ page.version.version }}/user-defined-functions.md %}) uses the `max()` [built-in function]({% link {{ page.version.version }}/functions-and-operators.md %}#aggregate-functions) to find the maximum `col` value in table `t`, and assigns the result to `i`.
+The following [user-defined function]({% link {{ page.version.version }}/user-defined-functions.md %}) uses the `max` [built-in function]({% link {{ page.version.version }}/functions-and-operators.md %}#aggregate-functions) to find the maximum `col` value in table `t`, and assigns the result to `i`.
{% include_cached copy-clipboard.html %}
~~~ sql
@@ -218,7 +234,7 @@ For usage examples of conditional statements, see [Examples](#examples).
### Write loops
-Use looping syntax to repeatedly execute statements.
+Write a loop to repeatedly execute statements.
On its own, `LOOP` executes statements infinitely.
@@ -238,25 +254,59 @@ WHILE condition LOOP
For an example, see [Create a stored procedure that uses a `WHILE` loop]({% link {{ page.version.version }}/create-procedure.md %}#create-a-stored-procedure-that-uses-a-while-loop).
-Add an `EXIT` statement to end a `LOOP` or `WHILE` statement block. This should be combined with a [conditional statement](#write-conditional-statements).
+### `EXIT` and `CONTINUE` statements
+
+Add an `EXIT` statement to end a [loop](#write-loops). An `EXIT` statement can be combined with an optional `WHEN` boolean condition.
~~~ sql
LOOP
statements;
- IF condition THEN
- EXIT;
- END IF;
+ EXIT [ WHEN condition ];
END LOOP;
~~~
-Add a `CONTINUE` statement to end a `LOOP` or `WHILE` statement block, skipping any statements below `CONTINUE`, and begin the next iteration of the loop. This should be combined with a [conditional statement](#write-conditional-statements). In the following example, if the `IF` condition is met, then `CONTINUE` causes the loop to skip the second block of statements and begin again.
+Add a label to an `EXIT` statement to target a block that has a matching label. An `EXIT` statement with a label can target either a loop or a [block](#structure). An `EXIT` statement inside a block must have a label.
+
+The following `EXIT` statement will end the `label` block before the statements are executed.
+
+~~~ sql
+BEGIN
+ <