Skip to content

Commit

Permalink
Merge pull request #135046 from cockroachdb/blathers/backport-release…
Browse files Browse the repository at this point in the history
…-24.3-134498

release-24.3: sql: correctly handle triggers with cyclical dependencies
  • Loading branch information
DrewKimball authored Nov 13, 2024
2 parents a67efa1 + aac4e04 commit 14c3962
Show file tree
Hide file tree
Showing 17 changed files with 698 additions and 110 deletions.
326 changes: 326 additions & 0 deletions pkg/ccl/logictestccl/testdata/logic_test/triggers
Original file line number Diff line number Diff line change
Expand Up @@ -2220,6 +2220,332 @@ DROP FUNCTION g;
statement ok
DELETE FROM xy WHERE True;

# ==============================================================================
# Test cyclical triggers.
# ==============================================================================

statement ok
CREATE TABLE t1 (a INT, b INT);
CREATE TABLE t2 (a INT, b INT);

# Test cyclical AFTER triggers.
subtest cyclical_after_triggers

statement ok
SET recursion_depth_limit = 10;

statement ok
CREATE FUNCTION insert_t1() RETURNS TRIGGER LANGUAGE PLpgSQL AS $$
BEGIN
RAISE NOTICE ' ';
RAISE NOTICE '% trigger % with NEW: %', TG_WHEN, TG_NAME, NEW;
RAISE NOTICE 'max t1.a: %, max t2.a: %', (SELECT max(a) FROM t1), (SELECT max(a) FROM t2);
RAISE NOTICE 'inserting into t1: %', ROW((NEW).a + 1, (NEW).b);
INSERT INTO t1 VALUES ((NEW).a + 1, (NEW).b);
RETURN NEW;
END
$$;
CREATE FUNCTION insert_t2() RETURNS TRIGGER LANGUAGE PLpgSQL AS $$
BEGIN
RAISE NOTICE ' ';
RAISE NOTICE '% trigger % with NEW: %', TG_WHEN, TG_NAME, NEW;
RAISE NOTICE 'max t1.a: %, max t2.a: %', (SELECT max(a) FROM t1), (SELECT max(a) FROM t2);
RAISE NOTICE 'inserting into t2: %', ROW((NEW).a + 1, (NEW).b);
INSERT INTO t2 VALUES ((NEW).a + 1, (NEW).b);
RETURN NEW;
END
$$;

statement ok
CREATE TRIGGER foo AFTER INSERT ON t1 FOR EACH ROW EXECUTE FUNCTION insert_t2();

statement ok
CREATE TRIGGER bar AFTER INSERT ON t2 FOR EACH ROW EXECUTE FUNCTION insert_t1();

# The triggers should fire until the limit is reached.
statement error pgcode 09000 pq: trigger reached recursion depth limit: 10
INSERT INTO t1 VALUES (1, 1);

statement ok
DROP TRIGGER foo ON t1;

# Add a WHEN clause to end the cycle after a few iterations.
statement ok
CREATE TRIGGER foo AFTER INSERT ON t1 FOR EACH ROW WHEN ((NEW).a < 5) EXECUTE FUNCTION insert_t2();

query T noticetrace
INSERT INTO t1 VALUES (1, 1);
----
NOTICE:
NOTICE: AFTER trigger foo with NEW: (1,1)
NOTICE: max t1.a: 1, max t2.a: <NULL>
NOTICE: inserting into t2: (2,1)
NOTICE:
NOTICE: AFTER trigger bar with NEW: (2,1)
NOTICE: max t1.a: 1, max t2.a: 2
NOTICE: inserting into t1: (3,1)
NOTICE:
NOTICE: AFTER trigger foo with NEW: (3,1)
NOTICE: max t1.a: 3, max t2.a: 2
NOTICE: inserting into t2: (4,1)
NOTICE:
NOTICE: AFTER trigger bar with NEW: (4,1)
NOTICE: max t1.a: 3, max t2.a: 4
NOTICE: inserting into t1: (5,1)

query II rowsort
SELECT * FROM t1;
----
1 1
3 1
5 1

query II rowsort
SELECT * FROM t2;
----
2 1
4 1

statement ok
DELETE FROM t1 WHERE True;
DELETE FROM t2 WHERE True;

