Skip to content

Commit

Permalink
updates to UDF, stored procs, and PL/pgSQL functionality (#18495)
Browse files Browse the repository at this point in the history
* 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
  • Loading branch information
taroface authored May 8, 2024
1 parent 79e6e45 commit 4cd0904
Show file tree
Hide file tree
Showing 11 changed files with 326 additions and 29 deletions.
Original file line number Diff line number Diff line change
@@ -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)
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -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 %}
Expand Down
1 change: 1 addition & 0 deletions src/current/_includes/v24.1/misc/session-vars.md
Original file line number Diff line number Diff line change
Expand Up @@ -51,6 +51,7 @@
| <a id="optimizer-use-lock-op-for-serializable"></a> `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 |
| <a id="optimizer-use-multicol-stats"></a> `optimizer_use_multicol_stats` | If `on`, the optimizer uses collected multi-column statistics for cardinality estimation. | `on` | No | Yes |
| <a id="optimizer-use-not-visible-indexes"></a> `optimizer_use_not_visible_indexes` | If `on`, the optimizer uses not visible indexes for planning. | `off` | No | Yes |
| <a id="plpgsql-use-strict-into"></a> `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 |
| <a id="pg_trgm_similarity_threshold"></a> `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 |
| <a id="prefer-lookup-joins-for-fks"></a> `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 |
| <a id="reorder-joins-limit"></a> `reorder_joins_limit` | Maximum number of joins that the optimizer will attempt to reorder when searching for an optimal query execution plan. <br/><br/>For more information, see [Join reordering]({% link {{ page.version.version }}/cost-based-optimizer.md %}#join-reordering). | `8` | Yes | Yes |
Expand Down
2 changes: 1 addition & 1 deletion src/current/v23.2/set-transaction.md
Original file line number Diff line number Diff line change
Expand Up @@ -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 %}
Expand Down
76 changes: 76 additions & 0 deletions src/current/v24.1/create-function.md
Original file line number Diff line number Diff line change
Expand Up @@ -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 %}
Expand Down
61 changes: 61 additions & 0 deletions src/current/v24.1/create-procedure.md
Original file line number Diff line number Diff line change
Expand Up @@ -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):
Expand Down
4 changes: 2 additions & 2 deletions src/current/v24.1/default-value.md
Original file line number Diff line number Diff line change
@@ -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
---
Expand All @@ -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
Expand Down
Loading

0 comments on commit 4cd0904

Please sign in to comment.