Options

Tracking Save Points

Jim_KnicelyJim_Knicely - Select Field - Administrator

The SAVEPOINT SQL command creates a special mark, called a savepoint, inside a transaction. A savepoint allows all commands that are executed after it was established to be rolled back, restoring the transaction to the state it was in at the point in which the savepoint was established.

Savepoints can be nested so it can get confusing as to when a particular savepoint was issued. You can quickly list the savepoints issued for the current transaction by querying the QUERY_PROFILES system table.

Example:

dbadmin=> CREATE TABLE saves (C INT);
CREATE TABLE

dbadmin=> INSERT INTO saves SELECT 1;
OUTPUT
--------
      1
(1 row)

dbadmin=> INSERT INTO saves SELECT 2;
OUTPUT
--------
      1
(1 row)

dbadmin=> SAVEPOINT abc;
SAVEPOINT

dbadmin=> INSERT INTO saves SELECT 3;
OUTPUT
--------
      1
(1 row)

dbadmin=> INSERT INTO saves SELECT 4;
OUTPUT
--------
      1
(1 row)

dbadmin=> SAVEPOINT x1;
SAVEPOINT

dbadmin=> DELETE FROM saves WHERE c = 1;
OUTPUT
--------
      1
(1 row)

dbadmin=> SAVEPOINT save_1;
SAVEPOINT

dbadmin=> SELECT query_start, query
dbadmin->   FROM query_profiles
dbadmin->  WHERE session_id = current_session()
dbadmin->    AND transaction_id = current_trans_id()
dbadmin->    AND query_type = 'TRANSACTION'
dbadmin->  ORDER BY query_start DESC;
          query_start          |       query
-------------------------------+-------------------
2019-01-01 08:20:09.09355-05  | SAVEPOINT save_1;
2019-01-01 08:19:26.022173-05 | SAVEPOINT x1;
2019-01-01 08:10:11.703962-05 | SAVEPOINT abc;
(3 rows)

Helpful Links:
https://www.vertica.com/docs/9.2.x/HTML/Content/Authoring/SQLReferenceManual/Statements/SAVEPOINT.htm
https://www.vertica.com/docs/9.2.x/HTML/Content/Authoring/SQLReferenceManual/SystemTables/MONITOR/QUERY_PROFILES.htm

Have fun!

Sign In or Register to comment.