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

plpgsql: enable catching retryable errors in exception blocks #111446

Open
DrewKimball opened this issue Sep 28, 2023 · 1 comment
Open

plpgsql: enable catching retryable errors in exception blocks #111446

DrewKimball opened this issue Sep 28, 2023 · 1 comment
Labels
A-sql-udf C-enhancement Solution expected to add code/behavior + preserve backward-compat (pg compat issues are exception) docs-known-limitation T-sql-queries SQL Queries Team

Comments

@DrewKimball
Copy link
Collaborator

DrewKimball commented Sep 28, 2023

It is possible to catch and handle arbitrary errors within a routine using a PLpgSQL exception block. Once an error is caught, any changes to database state that occurred within the exception block are rolled back, although the most recent values for the PLpgSQL variables are kept. The rollback behavior for exception handling is implemented in #110998, but for 23.2 we will disable catching Transaction Retry (40001, 40003) errors because they leave the transaction in a poisoned state that prevents rolling back to a previously created savepoint.

This issue tracks adding support for catching Transaction Retry errors. The read-committed retry loop is able to revert the transaction to a state where savepoint rollback is valid in some cases using txn.PrepareForPartialRetry. We will likely do something similar for routine exception handling. Note that some errors can leave the transaction in a state where it must be restarted completely; we will have to find a user-friendly way to handle these cases.

Jira issue: CRDB-31899

@DrewKimball DrewKimball added the C-enhancement Solution expected to add code/behavior + preserve backward-compat (pg compat issues are exception) label Sep 28, 2023
DrewKimball added a commit to DrewKimball/cockroach that referenced this issue Sep 29, 2023
When an exception occurs within the EXCEPTION block of a PLpgSQL routine,
all changes to database state are rolled back, but the updated values for
the variables are still visible to the exception handler. For example:
```
CREATE FUNCTION f() RETURNS INT AS $$
  DECLARE
    i INT;
  BEGIN
    INSERT INTO xy VALUES (-100, -100);
    i := 100;
    RETURN 1 // 0;
  EXCEPTION WHEN division_by_zero THEN
    RETURN i;
  END
$$ LANGUAGE PLpgSQL;
```
The above function would not modify `xy`, since the exception would
revert the insert. However, the function would return `100`, since the
variable assignment occurred before the error was thrown.

This patch implements the required rollback behavior through internal
savepoints; when the top-level routine of a PLpgSQL block begins
executing, it creates a savepoint (if it has an exception handler).
When the exception handler catches an error, it calls `RollbackSavepoint`
to revert any changes to database state within the scope of the block.

Note that some errors can leave the transaction in a poisoned state,
where immediately rolling back the nested transaction is not possible.
The transaction can be returned to a normal state in some cases
(as is done for the read committed retry loop), but this will be left
as a TODO in 23.2, tracked in cockroachdb#111446. Until this is fixed, catching
`40001` and `40003` errors is not permitted.

Fixes cockroachdb#105253

Release note (sql change): When a PLpgSQL exception handler catches an
error, it now rolls back any changes to database state that occurred
within the block. Exception blocks are not currently permitted to catch
`40001` and `40003` errors.
@DrewKimball
Copy link
Collaborator Author

@nvanbenschoten brought up a good point - in read-committed, transaction retry errors shouldn't be visible to the user, so the exception handler should probably ignore them and pass them through to the statement retry loop.

DrewKimball added a commit to DrewKimball/cockroach that referenced this issue Sep 29, 2023
When an exception occurs within the EXCEPTION block of a PLpgSQL routine,
all changes to database state are rolled back, but the updated values for
the variables are still visible to the exception handler. For example:
```
CREATE FUNCTION f() RETURNS INT AS $$
  DECLARE
    i INT;
  BEGIN
    INSERT INTO xy VALUES (-100, -100);
    i := 100;
    RETURN 1 // 0;
  EXCEPTION WHEN division_by_zero THEN
    RETURN i;
  END
$$ LANGUAGE PLpgSQL;
```
The above function would not modify `xy`, since the exception would
revert the insert. However, the function would return `100`, since the
variable assignment occurred before the error was thrown.

