Skip to content

Commit

Permalink
DO blocks (#19356)
Browse files Browse the repository at this point in the history
* DO blocks
  • Loading branch information
taroface authored Feb 12, 2025
1 parent ce4ff82 commit 59fa4ff
Show file tree
Hide file tree
Showing 4 changed files with 114 additions and 3 deletions.
6 changes: 6 additions & 0 deletions src/current/_includes/v25.1/sidebar-data/sql.json
Original file line number Diff line number Diff line change
Expand Up @@ -298,6 +298,12 @@
"/${VERSION}/delete.html"
]
},
{
"title": "<code>DO</code>",
"urls": [
"/${VERSION}/do.html"
]
},
{
"title": "<code>DROP DATABASE</code>",
"urls": [
Expand Down
106 changes: 106 additions & 0 deletions src/current/v25.1/do.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,106 @@
---
title: DO
summary: The DO SQL statement executes a PL/pgSQL code block.
toc: true
keywords:
docs_area: reference.sql
---

The `DO` [statement]({% link {{ page.version.version }}/sql-statements.md %}) defines a code block that executes [PL/pgSQL]({% link {{ page.version.version }}/plpgsql.md %}) syntax.

## Required privileges

- To define a `DO` block with a [user-defined type]({% link {{ page.version.version }}/create-type.md %}), a user must have `USAGE` privilege on the user-defined type.

## Synopsis

<div>
{% remote_include https://raw.githubusercontent.com/cockroachdb/generated-diagrams/{{ page.release_info.crdb_branch_name }}/grammar_svg/do.html %}
</div>

## Parameters

| Parameter | Description |
|--------------------|-----------------------------|
| `routine_body_str` | The body of the code block. |

## Examples

### Declare a variable in a `DO` block

The following example uses the [PL/pgSQL `DECLARE` syntax]({% link {{ page.version.version }}/plpgsql.md %}#declare-a-variable) to declare variables to use in the code block.

{% include_cached copy-clipboard.html %}
~~~ sql
DO $$
DECLARE
x INT := 10;
y INT := 5;
result INT;
BEGIN
result := x + y;
RAISE NOTICE 'The sum of % and % is %', x, y, result;
END $$;
~~~

~~~
NOTICE: The sum of 10 and 5 is 15
DO
~~~

### Use a loop in a `DO` block

The following example uses the [PL/pgSQL `WHILE` syntax]({% link {{ page.version.version }}/plpgsql.md %}#write-loops) to loop through several statements.

{% include_cached copy-clipboard.html %}
~~~ sql
DO $$
DECLARE
counter INT := 1;
BEGIN
WHILE counter <= 5 LOOP
RAISE NOTICE 'Counter: %', counter;
counter := counter + 1;
END LOOP;
END $$;
~~~

~~~
NOTICE: Counter: 1
NOTICE: Counter: 2
NOTICE: Counter: 3
NOTICE: Counter: 4
NOTICE: Counter: 5
DO
~~~

### Use a common table expression in a `DO` block

The following example uses a [common table expression]({% link {{ page.version.version }}/common-table-expressions.md %}) in the body of the code block.

{% include_cached copy-clipboard.html %}
~~~ sql
DO $$
DECLARE
sum_result INT;
BEGIN
WITH numbers AS (
SELECT generate_series(1, 5) AS num
)
SELECT sum(num) INTO sum_result
FROM numbers;

RAISE NOTICE 'Sum of numbers 1-5: %', sum_result;
END $$;
~~~

~~~
NOTICE: Sum of numbers 1-5: 15
DO
~~~

## See also

- [PL/pgSQL]({% link {{ page.version.version }}/plpgsql.md %})
- [Stored Procedures]({% link {{ page.version.version }}/stored-procedures.md %})
- [User-Defined Functions]({% link {{ page.version.version }}/user-defined-functions.md %})
4 changes: 1 addition & 3 deletions src/current/v25.1/plpgsql.md
Original file line number Diff line number Diff line change
Expand Up @@ -5,9 +5,7 @@ toc: true
docs_area: reference.sql
---



[PL/pgSQL](https://www.postgresql.org/docs/16/plpgsql-overview.html) is a procedural language that you can use within [user-defined functions]({% link {{ page.version.version }}/user-defined-functions.md %}) and [stored procedures]({% link {{ page.version.version }}/stored-procedures.md %}) in CockroachDB.
[PL/pgSQL](https://www.postgresql.org/docs/16/plpgsql-overview.html) is a procedural language that you can use within [user-defined functions]({% link {{ page.version.version }}/user-defined-functions.md %}), [stored procedures]({% link {{ page.version.version }}/stored-procedures.md %}), and [`DO`]({% link {{ page.version.version }}/do.md %}) blocks in CockroachDB.

In contrast to [SQL statements]({% link {{ page.version.version }}/sql-statements.md %}), which are issued one-by-one from the client to the database, PL/pgSQL statements are encapsulated in a [block structure](#structure) and executed on the database side, thus reducing network latency. PL/pgSQL enables more complex functionality than standard SQL, including [conditional statements](#write-conditional-statements), [loops](#write-loops), and [exception handling](#report-messages-and-handle-exceptions).

Expand Down
1 change: 1 addition & 0 deletions src/current/v25.1/sql-statements.md
Original file line number Diff line number Diff line change
Expand Up @@ -79,6 +79,7 @@ Statement | Usage
[`CREATE TABLE AS`]({% link {{ page.version.version }}/create-table-as.md %}) | Create a new table in a database using the results from a [selection query]({% link {{ page.version.version }}/selection-queries.md %}).
[`COPY FROM`]({% link {{ page.version.version }}/copy.md %}) | Copy data from a third-party client to a CockroachDB cluster.<br>For compatibility with PostgreSQL drivers and ORMs, CockroachDB supports `COPY FROM` statements issued from third-party clients. To import data from files, use an [`IMPORT INTO`]({% link {{ page.version.version }}/import-into.md %}) statement instead.
[`DELETE`]({% link {{ page.version.version }}/delete.md %}) | Delete specific rows from a table.
[`DO`]({% link {{ page.version.version }}/do.md %}) | Execute a [PL/pgSQL]({% link {{ page.version.version }}/plpgsql.md %}) code block.
[`EXPORT`]({% link {{ page.version.version }}/export.md %}) | Export an entire table's data, or the results of a `SELECT` statement, to CSV files.
[`IMPORT INTO`]({% link {{ page.version.version }}/import-into.md %}) | Bulk-insert CSV data into an existing table.
[`INSERT`]({% link {{ page.version.version }}/insert.md %}) | Insert rows into a table.
Expand Down

0 comments on commit 59fa4ff

Please sign in to comment.