Skip to content

Commit

Permalink
Triggers docs, syntax, limitations (#19129)
Browse files Browse the repository at this point in the history
* Triggers docs, syntax, limitations

---------

Co-authored-by: Florence Morris <[email protected]>
  • Loading branch information
taroface and florence-crl authored Nov 14, 2024
1 parent 7d297eb commit b93b0b9
Show file tree
Hide file tree
Showing 13 changed files with 837 additions and 5 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
[`DROP TRIGGER`]({% link {{ page.version.version }}/drop-trigger.md %}) with `CASCADE` is not supported. [#128151](https://github.com/cockroachdb/cockroach/issues/128151)
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
- A [trigger function]({% link {{ page.version.version }}/triggers.md %}#trigger-function) that is used in an existing trigger cannot be replaced with `CREATE OR REPLACE` syntax. To use `CREATE OR REPLACE`, first [drop any triggers]({% link {{ page.version.version }}/drop-trigger.md %}) that are using the function. [#134555](https://github.com/cockroachdb/cockroach/issues/134555)
- Hidden columns are not visible to triggers. [#133331](https://github.com/cockroachdb/cockroach/issues/133331)
- {% include {{ page.version.version }}/known-limitations/drop-trigger-limitations.md %}
18 changes: 18 additions & 0 deletions src/current/_includes/v24.3/sidebar-data/sql.json
Original file line number Diff line number Diff line change
Expand Up @@ -256,6 +256,12 @@
"/${VERSION}/create-table-as.html"
]
},
{
"title": "<code>CREATE TRIGGER</code>",
"urls": [
"/${VERSION}/create-trigger.html"
]
},
{
"title": "<code>CREATE TYPE</code>",
"urls": [
Expand Down Expand Up @@ -310,6 +316,12 @@
"/${VERSION}/drop-owned-by.html"
]
},
{
"title": "<code>DROP TRIGGER</code>",
"urls": [
"/${VERSION}/drop-trigger.html"
]
},
{
"title": "<code>DROP TYPE</code>",
"urls": [
Expand Down Expand Up @@ -873,6 +885,12 @@
"/${VERSION}/stored-procedures.html"
]
},
{
"title": "Triggers",
"urls": [
"/${VERSION}/triggers.html"
]
},
{
"title": "Window Functions",
"urls": [
Expand Down
Original file line number Diff line number Diff line change
@@ -1,4 +1,3 @@
- Triggers. These must be implemented in your application logic.
- Events.
- Drop primary key.

Expand Down
4 changes: 4 additions & 0 deletions src/current/v24.3/cockroachdb-feature-availability.md
Original file line number Diff line number Diff line change
Expand Up @@ -47,6 +47,10 @@ Any feature made available in a phase prior to GA is provided without any warran
**The following features are in preview** and are subject to change. To share feedback and/or issues, contact [Support](https://support.cockroachlabs.com/hc).
{{site.data.alerts.end}}

### Triggers

[Triggers]({% link {{ page.version.version }}/triggers.md %}) are in Preview. A trigger executes a function when one or more specified SQL operations is performed on a table. Triggers respond to data changes by adding logic within the database, rather than in an application. They can be used to modify data before it is inserted, maintain data consistency across rows or tables, or record an update to a row.

### Admission control for ingesting snapshots

The [cluster setting]({% link {{ page.version.version }}/cluster-settings.md %}) `kvadmission.store.snapshot_ingest_bandwidth_control.enabled` is in Preview. When configured, it limits the disk impact of ingesting snapshots on a node.
Expand Down
17 changes: 17 additions & 0 deletions src/current/v24.3/create-function.md
Original file line number Diff line number Diff line change
Expand Up @@ -273,6 +273,23 @@ SELECT f(1);

{% include {{ page.version.version }}/sql/udf-plpgsql-example.md %}

### Create a trigger function

A trigger function is a [function that is executed by a trigger]({% link {{ page.version.version }}/triggers.md %}#trigger-function). A trigger function must return type `TRIGGER` and is written in [PL/pgSQL]({% link {{ page.version.version }}/plpgsql.md %}).

{% include_cached copy-clipboard.html %}
~~~ sql
CREATE OR REPLACE FUNCTION change_name()
RETURNS TRIGGER AS $$
BEGIN
NEW.name = 'Dear ' || (NEW).name;
RETURN NEW;
END;
$$ LANGUAGE PLpgSQL;
~~~

The preceding example modifies a given `name` value and returns the `NEW` [trigger variable]({% link {{ page.version.version }}/triggers.md %}#trigger-variables) because it is meant to be executed by a `BEFORE` trigger. For details, refer to [Triggers]({% link {{ page.version.version }}/triggers.md %}).

### Create a `SECURITY DEFINER` function

The following example defines a function using the `SECURITY DEFINER` clause. This causes the function to execute with the privileges of the function owner.
Expand Down
190 changes: 190 additions & 0 deletions src/current/v24.3/create-trigger.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,190 @@
---
title: CREATE TRIGGER
summary: The CREATE TRIGGER statement creates a trigger on a specified table.
toc: true
keywords:
docs_area: reference.sql
---

The `CREATE TRIGGER` [statement]({% link {{ page.version.version }}/sql-statements.md %}) defines a [trigger]({% link {{ page.version.version }}/triggers.md %}) on a specified table.

## Required privileges

To create a trigger, a user must have [`CREATE` privilege]({% link {{ page.version.version }}/security-reference/authorization.md %}#supported-privileges) on the schema of the trigger.

## Synopsis

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

## Parameters

| Parameter | Description |
|-----------------------|-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------|
| `trigger_create_name` | The name of the trigger. |
| `table_name` | The name of the table associated with the trigger. |
| `func_name` | The [trigger function]({% link {{ page.version.version }}/triggers.md %}#trigger-function) that is executed when the trigger activates. |
| `a_expr` | Boolean condition that determines if the trigger function should execute for a given row. For details, refer to [Trigger conditions]({% link {{ page.version.version }}/triggers.md %}#trigger-conditions). |
| `trigger_func_args` | A comma-separated list of constant string arguments. |

## Examples

The following are examples of basic triggers. For more detailed examples of trigger usage, see [Triggers]({% link {{ page.version.version }}/triggers.md %}#examples).

### Create a `BEFORE` trigger

Create a sample table:

{% include_cached copy-clipboard.html %}
~~~ sql
CREATE TABLE lock_table (
id INT PRIMARY KEY,
name TEXT NOT NULL,
is_locked BOOLEAN DEFAULT FALSE
);
~~~

Populate `lock_table` with sample values:

{% include_cached copy-clipboard.html %}
~~~ sql
INSERT INTO lock_table VALUES (1, 'Record 1', FALSE);
INSERT INTO lock_table VALUES (2, 'Record 2', TRUE);
~~~

Create a [trigger function]({% link {{ page.version.version }}/triggers.md %}#trigger-function) that prevents "locked" rows from being deleted:

{% include_cached copy-clipboard.html %}
~~~ sql
CREATE OR REPLACE FUNCTION prevent_delete_locked()
RETURNS TRIGGER AS $$
BEGIN
IF (OLD).is_locked THEN
RAISE EXCEPTION 'Record is locked and cannot be deleted';
END IF;
RETURN OLD;
END;
$$ LANGUAGE PLpgSQL;
~~~

Create a trigger that executes `prevent_delete_locked` before a `DELETE` is issued on `lock_table`:

{% include_cached copy-clipboard.html %}
~~~ sql
CREATE TRIGGER prevent_locked_delete
BEFORE DELETE ON lock_table
FOR EACH ROW
EXECUTE FUNCTION prevent_delete_locked();
~~~

Test the trigger by attempting to delete a row:

{% include_cached copy-clipboard.html %}
~~~ sql
DELETE FROM lock_table WHERE id = 2;
~~~

~~~
ERROR: Record is locked and cannot be deleted
SQLSTATE: P0001
~~~

View `lock_table` to verify that the row was not deleted:

{% include_cached copy-clipboard.html %}
~~~ sql
SELECT * FROM lock_table;
~~~

~~~
id | name | is_locked
-----+----------+------------
1 | Record 1 | f
2 | Record 2 | t
(2 rows)
~~~

### Create an `AFTER` trigger

Create two sample tables. `stock` contains a product inventory, and `orders_placed` contains a list of orders on those products:

{% include_cached copy-clipboard.html %}
~~~ sql
CREATE TABLE stock (
"product_id" STRING PRIMARY KEY,
"quantity_on_hand" INTEGER NOT NULL DEFAULT 1
);
~~~

{% include_cached copy-clipboard.html %}
~~~ sql
CREATE TABLE orders_placed (
"product_id" STRING NOT NULL REFERENCES stock ("product_id"),
"quantity" INTEGER NOT NULL DEFAULT 1
);
~~~

Populate `stock` with three products each at `1000` count:

{% include_cached copy-clipboard.html %}
~~~ sql
INSERT INTO stock ("product_id", "quantity_on_hand") VALUES ('a', 1000), ('b', 1000), ('c', 1000);
~~~

Create a [trigger function]({% link {{ page.version.version }}/triggers.md %}#trigger-function) that updates the `stock` table to reflect the quantity on hand after each order that is placed:

{% include_cached copy-clipboard.html %}
~~~ sql
CREATE OR REPLACE FUNCTION update_stock_after_order()
RETURNS TRIGGER
AS $$
BEGIN
UPDATE stock
SET quantity_on_hand = quantity_on_hand - (NEW).quantity
WHERE stock.product_id = (NEW).product_id;
RETURN NULL;
END;
$$ LANGUAGE PLpgSQL;
~~~

Create a trigger that executes `update_stock_after_order` after an `INSERT` is issued on `orders_placed` (i.e., an order is placed):

{% include_cached copy-clipboard.html %}
~~~ sql
CREATE TRIGGER trg_update_stock_after_order
AFTER INSERT ON orders_placed
FOR EACH ROW
EXECUTE FUNCTION update_stock_after_order();
~~~

Test the trigger by inserting some sample orders:

{% include_cached copy-clipboard.html %}
~~~ sql
INSERT INTO orders_placed (product_id, quantity) VALUES ('a', 1), ('b', 3);
~~~

View the `stock` table to see that the quantities have decreased accordingly:

{% include_cached copy-clipboard.html %}
~~~ sql
SELECT * FROM stock;
~~~

~~~
product_id | quantity_on_hand
-------------+-------------------
a | 999
b | 997
c | 1000
(3 rows)
~~~

## See also

- [Triggers]({% link {{ page.version.version }}/triggers.md %})
- [`DROP TRIGGER`]({% link {{ page.version.version }}/drop-trigger.md %})
- [User-defined functions]({% link {{ page.version.version }}/user-defined-functions.md %})
- [`CREATE FUNCTION`]({% link {{ page.version.version }}/create-function.md %})
- [PL/pgSQL]({% link {{ page.version.version }}/plpgsql.md %})
72 changes: 72 additions & 0 deletions src/current/v24.3/drop-trigger.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,72 @@
---
title: DROP TRIGGER
summary: The DROP TRIGGER statement drops a trigger for a specified table.
toc: true
keywords:
docs_area: reference.sql
---

The `DROP TRIGGER` [statement]({% link {{ page.version.version }}/sql-statements.md %}) drops a [trigger]({% link {{ page.version.version }}/triggers.md %}).

## Required privileges

To drop a trigger, a user must have the `DROP` [privilege]({% link {{ page.version.version }}/security-reference/authorization.md %}#managing-privileges) on the trigger.

## Synopsis

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

## Parameters

| Parameter | Description |
|----------------|----------------------------------------------------|
| `trigger_name` | The name of the trigger to drop. |
| `table_name` | The name of the table associated with the trigger. |

## Examples

{% include {{page.version.version}}/sql/movr-statements.md %}

### Drop a trigger

Create a sample trigger function:

{% include_cached copy-clipboard.html %}
~~~ sql
CREATE FUNCTION update_timestamp()
RETURNS TRIGGER AS $$
BEGIN
RAISE NOTICE 'Current timestamp: %', now();
RETURN NEW;
END;
$$ LANGUAGE PLpgSQL;
~~~

Create a sample trigger:

{% include_cached copy-clipboard.html %}
~~~ sql
CREATE TRIGGER log_update_timestamp
AFTER UPDATE ON users
FOR EACH ROW
EXECUTE FUNCTION update_timestamp();
~~~

Drop the trigger:

{% include_cached copy-clipboard.html %}
~~~ sql
DROP TRIGGER log_update_timestamp ON users;
~~~

## Known limitations

{% include {{ page.version.version }}/known-limitations/drop-trigger-limitations.md %}

## See also

- [Triggers]({% link {{ page.version.version }}/triggers.md %})
- [`CREATE TRIGGER`]({% link {{ page.version.version }}/create-trigger.md %})
- [`CREATE FUNCTION`]({% link {{ page.version.version }}/create-function.md %})
8 changes: 6 additions & 2 deletions src/current/v24.3/known-limitations.md
Original file line number Diff line number Diff line change
Expand Up @@ -12,9 +12,13 @@ docs_area: releases

This section describes newly identified limitations in CockroachDB {{ page.version.version }}.

{{site.data.alerts.callout_info}}
### Triggers

{% include {{ page.version.version }}/known-limitations/trigger-limitations.md %}

{% comment %}{{site.data.alerts.callout_info}}
Limitations will be added as they are discovered.
{{site.data.alerts.end}}
{{site.data.alerts.end}}{% endcomment %}

### Logical data replication (LDR)

Expand Down
2 changes: 2 additions & 0 deletions src/current/v24.3/sql-statements.md
Original file line number Diff line number Diff line change
Expand Up @@ -34,6 +34,7 @@ Statement | Usage
[`CREATE SEQUENCE`]({% link {{ page.version.version }}/create-sequence.md %}) | Create a new sequence.
[`CREATE TABLE`]({% link {{ page.version.version }}/create-table.md %}) | Create a new table in a database.
[`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 %}).
[`CREATE TRIGGER`]({% link {{ page.version.version }}/create-trigger.md %}) | Create a new [trigger]({% link {{ page.version.version }}/triggers.md %}) on a specified table.
[`CREATE TYPE`]({% link {{ page.version.version }}/create-type.md %}) | Create a user-defined, [enumerated data type]({% link {{ page.version.version }}/enum.md %}).
[`CREATE VIEW`]({% link {{ page.version.version }}/create-view.md %}) | Create a new [view]({% link {{ page.version.version }}/views.md %}) in a database.
[`DROP DATABASE`]({% link {{ page.version.version }}/drop-database.md %}) | Remove a database and all its objects.
Expand All @@ -43,6 +44,7 @@ Statement | Usage
[`DROP SCHEMA`]({% link {{ page.version.version }}/drop-schema.md %}) | Drop a user-defined schema.
[`DROP SEQUENCE`]({% link {{ page.version.version }}/drop-sequence.md %}) | Remove a sequence.
[`DROP TABLE`]({% link {{ page.version.version }}/drop-table.md %}) | Remove a table.
[`DROP TRIGGER`]({% link {{ page.version.version }}/drop-trigger.md %}) | Remove a [trigger]({% link {{ page.version.version }}/triggers.md %}).
[`DROP TYPE`]({% link {{ page.version.version }}/drop-type.md %}) | Remove a user-defined, [enumerated data type]({% link {{ page.version.version }}/enum.md %}).
[`DROP VIEW`]({% link {{ page.version.version }}/drop-view.md %})| Remove a view.
[`REFRESH`]({% link {{ page.version.version }}/refresh.md %}) | Refresh the stored query results of a [materialized view]({% link {{ page.version.version }}/views.md %}#materialized-views).
Expand Down
3 changes: 2 additions & 1 deletion src/current/v24.3/string.md
Original file line number Diff line number Diff line change
Expand Up @@ -23,8 +23,9 @@ For PostgreSQL compatibility, CockroachDB supports the following `STRING`-relate

- `VARCHAR` (and alias `CHARACTER VARYING`)
- `CHAR` (and alias `CHARACTER`)
- `NAME`

These types are functionality identical to `STRING`.
These types are functionally identical to `STRING`.

CockroachDB also supports the single-byte `"char"` special character type. As in PostgreSQL, this special type is intended for internal use in [system catalogs]({% link {{ page.version.version }}/system-catalogs.md %}), and has a storage size of 1 byte. CockroachDB truncates all values of type `"char"` to a single character.

Expand Down
Loading

0 comments on commit b93b0b9

Please sign in to comment.