statement ok
DROP TRIGGER foo ON t1;

statement ok
DROP TRIGGER bar ON t2;

# Test cyclical BEFORE triggers.
subtest cyclical_before_triggers

statement ok
CREATE TRIGGER foo BEFORE INSERT ON t1 FOR EACH ROW EXECUTE FUNCTION insert_t2();

statement ok
CREATE TRIGGER bar BEFORE INSERT ON t2 FOR EACH ROW EXECUTE FUNCTION insert_t1();

# The triggers should fire until the limit is reached.
statement error pgcode 09000 pq: trigger reached recursion depth limit: 10
INSERT INTO t1 VALUES (1, 1);

statement ok
DROP TRIGGER foo ON t1;

# Add a WHEN clause to end the cycle after a few iterations.
statement ok
CREATE TRIGGER foo BEFORE INSERT ON t1 FOR EACH ROW WHEN ((NEW).a < 5) EXECUTE FUNCTION insert_t2();

query T noticetrace
INSERT INTO t1 VALUES (1, 1);
----
NOTICE:
NOTICE: BEFORE trigger foo with NEW: (1,1)
NOTICE: max t1.a: <NULL>, max t2.a: <NULL>
NOTICE: inserting into t2: (2,1)
NOTICE:
NOTICE: BEFORE trigger bar with NEW: (2,1)
NOTICE: max t1.a: <NULL>, max t2.a: <NULL>
NOTICE: inserting into t1: (3,1)
NOTICE:
NOTICE: BEFORE trigger foo with NEW: (3,1)
NOTICE: max t1.a: <NULL>, max t2.a: <NULL>
NOTICE: inserting into t2: (4,1)
NOTICE:
NOTICE: BEFORE trigger bar with NEW: (4,1)
NOTICE: max t1.a: <NULL>, max t2.a: <NULL>
NOTICE: inserting into t1: (5,1)

query II rowsort
SELECT * FROM t1;
----
1 1
3 1
5 1

query II rowsort
SELECT * FROM t2;
----
2 1
4 1

statement ok
DELETE FROM t1 WHERE True;
DELETE FROM t2 WHERE True;

# Test mutually cyclical BEFORE and AFTER triggers.
subtest cyclical_before_after_triggers

statement ok
DROP TRIGGER foo ON t1;

statement ok
CREATE TRIGGER foo AFTER INSERT ON t1 FOR EACH ROW EXECUTE FUNCTION insert_t2();

# The triggers should fire until the limit is reached.
statement error pgcode 09000 pq: trigger reached recursion depth limit: 10
INSERT INTO t1 VALUES (1, 1);

statement ok
DROP TRIGGER foo ON t1;

# Add a WHEN clause to end the cycle after a few iterations.
statement ok
CREATE TRIGGER foo AFTER INSERT ON t1 FOR EACH ROW WHEN ((NEW).a < 5) EXECUTE FUNCTION insert_t2();

query T noticetrace
INSERT INTO t1 VALUES (1, 1);
----
NOTICE:
NOTICE: AFTER trigger foo with NEW: (1,1)
NOTICE: max t1.a: 1, max t2.a: <NULL>
NOTICE: inserting into t2: (2,1)
NOTICE:
NOTICE: BEFORE trigger bar with NEW: (2,1)
NOTICE: max t1.a: 1, max t2.a: <NULL>
NOTICE: inserting into t1: (3,1)
NOTICE:
NOTICE: AFTER trigger foo with NEW: (3,1)
NOTICE: max t1.a: 3, max t2.a: <NULL>
NOTICE: inserting into t2: (4,1)
NOTICE:
NOTICE: BEFORE trigger bar with NEW: (4,1)
NOTICE: max t1.a: 3, max t2.a: <NULL>
NOTICE: inserting into t1: (5,1)

query II rowsort
SELECT * FROM t1;
----
1 1
3 1
5 1

query II rowsort
SELECT * FROM t2;
----
2 1
4 1

statement ok
DELETE FROM t1 WHERE True;
DELETE FROM t2 WHERE True;

statement ok
DROP TRIGGER foo ON t1;

statement ok
DROP TRIGGER bar ON t2;

# Test a single cyclical trigger.
subtest cyclical_trigger_singleton

