Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

document RETURNS TABLE, CTEs in routines #19351

Merged
merged 5 commits into from
Feb 7, 2025
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,5 @@
- Expressions (column, index, constraint) in tables. [#87699](https://github.com/cockroachdb/cockroach/issues/87699)
- Views. [#87699](https://github.com/cockroachdb/cockroach/issues/87699)
- 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)
- Casting subqueries to [user-defined types]({% link {{ page.version.version }}/create-type.md %}) in UDFs is not supported. [#108184](https://github.com/cockroachdb/cockroach/issues/108184)
58 changes: 51 additions & 7 deletions src/current/v25.1/create-function.md
Original file line number Diff line number Diff line change
Expand Up @@ -31,8 +31,8 @@ Parameter | Description
----------|------------
`routine_create_name` | The name of the function.
`routine_param` | A comma-separated list of function parameters, specifying the mode, name, and type.
`routine_return_type` | The type returned by the function.
`routine_body_str` | The body of the function. For allowed contents, see [User-Defined Functions]({% link {{ page.version.version }}/user-defined-functions.md %}#overview).
`routine_return_type` | The type returned by the function: any built-in [SQL type]({% link {{ page.version.version }}/data-types.md %}), user-defined [`ENUM`]({% link {{ page.version.version }}/enum.md %}) or [composite]({% link {{ page.version.version }}/create-type.md %}#create-a-composite-data-type) type, [`RECORD`](#create-a-function-that-returns-a-record-type), [`TABLE`](#create-a-function-that-returns-a-table), PL/pgSQL [`REFCURSOR`]({% link {{ page.version.version }}/plpgsql.md %}#declare-cursor-variables) type, [`TRIGGER`]({% link {{ page.version.version }}/triggers.md %}#trigger-function), or `VOID`.
`routine_body_str` | The body of the function. For allowed contents, refer to [User-Defined Functions]({% link {{ page.version.version }}/user-defined-functions.md %}#overview).

## Example of a simple function

Expand Down Expand Up @@ -143,6 +143,10 @@ SELECT total_euro_revenue();

The following statement defines a function that returns information for all vehicles not in use. The `SETOF` clause specifies that the function should return each row as the query executes to completion.

{{site.data.alerts.callout_success}}
[`RETURNS TABLE`](#create-a-function-that-returns-a-table) also returns a set of results, each formatted as a [`RECORD`](#create-a-function-that-returns-a-record-type) type.
{{site.data.alerts.end}}

{% include_cached copy-clipboard.html %}
~~~ sql
CREATE OR REPLACE FUNCTION available_vehicles() RETURNS SETOF vehicles LANGUAGE SQL AS $$
Expand All @@ -168,9 +172,9 @@ SELECT city,current_location,type FROM available_vehicles();

### Create a function that returns a `RECORD` type

The following statement defines a function that returns the information for the user that most recently completed a ride. The information is returned as a record, which takes the structure of the row that is retrieved by the selection query.
The following function returns the information for the user that most recently completed a ride. The information is returned as a record, which takes the structure of the row that is retrieved by the selection query.

In the function subquery, the latest `end_time` timestamp is used to determine the most recently completed ride.
In the function subquery, the latest `end_time` timestamp is used to determine the most recently completed ride:

{% include_cached copy-clipboard.html %}
~~~ sql
Expand All @@ -187,12 +191,52 @@ SELECT last_rider();
~~~

~~~
last_rider
----------------------------------------------------------------------------------------------------------
(70a3d70a-3d70-4400-8000-000000000016,seattle,"Mary Thomas","43322 Anthony Flats Suite 85",1141093639)
last_rider
-------------------------------------------------------------------------------------------------------------------
(147ae147-ae14-4b00-8000-000000000004,"new york","Isabel Clark DVM","98891 Timothy Cliffs Suite 39",4302568047)
(1 row)
~~~

### Create a function that returns a table

The following function returns information for the last `x` users that recently completed a ride. The information is returned as a table, which is equivalent to a set of [`RECORD` values](#create-a-function-that-returns-a-record-type). The rows are sorted in order of most recent ride.

The `RETURNS TABLE` clause specifies the column names to output: `id`, `name`, `city`, and `end_time`. A [common table expression]({% link {{ page.version.version }}/common-table-expressions.md %}) reads the most recent rides from the `rides` table.

{{site.data.alerts.callout_info}}
[`OUT` and `INOUT` parameters](#create-a-function-that-uses-out-and-inout-parameters) cannot be used with `RETURNS TABLE`.
{{site.data.alerts.end}}

{% include_cached copy-clipboard.html %}
~~~ sql
CREATE OR REPLACE FUNCTION last_x_riders(x INT) RETURNS TABLE(id UUID, name VARCHAR, city VARCHAR, end_time TIMESTAMP) LANGUAGE SQL AS $$
WITH recent_rides AS (
SELECT rider_id, end_time FROM rides
ORDER BY end_time DESC
)
SELECT u.id, u.name, u.city, r.end_time FROM users u, recent_rides r
WHERE u.id = r.rider_id
ORDER BY r.end_time DESC
LIMIT x
$$;
~~~

{% include_cached copy-clipboard.html %}
~~~ sql
SELECT * FROM last_x_riders(5);
~~~

~~~
id | name | city | end_time
---------------------------------------+------------------+---------------+----------------------
147ae147-ae14-4b00-8000-000000000004 | Isabel Clark DVM | new york | 2019-01-04 14:04:05
8f5c28f5-c28f-4000-8000-00000000001c | Patricia Sexton | los angeles | 2019-01-04 08:04:05
75c28f5c-28f5-4400-8000-000000000017 | Andre Wilson | san francisco | 2019-01-04 07:04:05
00000000-0000-4000-8000-000000000000 | William Martin | new york | 2019-01-04 04:04:05
d1eb851e-b851-4800-8000-000000000029 | Terry Reyes | paris | 2019-01-03 21:04:05
(5 rows)
~~~

### 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.
Expand Down
2 changes: 1 addition & 1 deletion src/current/v25.1/user-defined-functions.md
Original file line number Diff line number Diff line change
Expand Up @@ -16,7 +16,7 @@ The basic components of a user-defined function are a name, list of arguments, r
- An argument has a _mode_ and a _type_.
- CockroachDB supports the `IN` (default), `OUT`, and `INOUT` argument modes. For an example, see [Create a function that uses `OUT` and `INOUT` parameters]({% link {{ page.version.version }}/create-function.md %}#create-a-function-that-uses-out-and-inout-parameters).
- The type can be a built-in type, [user-defined `ENUM`]({% link {{ page.version.version }}/enum.md %}) or [composite]({% link {{ page.version.version }}/create-type.md %}#create-a-composite-data-type) type, or implicit record type. A type can have a `DEFAULT` value.
- The return type can be a built-in [SQL type]({% link {{ page.version.version }}/data-types.md %}), user-defined [`ENUM`]({% link {{ page.version.version }}/enum.md %}) or [composite]({% link {{ page.version.version }}/create-type.md %}#create-a-composite-data-type) type, [`RECORD`]({% link {{ page.version.version }}/create-function.md %}#create-a-function-that-returns-a-record-type), PL/pgSQL [`REFCURSOR`]({% link {{ page.version.version }}/plpgsql.md %}#declare-cursor-variables) type, implicit record type, [`TRIGGER`]({% link {{ page.version.version }}/triggers.md %}#trigger-function), or `VOID`.
- The return type can be a built-in [SQL type]({% link {{ page.version.version }}/data-types.md %}), user-defined [`ENUM`]({% link {{ page.version.version }}/enum.md %}) or [composite]({% link {{ page.version.version }}/create-type.md %}#create-a-composite-data-type) type, [`RECORD`]({% link {{ page.version.version }}/create-function.md %}#create-a-function-that-returns-a-record-type), [`TABLE`]({% link {{ page.version.version }}/create-function.md %}#create-a-function-that-returns-a-table), PL/pgSQL [`REFCURSOR`]({% link {{ page.version.version }}/plpgsql.md %}#declare-cursor-variables) type, implicit record type, [`TRIGGER`]({% link {{ page.version.version }}/triggers.md %}#trigger-function), or `VOID`.
- Preceding a type with `SETOF` indicates that a set, or multiple rows, may be returned. For an example, see [Create a function that returns a set of results]({% link {{ page.version.version }}/create-function.md %}#create-a-function-that-returns-a-set-of-results).
- `VOID` indicates that there is no return type and `NULL` will always be returned. {% comment %}If the return type of the function is not `VOID`, the last statement of a UDF must be a `SELECT`.{% endcomment %}
- The [volatility]({% link {{ page.version.version }}/functions-and-operators.md %}#function-volatility) indicates whether the function has side effects. `VOLATILE` and `NOT LEAKPROOF` are the default.
Expand Down
Loading