This patch implements the required rollback behavior through internal
savepoints; when the top-level routine of a PLpgSQL block begins
executing, it creates a savepoint (if it has an exception handler).
When the exception handler catches an error, it calls `RollbackSavepoint`
to revert any changes to database state within the scope of the block.

Note that some errors can leave the transaction in a poisoned state,
where immediately rolling back the nested transaction is not possible.
The transaction can be returned to a normal state in some cases
(as is done for the read committed retry loop), but this will be left
as a TODO in 23.2, tracked in cockroachdb#111446. Until this is fixed, catching
`40001` and `40003` errors is not permitted.

Fixes cockroachdb#105253

Release note (sql change): When a PLpgSQL exception handler catches an
error, it now rolls back any changes to database state that occurred
within the block. Exception blocks are not currently permitted to catch
`40001` and `40003` errors.
DrewKimball added a commit to DrewKimball/cockroach that referenced this issue Oct 2, 2023
When an exception occurs within the EXCEPTION block of a PLpgSQL routine,
all changes to database state are rolled back, but the updated values for
the variables are still visible to the exception handler. For example:
```
CREATE FUNCTION f() RETURNS INT AS $$
  DECLARE
    i INT;
  BEGIN
    INSERT INTO xy VALUES (-100, -100);
    i := 100;
    RETURN 1 // 0;
  EXCEPTION WHEN division_by_zero THEN
    RETURN i;
  END
$$ LANGUAGE PLpgSQL;
```
The above function would not modify `xy`, since the exception would
revert the insert. However, the function would return `100`, since the
variable assignment occurred before the error was thrown.

This patch implements the required rollback behavior through internal
savepoints; when the top-level routine of a PLpgSQL block begins
executing, it creates a savepoint (if it has an exception handler).
When the exception handler catches an error, it calls `RollbackSavepoint`
to revert any changes to database state within the scope of the block.

Note that some errors can leave the transaction in a poisoned state,
where immediately rolling back the nested transaction is not possible.
The transaction can be returned to a normal state in some cases
(as is done for the read committed retry loop), but this will be left
as a TODO in 23.2, tracked in cockroachdb#111446. Until this is fixed, catching
`40001` and `40003` errors is not permitted.

Fixes cockroachdb#105253

Release note (sql change): When a PLpgSQL exception handler catches an
error, it now rolls back any changes to database state that occurred
within the block. Exception blocks are not currently permitted to catch
`40001` and `40003` errors.
DrewKimball added a commit to DrewKimball/cockroach that referenced this issue Oct 2, 2023
When an exception occurs within the EXCEPTION block of a PLpgSQL routine,
all changes to database state are rolled back, but the updated values for
the variables are still visible to the exception handler. For example:
```
CREATE FUNCTION f() RETURNS INT AS $$
  DECLARE
    i INT;
  BEGIN
    INSERT INTO xy VALUES (-100, -100);
    i := 100;
    RETURN 1 // 0;
  EXCEPTION WHEN division_by_zero THEN
    RETURN i;
  END
$$ LANGUAGE PLpgSQL;
```
The above function would not modify `xy`, since the exception would
revert the insert. However, the function would return `100`, since the
variable assignment occurred before the error was thrown.

This patch implements the required rollback behavior through internal
savepoints; when the top-level routine of a PLpgSQL block begins
executing, it creates a savepoint (if it has an exception handler).
When the exception handler catches an error, it calls `RollbackSavepoint`
to revert any changes to database state within the scope of the block.

Note that some errors can leave the transaction in a poisoned state,
where immediately rolling back the nested transaction is not possible.
The transaction can be returned to a normal state in some cases
(as is done for the read committed retry loop), but this will be left
as a TODO in 23.2, tracked in cockroachdb#111446. Until this is fixed, catching
`40001` and `40003` errors is not permitted.

Fixes cockroachdb#105253