statement ok
CREATE TRIGGER foo AFTER INSERT ON t1 FOR EACH ROW EXECUTE FUNCTION insert_t1();

# The trigger should fire until the limit is reached.
statement error pgcode 09000 pq: trigger reached recursion depth limit: 10
INSERT INTO t1 VALUES (1, 1);

statement ok
DROP TRIGGER foo ON t1;

# Add a WHEN clause to end the cycle after a few iterations.
statement ok
CREATE TRIGGER foo AFTER INSERT ON t1 FOR EACH ROW WHEN ((NEW).a < 5) EXECUTE FUNCTION insert_t1();

query T noticetrace
INSERT INTO t1 VALUES (1, 1);
----
NOTICE:
NOTICE: AFTER trigger foo with NEW: (1,1)
NOTICE: max t1.a: 1, max t2.a: <NULL>
NOTICE: inserting into t1: (2,1)
NOTICE:
NOTICE: AFTER trigger foo with NEW: (2,1)
NOTICE: max t1.a: 2, max t2.a: <NULL>
NOTICE: inserting into t1: (3,1)
NOTICE:
NOTICE: AFTER trigger foo with NEW: (3,1)
NOTICE: max t1.a: 3, max t2.a: <NULL>
NOTICE: inserting into t1: (4,1)
NOTICE:
NOTICE: AFTER trigger foo with NEW: (4,1)
NOTICE: max t1.a: 4, max t2.a: <NULL>
NOTICE: inserting into t1: (5,1)

query II rowsort
SELECT * FROM t1;
----
1 1
2 1
3 1
4 1
5 1

statement ok
DELETE FROM t1 WHERE True;

statement ok
DROP TRIGGER foo ON t1;

statement ok
CREATE TRIGGER bar BEFORE INSERT ON t1 FOR EACH ROW EXECUTE FUNCTION insert_t1();

# The trigger should fire until the limit is reached.
statement error pgcode 09000 pq: trigger reached recursion depth limit: 10
INSERT INTO t1 VALUES (1, 1);

statement ok
DROP TRIGGER bar ON t1;

# Add a WHEN clause to end the cycle after a few iterations.
statement ok
CREATE TRIGGER bar BEFORE INSERT ON t1 FOR EACH ROW WHEN ((NEW).a < 5) EXECUTE FUNCTION insert_t1();

query T noticetrace
INSERT INTO t1 VALUES (1, 1);
----
NOTICE:
NOTICE: BEFORE trigger bar with NEW: (1,1)
NOTICE: max t1.a: <NULL>, max t2.a: <NULL>
NOTICE: inserting into t1: (2,1)
NOTICE:
NOTICE: BEFORE trigger bar with NEW: (2,1)
NOTICE: max t1.a: <NULL>, max t2.a: <NULL>
NOTICE: inserting into t1: (3,1)
NOTICE:
NOTICE: BEFORE trigger bar with NEW: (3,1)
NOTICE: max t1.a: <NULL>, max t2.a: <NULL>
NOTICE: inserting into t1: (4,1)
NOTICE:
NOTICE: BEFORE trigger bar with NEW: (4,1)
NOTICE: max t1.a: <NULL>, max t2.a: <NULL>
NOTICE: inserting into t1: (5,1)

query II rowsort
SELECT * FROM t1;
----
1 1
2 1
3 1
4 1
5 1

statement ok
DELETE FROM t1 WHERE True;

statement ok
DROP TRIGGER bar ON t1;

statement ok
DROP FUNCTION insert_t1;
DROP FUNCTION insert_t2;
DROP TABLE t1;
DROP TABLE t2;

statement ok
RESET recursion_depth_limit;

