pg_ivm/specs/refresh_insert2.spec
Yugo Nagata f1166c0421
Fix potential view inconsistency issues (#121)
Previously, the view contents could become inconsistent with the base tables
in the following scenarios:

1) A concurrent transaction modifies a base table and commits before the
   incremental view maintenance starts in the current transaction.

2) A concurrent transaction modifies a base table and commits before the
   create_immv or refresh_immv command generates data.

3) Concurrent transactions incrementally update a view with a self-join
   or modify multiple base tables simultaneously.

Incremental updates of a view are generally performed sequentially using an
exclusive lock. However, even if we are able to acquire the lock, a concurrent
transaction may have already incrementally updated the view and been committed
before we can acquire it. In REPEATABLE READ or SERIALIZABLE isolation levels,
this could lead to an inconsistent view state, which is the cause of the first
issue.

To fix this, a new field, lastivmupdate, has been added to the pg_ivm_immv
catalog to record the transaction ID of the most recent update to the view.
Before performing view maintenance, the transaction ID is checked. If the
transaction was still in progress at the start of the current transaction,
an error is raised to prevent anomalies.

To fix the second issue, the timing of CreateTrigger() has been moved to
before data generation. This ensures that locks conflicting with table
modifications have been acquired on all base tables. In addition, the latest
snapshot is used in READ COMMITTED level during the data generation to reflect
committed changes from concurrent transactions. Additionally, inconsistencies
that cannot be avoided through locking are prevented by checking the transaction
ID of the last view update, as done for the first issue.

However, concurrent table modifications and create_immv execution still cannot
be detected at the time of view creation. Therefore, create_immv raises a warning
in REPEATABLE READ or SERIALIZABLE isolation levels, suggesting that the command
be used in READ COMMITTED mode or that refresh_immv be executed afterward to
ensure the view remains consistent.

The third issue was caused by the snapshot used for checking tuple visibility in
the table's pre-update state not being the latest one. To fix this, the latest
snapshot is now used in READ COMMITTED mode.

Isolation tests are also added.

Issue #104
2025-03-10 18:26:54 +09:00

46 lines
1.5 KiB
Python

# Test interaction between concurrent transactions performing
# refresh_immv and insert in REPEATABLE READ isolation level
setup
{
CREATE TABLE a (i int);
INSERT INTO a VALUES (1);
SELECT pgivm.create_immv('mv(x,y)', 'SELECT * FROM a a1, a a2 WHERE a1.i = a2.i');
CREATE VIEW v(x,y) AS SELECT * FROM a AS a1, a AS a2 WHERE a1.i = a2.i;
CREATE FUNCTION check_mv() RETURNS text AS
$$ SELECT CASE WHEN count(*) = 0 THEN 'ok' ELSE 'ng' END
FROM ((SELECT * FROM mv EXCEPT ALL SELECT * FROM v) UNION ALL
(SELECT * FROM v EXCEPT ALL SELECT * FROM mv)) $$ LANGUAGE sql;
}
teardown
{
DROP FUNCTION check_mv();
DROP TABLE mv;
DROP VIEW v;
DROP TABLE a;
}
session tx1
setup { BEGIN TRANSACTION ISOLATION LEVEL REPEATABLE READ; }
step s1 { SELECT; }
step refresh { SELECT pgivm.refresh_immv('mv', true); }
step check1 {SELECT check_mv();}
step c1 { COMMIT; }
step mv { SELECT * FROM mv ORDER BY 1,2; SELECT check_mv(); }
session tx2
setup { BEGIN TRANSACTION ISOLATION LEVEL REPEATABLE READ; }
step s2 { SELECT; }
step insert { INSERT INTO a VALUES (2); }
step check2 {SELECT check_mv(); }
step c2 { COMMIT; }
permutation s1 refresh s2 insert c1 check2 c2 mv
permutation s1 refresh s2 c1 insert check2 c2 mv
permutation s1 s2 refresh insert c1 check2 c2 mv
permutation s1 s2 insert refresh c2 check1 c1 mv
permutation s1 s2 refresh c1 insert check2 c2 mv
permutation s2 insert s1 refresh c2 check1 c1 mv
permutation s2 insert s1 c2 refresh check1 c1 mv
permutation s2 s1 insert c2 refresh check1 c1 mv