Release note (sql change): When a PLpgSQL exception handler catches an
error, it now rolls back any changes to database state that occurred
within the block. Exception blocks are not currently permitted to catch
`40001` and `40003` errors.
DrewKimball added a commit to DrewKimball/cockroach that referenced this issue Oct 2, 2023
When an exception occurs within the EXCEPTION block of a PLpgSQL routine,
all changes to database state are rolled back, but the updated values for
the variables are still visible to the exception handler. For example:
```
CREATE FUNCTION f() RETURNS INT AS $$
  DECLARE
    i INT;
  BEGIN
    INSERT INTO xy VALUES (-100, -100);
    i := 100;
    RETURN 1 // 0;
  EXCEPTION WHEN division_by_zero THEN
    RETURN i;
  END
$$ LANGUAGE PLpgSQL;
```
The above function would not modify `xy`, since the exception would
revert the insert. However, the function would return `100`, since the
variable assignment occurred before the error was thrown.

This patch implements the required rollback behavior through internal
savepoints; when the top-level routine of a PLpgSQL block begins
executing, it creates a savepoint (if it has an exception handler).
When the exception handler catches an error, it calls `RollbackSavepoint`
to revert any changes to database state within the scope of the block.

Note that some errors can leave the transaction in a poisoned state,
where immediately rolling back the nested transaction is not possible.
The transaction can be returned to a normal state in some cases
(as is done for the read committed retry loop), but this will be left
as a TODO in 23.2, tracked in cockroachdb#111446. Until this is fixed, catching
`40001` and `40003` errors is not permitted.

Fixes cockroachdb#105253

Release note (sql change): When a PLpgSQL exception handler catches an
error, it now rolls back any changes to database state that occurred
within the block. Exception blocks are not currently permitted to catch
`40001` and `40003` errors.
craig bot pushed a commit that referenced this issue Oct 2, 2023
110998: plpgsql: implement rollback behavior for EXCEPTION blocks r=DrewKimball a=DrewKimball

#### plpgsql: implement rollback behavior for EXCEPTION blocks

When an exception occurs within the EXCEPTION block of a PLpgSQL routine,
all changes to database state are rolled back, but the updated values for
the variables are still visible to the exception handler. For example:
```
CREATE FUNCTION f() RETURNS INT AS $$
  DECLARE
    i INT;
  BEGIN
    INSERT INTO xy VALUES (-100, -100);
    i := 100;
    RETURN 1 // 0;
  EXCEPTION WHEN division_by_zero THEN
    RETURN i;
  END
$$ LANGUAGE PLpgSQL;
```
The above function would not modify `xy`, since the exception would
revert the insert. However, the function would return `100`, since the
variable assignment occurred before the error was thrown.

This patch implements the required rollback behavior through internal
savepoints; when the top-level routine of a PLpgSQL block begins
executing, it creates a savepoint (if it has an exception handler).
When the exception handler catches an error, it calls `RollbackSavepoint`
to revert any changes to database state within the scope of the block.

Note that some errors can leave the transaction in a poisoned state,
where immediately rolling back the nested transaction is not possible.
The transaction can be returned to a normal state in some cases
(as is done for the read committed retry loop), but this will be left
as a TODO in 23.2, tracked in #111446. Until this is fixed, catching
`40001` and `40003` errors is not permitted.

Fixes #105253

Release note (sql change): When a PLpgSQL exception handler catches an
error, it now rolls back any changes to database state that occurred
within the block. Exception blocks are not currently permitted to catch
`40001` and `40003` errors.

Co-authored-by: Drew Kimball <drewk@cockroachlabs.com>
THardy98 pushed a commit to THardy98/cockroach that referenced this issue Oct 6, 2023
When an exception occurs within the EXCEPTION block of a PLpgSQL routine,
all changes to database state are rolled back, but the updated values for
the variables are still visible to the exception handler. For example:
```
CREATE FUNCTION f() RETURNS INT AS $$
  DECLARE
    i INT;
  BEGIN
    INSERT INTO xy VALUES (-100, -100);
    i := 100;
    RETURN 1 // 0;
  EXCEPTION WHEN division_by_zero THEN
    RETURN i;
  END
$$ LANGUAGE PLpgSQL;
```
The above function would not modify `xy`, since the exception would
revert the insert. However, the function would return `100`, since the
variable assignment occurred before the error was thrown.

This patch implements the required rollback behavior through internal
savepoints; when the top-level routine of a PLpgSQL block begins
executing, it creates a savepoint (if it has an exception handler).
When the exception handler catches an error, it calls `RollbackSavepoint`
to revert any changes to database state within the scope of the block.

