From 43351557d0d2b9c5e20298b5fee2849abef86aff Mon Sep 17 00:00:00 2001 From: Michael Paquier Date: Thu, 1 Dec 2022 15:41:13 +0900 Subject: [PATCH] Make materialized views participate in predicate locking Matviews have been discarded from needing predicate locks since 3bf3ab8 and their introduction. At this point, there was no concurrent flavor of REFRESH yet, hence there was no meaning in having materialized views look at read/write conflicts with concurrent transactions using themselves the serializable isolation level because they could only be refreshed with an access exclusive lock. CONCURRENTLY, on the contrary, allows reads and writes during a refresh as it holds a share update exclusive lock. Some isolation tests are added to show the effect of the change, with a combination of one table and a matview based on it, using a mix of REFRESH CONCURRENTLY and read/write queries. This could arguably be considered as a bug, but as it is a subtle behavior change potentially impacting applications no backpatch is done. Author: Yugo Nagata Reviewed-by: Richard Guo, Dilip Kumar, Michael Paquier Discussion: https://postgr.es/m/20220726164434.42d4e33911b4b4fcf751c4e7@sraoss.co.jp --- src/backend/storage/lmgr/predicate.c | 5 +- .../isolation/expected/matview-write-skew.out | 121 ++++++++++++++++++ src/test/isolation/isolation_schedule | 1 + .../isolation/specs/matview-write-skew.spec | 51 ++++++++ 4 files changed, 175 insertions(+), 3 deletions(-) create mode 100644 src/test/isolation/expected/matview-write-skew.out create mode 100644 src/test/isolation/specs/matview-write-skew.spec diff --git a/src/backend/storage/lmgr/predicate.c b/src/backend/storage/lmgr/predicate.c index e8120174d6..df1c0d72e9 100644 --- a/src/backend/storage/lmgr/predicate.c +++ b/src/backend/storage/lmgr/predicate.c @@ -490,14 +490,13 @@ static void ReleasePredicateLocksLocal(void); /* * Does this relation participate in predicate locking? Temporary and system - * relations are exempt, as are materialized views. + * relations are exempt. */ static inline bool PredicateLockingNeededForRelation(Relation relation) { return !(relation->rd_id < FirstUnpinnedObjectId || - RelationUsesLocalBuffers(relation) || - relation->rd_rel->relkind == RELKIND_MATVIEW); + RelationUsesLocalBuffers(relation)); } /* diff --git a/src/test/isolation/expected/matview-write-skew.out b/src/test/isolation/expected/matview-write-skew.out new file mode 100644 index 0000000000..4c8eaf5ae8 --- /dev/null +++ b/src/test/isolation/expected/matview-write-skew.out @@ -0,0 +1,121 @@ +Parsed test spec with 2 sessions + +starting permutation: s1_begin s2_begin s1_refresh s2_read s2_insert s1_commit s2_commit +step s1_begin: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2_begin: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1_refresh: REFRESH MATERIALIZED VIEW CONCURRENTLY order_summary; +step s2_read: SELECT max(date) FROM order_summary; + max +---------- +04-01-2022 +(1 row) + +step s2_insert: INSERT INTO orders VALUES ('2022-04-02', 'orange', 15); +step s1_commit: COMMIT; +step s2_commit: COMMIT; +ERROR: could not serialize access due to read/write dependencies among transactions + +starting permutation: s1_begin s2_begin s1_refresh s2_read s2_update s1_commit s2_commit +step s1_begin: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2_begin: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1_refresh: REFRESH MATERIALIZED VIEW CONCURRENTLY order_summary; +step s2_read: SELECT max(date) FROM order_summary; + max +---------- +04-01-2022 +(1 row) + +step s2_update: UPDATE orders SET num = num + 1; +step s1_commit: COMMIT; +step s2_commit: COMMIT; +ERROR: could not serialize access due to read/write dependencies among transactions + +starting permutation: s1_begin s2_begin s2_read s1_refresh s2_insert s1_commit s2_commit +step s1_begin: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2_begin: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2_read: SELECT max(date) FROM order_summary; + max +---------- +04-01-2022 +(1 row) + +step s1_refresh: REFRESH MATERIALIZED VIEW CONCURRENTLY order_summary; +step s2_insert: INSERT INTO orders VALUES ('2022-04-02', 'orange', 15); +step s1_commit: COMMIT; +step s2_commit: COMMIT; +ERROR: could not serialize access due to read/write dependencies among transactions + +starting permutation: s1_begin s2_begin s2_read s1_refresh s2_update s1_commit s2_commit +step s1_begin: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2_begin: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2_read: SELECT max(date) FROM order_summary; + max +---------- +04-01-2022 +(1 row) + +step s1_refresh: REFRESH MATERIALIZED VIEW CONCURRENTLY order_summary; +step s2_update: UPDATE orders SET num = num + 1; +step s1_commit: COMMIT; +step s2_commit: COMMIT; +ERROR: could not serialize access due to read/write dependencies among transactions + +starting permutation: s1_begin s2_begin s2_read s2_insert s1_refresh s1_commit s2_commit +step s1_begin: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2_begin: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2_read: SELECT max(date) FROM order_summary; + max +---------- +04-01-2022 +(1 row) + +step s2_insert: INSERT INTO orders VALUES ('2022-04-02', 'orange', 15); +step s1_refresh: REFRESH MATERIALIZED VIEW CONCURRENTLY order_summary; +step s1_commit: COMMIT; +step s2_commit: COMMIT; +ERROR: could not serialize access due to read/write dependencies among transactions + +starting permutation: s1_begin s2_begin s2_read s2_update s1_refresh s1_commit s2_commit +step s1_begin: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2_begin: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2_read: SELECT max(date) FROM order_summary; + max +---------- +04-01-2022 +(1 row) + +step s2_update: UPDATE orders SET num = num + 1; +step s1_refresh: REFRESH MATERIALIZED VIEW CONCURRENTLY order_summary; +step s1_commit: COMMIT; +step s2_commit: COMMIT; +ERROR: could not serialize access due to read/write dependencies among transactions + +starting permutation: s1_begin s2_begin s1_refresh s2_insert s2_read s1_commit s2_commit +step s1_begin: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2_begin: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1_refresh: REFRESH MATERIALIZED VIEW CONCURRENTLY order_summary; +step s2_insert: INSERT INTO orders VALUES ('2022-04-02', 'orange', 15); +step s2_read: SELECT max(date) FROM order_summary; + max +---------- +04-01-2022 +(1 row) + +step s1_commit: COMMIT; +step s2_commit: COMMIT; +ERROR: could not serialize access due to read/write dependencies among transactions + +starting permutation: s1_begin s2_begin s1_refresh s2_update s2_read s1_commit s2_commit +step s1_begin: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s2_begin: BEGIN ISOLATION LEVEL SERIALIZABLE; +step s1_refresh: REFRESH MATERIALIZED VIEW CONCURRENTLY order_summary; +step s2_update: UPDATE orders SET num = num + 1; +step s2_read: SELECT max(date) FROM order_summary; + max +---------- +04-01-2022 +(1 row) + +step s1_commit: COMMIT; +step s2_commit: COMMIT; +ERROR: could not serialize access due to read/write dependencies among transactions diff --git a/src/test/isolation/isolation_schedule b/src/test/isolation/isolation_schedule index 5413a59a80..c11dc9a420 100644 --- a/src/test/isolation/isolation_schedule +++ b/src/test/isolation/isolation_schedule @@ -108,3 +108,4 @@ test: cluster-conflict-partition test: truncate-conflict test: serializable-parallel test: serializable-parallel-2 +test: matview-write-skew diff --git a/src/test/isolation/specs/matview-write-skew.spec b/src/test/isolation/specs/matview-write-skew.spec new file mode 100644 index 0000000000..5fe21f1fb5 --- /dev/null +++ b/src/test/isolation/specs/matview-write-skew.spec @@ -0,0 +1,51 @@ +# Test write skew with a materialized view. +# +# This test uses two serializable transactions: one that refreshes a +# materialized view containing a summary of some order information, and +# one that looks at the materialized view while doing writes on its +# parent relation. +# +# Any overlap between the transactions should cause a serialization failure. + +setup +{ + CREATE TABLE orders (date date, item text, num int); + INSERT INTO orders VALUES ('2022-04-01', 'apple', 10), ('2022-04-01', 'banana', 20); + + CREATE MATERIALIZED VIEW order_summary AS + SELECT date, item, sum(num) FROM orders GROUP BY date, item; + CREATE UNIQUE INDEX ON order_summary(date, item); + -- Create a diff between the summary table and the parent orders. + INSERT INTO orders VALUES ('2022-04-02', 'apple', 20); +} + +teardown +{ + DROP MATERIALIZED VIEW order_summary; + DROP TABLE orders; +} + +session s1 +step s1_begin { BEGIN ISOLATION LEVEL SERIALIZABLE; } +step s1_refresh { REFRESH MATERIALIZED VIEW CONCURRENTLY order_summary; } +step s1_commit { COMMIT; } + +session s2 +step s2_begin { BEGIN ISOLATION LEVEL SERIALIZABLE; } +step s2_read { SELECT max(date) FROM order_summary; } +step s2_insert { INSERT INTO orders VALUES ('2022-04-02', 'orange', 15); } +step s2_update { UPDATE orders SET num = num + 1; } +step s2_commit { COMMIT; } + +# refresh -> read -> write +permutation "s1_begin" "s2_begin" "s1_refresh" "s2_read" "s2_insert" "s1_commit" "s2_commit" +permutation "s1_begin" "s2_begin" "s1_refresh" "s2_read" "s2_update" "s1_commit" "s2_commit" +# read -> refresh -> write +permutation "s1_begin" "s2_begin" "s2_read" "s1_refresh" "s2_insert" "s1_commit" "s2_commit" +permutation "s1_begin" "s2_begin" "s2_read" "s1_refresh" "s2_update" "s1_commit" "s2_commit" +# read -> write -> refresh +permutation "s1_begin" "s2_begin" "s2_read" "s2_insert" "s1_refresh" "s1_commit" "s2_commit" +permutation "s1_begin" "s2_begin" "s2_read" "s2_update" "s1_refresh" "s1_commit" "s2_commit" +# refresh -> write -> read +permutation "s1_begin" "s2_begin" "s1_refresh" "s2_insert" "s2_read" "s1_commit" "s2_commit" +permutation "s1_begin" "s2_begin" "s1_refresh" "s2_update" "s2_read" "s1_commit" "s2_commit"