# ==============================================================================
# Test row-level trigger interaction with FK cascades and checks.
# ==============================================================================
Expand Down
1 change: 0 additions & 1 deletion pkg/sql/distsql_running.go
Original file line number Diff line number Diff line change
Expand Up @@ -2373,7 +2373,6 @@ func addPostQueriesFromPlan(
// In cyclical reference situations, the number of cascading operations can
// be arbitrarily large. To avoid OOM, we enforce a limit. This is also a
// safeguard in case we have a bug that results in an infinite cascade loop.
// TODO(drewk): add something similar for triggers.
if limit := int(evalCtx.SessionData().OptimizerFKCascadesLimit); len(toPlan.cascades) > limit {
telemetry.Inc(sqltelemetry.CascadesLimitReached)
err := pgerror.Newf(pgcode.TriggeredActionException, "cascades limit (%d) reached", limit)
Expand Down
4 changes: 4 additions & 0 deletions pkg/sql/exec_util.go
Original file line number Diff line number Diff line change
Expand Up @@ -3900,6 +3900,10 @@ func (m *sessionDataMutator) SetUnsafeAllowTriggersModifyingCascades(val bool) {
m.data.UnsafeAllowTriggersModifyingCascades = val
}

func (m *sessionDataMutator) SetRecursionDepthLimit(val int) {
m.data.RecursionDepthLimit = int64(val)
}

// Utility functions related to scrubbing sensitive information on SQL Stats.

// quantizeCounts ensures that the Count field in the
Expand Down
1 change: 1 addition & 0 deletions pkg/sql/logictest/testdata/logic_test/information_schema
Original file line number Diff line number Diff line change
Expand Up @@ -6347,6 +6347,7 @@ plpgsql_use_strict_into off
prefer_lookup_joins_for_fks off
prepared_statements_cache_size 0 B
propagate_input_ordering off
recursion_depth_limit 1000
reorder_joins_limit 8
require_explicit_primary_keys off
results_buffer_size 524288
Expand Down
3 changes: 3 additions & 0 deletions pkg/sql/logictest/testdata/logic_test/pg_catalog
Original file line number Diff line number Diff line change
Expand Up @@ -2996,6 +2996,7 @@ plpgsql_use_strict_into off N
prefer_lookup_joins_for_fks off NULL NULL NULL string
prepared_statements_cache_size 0 B NULL NULL NULL string
propagate_input_ordering off NULL NULL NULL string
recursion_depth_limit 1000 NULL NULL NULL string
reorder_joins_limit 8 NULL NULL NULL string
require_explicit_primary_keys off NULL NULL NULL string
results_buffer_size 524288 NULL NULL NULL string
Expand Down Expand Up @@ -3192,6 +3193,7 @@ plpgsql_use_strict_into off N
prefer_lookup_joins_for_fks off NULL user NULL off off
prepared_statements_cache_size 0 B NULL user NULL 0 B 0 B
propagate_input_ordering off NULL user NULL off off
recursion_depth_limit 1000 NULL user NULL 1000 1000
reorder_joins_limit 8 NULL user NULL 8 8
require_explicit_primary_keys off NULL user NULL off off
results_buffer_size 524288 NULL user NULL 524288 524288
Expand Down Expand Up @@ -3387,6 +3389,7 @@ plpgsql_use_strict_into NULL NULL NULL
prefer_lookup_joins_for_fks NULL NULL NULL NULL NULL
prepared_statements_cache_size NULL NULL NULL NULL NULL
propagate_input_ordering NULL NULL NULL NULL NULL
recursion_depth_limit NULL NULL NULL NULL NULL
reorder_joins_limit NULL NULL NULL NULL NULL
require_explicit_primary_keys NULL NULL NULL NULL NULL
results_buffer_size NULL NULL NULL NULL NULL
Expand Down
1 change: 1 addition & 0 deletions pkg/sql/logictest/testdata/logic_test/show_source
Original file line number Diff line number Diff line change
Expand Up @@ -162,6 +162,7 @@ plpgsql_use_strict_into off
prefer_lookup_joins_for_fks off
prepared_statements_cache_size 0 B
propagate_input_ordering off
recursion_depth_limit 1000
reorder_joins_limit 8
require_explicit_primary_keys off
results_buffer_size 524288
Expand Down
1 change: 1 addition & 0 deletions pkg/sql/opt/exec/execbuilder/relational.go
Original file line number Diff line number Diff line change
Expand Up @@ -3408,6 +3408,7 @@ func (b *Builder) buildCall(c *memo.CallExpr) (_ execPlan, outputCols colOrdMap,
udf.Def.SetReturning,
false, /* tailCall */
true, /* procedure */
false, /* triggerFunc */
false, /* blockStart */
nil, /* blockState */
nil, /* cursorDeclaration */
Expand Down
Loading

0 comments on commit 14c3962

Please sign in to comment.