Note that some errors can leave the transaction in a poisoned state,
where immediately rolling back the nested transaction is not possible.
The transaction can be returned to a normal state in some cases
(as is done for the read committed retry loop), but this will be left
as a TODO in 23.2, tracked in cockroachdb#111446. Until this is fixed, catching
`40001` and `40003` errors is not permitted.

Fixes cockroachdb#105253

Release note (sql change): When a PLpgSQL exception handler catches an
error, it now rolls back any changes to database state that occurred
within the block. Exception blocks are not currently permitted to catch
`40001` and `40003` errors.
DrewKimball added a commit to DrewKimball/cockroach that referenced this issue Oct 20, 2023
PLpgSQL exception-handling allows use of the special `OTHERS` condition
that matches any error code apart from `query_canceled` and `assert_failure`
(although these can be caught explicitly). Note that transaction-rollback
(Class 40) errors still cannot be caught, either explicitly or by `OTHERS`.

Informs cockroachdb#105253

Release note (sql change): Added support for the special `OTHERS` condition
in PLpgSQL exception blocks, which allows matching any error code apart
from `query_canceled` and `assert_failure`. Note that Class 40 errors
(40000, 40001, 40003, 40002, and 40P01) cannot be caught either, tracked
in cockroachdb#111446.
DrewKimball added a commit to DrewKimball/cockroach that referenced this issue Oct 20, 2023
PLpgSQL exception-handling allows use of the special `OTHERS` condition
that matches any error code apart from `query_canceled` and `assert_failure`
(although these can be caught explicitly). Note that transaction-rollback
(Class 40) errors still cannot be caught, either explicitly or by `OTHERS`.

Informs cockroachdb#105253

Release note (sql change): Added support for the special `OTHERS` condition
in PLpgSQL exception blocks, which allows matching any error code apart
from `query_canceled` and `assert_failure`. Note that Class 40 errors
(40000, 40001, 40003, 40002, and 40P01) cannot be caught either, tracked
in cockroachdb#111446.
craig bot pushed a commit that referenced this issue Oct 21, 2023
112779: plpgql: implement special OTHERS exception-handling branch r=DrewKimball a=DrewKimball

PLpgSQL exception-handling allows use of the special `OTHERS` condition that matches any error code apart from `query_canceled` and `assert_failure` (although these can be caught explicitly). Note that transaction-rollback (Class 40) errors still cannot be caught, either explicitly or by `OTHERS`.

Informs #105253

Release note (sql change): Added support for the special `OTHERS` condition in PLpgSQL exception blocks, which allows matching any error code apart from `query_canceled` and `assert_failure`. Note that Class 40 errors (40000, 40001, 40003, 40002, and 40P01) cannot be caught either, tracked in #111446.

Co-authored-by: Drew Kimball <drewk@cockroachlabs.com>
blathers-crl bot pushed a commit that referenced this issue Oct 21, 2023
PLpgSQL exception-handling allows use of the special `OTHERS` condition
that matches any error code apart from `query_canceled` and `assert_failure`
(although these can be caught explicitly). Note that transaction-rollback
(Class 40) errors still cannot be caught, either explicitly or by `OTHERS`.

Informs #105253

Release note (sql change): Added support for the special `OTHERS` condition
in PLpgSQL exception blocks, which allows matching any error code apart
from `query_canceled` and `assert_failure`. Note that Class 40 errors
(40000, 40001, 40003, 40002, and 40P01) cannot be caught either, tracked
in #111446.
@yuzefovich yuzefovich added the T-sql-queries SQL Queries Team label Oct 25, 2023
@mgartner mgartner added the A-sql-routine UDFs and Stored Procedures label Nov 28, 2023
@exalate-issue-sync exalate-issue-sync bot added A-sql-udf and removed A-sql-routine UDFs and Stored Procedures labels Jul 22, 2024
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
A-sql-udf C-enhancement Solution expected to add code/behavior + preserve backward-compat (pg compat issues are exception) docs-known-limitation T-sql-queries SQL Queries Team
Projects
Status: 24.3 Release
Development

No branches or pull requests

3 participants