From 97241345433e3e8c22b9bc172d6d01121c9bccae Mon Sep 17 00:00:00 2001 From: Faizaan Madhani Date: Mon, 10 Oct 2022 12:09:59 -0500 Subject: [PATCH] sql: add support for `DELETE FROM ... USING` to optbuilder Previously, the optbuilder would return an error when given sql statements of the form `DELETE FROM USING`. This commit adds support to the Optbuilder to build query plans for statements of the form `DELETE FROM ... USING`. Release note: None --- pkg/sql/opt/memo/expr_format.go | 1 + pkg/sql/opt/ops/mutation.opt | 7 +- pkg/sql/opt/optbuilder/delete.go | 5 + pkg/sql/opt/optbuilder/mutation_builder.go | 72 ++- pkg/sql/opt/optbuilder/testdata/delete | 649 +++++++++++++++++++++ 5 files changed, 718 insertions(+), 16 deletions(-) diff --git a/pkg/sql/opt/memo/expr_format.go b/pkg/sql/opt/memo/expr_format.go index 0b9e10429ce3..4df3270123bd 100644 --- a/pkg/sql/opt/memo/expr_format.go +++ b/pkg/sql/opt/memo/expr_format.go @@ -684,6 +684,7 @@ func (f *ExprFmtCtx) formatRelational(e RelExpr, tp treeprinter.Node) { } f.formatOptionalColList(e, tp, "fetch columns:", t.FetchCols) f.formatMutationCols(e, tp, "return-mapping:", t.ReturnCols, t.Table) + f.formatOptionalColList(e, tp, "passthrough columns", opt.OptionalColList(t.PassthroughCols)) f.formatOptionalColList(e, tp, "partial index del columns:", t.PartialIndexDelCols) f.formatMutationCommon(tp, &t.MutationPrivate) } diff --git a/pkg/sql/opt/ops/mutation.opt b/pkg/sql/opt/ops/mutation.opt index 734e1ca0efc8..cc9670beb477 100644 --- a/pkg/sql/opt/ops/mutation.opt +++ b/pkg/sql/opt/ops/mutation.opt @@ -162,9 +162,10 @@ define MutationPrivate { # PassthroughCols are columns that the mutation needs to passthrough from # its input. It's similar to the passthrough columns in projections. This - # is useful for `UPDATE .. FROM` mutations where the `RETURNING` clause - # references columns from tables in the `FROM` clause. When this happens - # the update will need to pass through those refenced columns from its input. + # is useful for `UPDATE .. FROM` and `DELETE ... USING` mutations where the + # `RETURNING` clause references columns from tables in the `FROM` or `USING` + # clause, respectively. When this happens the mutation will need to pass through + # those referenced columns from its input. PassthroughCols ColList # Mutation operators can act similarly to a With operator: they buffer their diff --git a/pkg/sql/opt/optbuilder/delete.go b/pkg/sql/opt/optbuilder/delete.go index 16d9cbcb3f4d..834eee850a8c 100644 --- a/pkg/sql/opt/optbuilder/delete.go +++ b/pkg/sql/opt/optbuilder/delete.go @@ -83,6 +83,11 @@ func (mb *mutationBuilder) buildDelete(returning tree.ReturningExprs) { mb.projectPartialIndexDelCols() private := mb.makeMutationPrivate(returning != nil) + for _, col := range mb.extraAccessibleCols { + if col.id != 0 { + private.PassthroughCols = append(private.PassthroughCols, col.id) + } + } mb.outScope.expr = mb.b.factory.ConstructDelete( mb.outScope.expr, mb.uniqueChecks, mb.fkChecks, private, ) diff --git a/pkg/sql/opt/optbuilder/mutation_builder.go b/pkg/sql/opt/optbuilder/mutation_builder.go index 5dba82f2f80e..de0d54cf08a4 100644 --- a/pkg/sql/opt/optbuilder/mutation_builder.go +++ b/pkg/sql/opt/optbuilder/mutation_builder.go @@ -184,8 +184,9 @@ type mutationBuilder struct { // extraAccessibleCols stores all the columns that are available to the // mutation that are not part of the target table. This is useful for - // UPDATE ... FROM queries, as the columns from the FROM tables must be - // made accessible to the RETURNING clause. + // UPDATE ... FROM queries and DELETE ... USING queries, as the columns + // from the FROM and USING tables must be made accessible to the + // RETURNING clause, respectively. extraAccessibleCols []scopeColumn // fkCheckHelper is used to prevent allocating the helper separately. @@ -376,7 +377,7 @@ func (mb *mutationBuilder) buildInputForUpdate( // the Delete operator, similar to this: // // SELECT -// FROM +// FROM
[, ] // WHERE // ORDER BY // LIMIT @@ -418,7 +419,39 @@ func (mb *mutationBuilder) buildInputForDelete( inScope, false, /* disableNotVisibleIndex */ ) - mb.outScope = mb.fetchScope + + // Set list of columns that will be fetched by the input expression. + mb.setFetchColIDs(mb.fetchScope.cols) + + // USING + usingClausePresent := len(using) > 0 + if usingClausePresent { + usingScope := mb.b.buildFromTables(using, noRowLocking, inScope) + + // Check that the same table name is not used multiple times + mb.b.validateJoinTableNames(mb.fetchScope, usingScope) + + // The USING table columns can be accessed by the RETURNING clause of the + // query and so we have to make them accessible. + mb.extraAccessibleCols = usingScope.cols + + // Add the columns to the USING scope. + // We create a new scope so that fetchScope is not modified + // as fetchScope contains the set of columns from the target + // table specified by USING. This will be used later with partial + // index predicate expressions and will prevent ambiguities with + // column names in the USING clause. + mb.outScope = mb.fetchScope.replace() + mb.outScope.appendColumnsFromScope(mb.fetchScope) + mb.outScope.appendColumnsFromScope(usingScope) + + left := mb.fetchScope.expr + right := usingScope.expr + + mb.outScope.expr = mb.b.factory.ConstructInnerJoin(left, right, memo.TrueFilter, memo.EmptyJoinPrivate) + } else { + mb.outScope = mb.fetchScope + } // WHERE mb.b.buildWhere(where, mb.outScope) @@ -430,11 +463,6 @@ func (mb *mutationBuilder) buildInputForDelete( mb.b.buildOrderBy(mb.outScope, projectionsScope, orderByScope) mb.b.constructProjectForScope(mb.outScope, projectionsScope) - // USING - if using != nil { - panic("DELETE USING is unimplemented so should not be used") - } - // LIMIT if limit != nil { mb.b.buildLimit(limit, inScope, projectionsScope) @@ -442,8 +470,25 @@ func (mb *mutationBuilder) buildInputForDelete( mb.outScope = projectionsScope - // Set list of columns that will be fetched by the input expression. - mb.setFetchColIDs(mb.outScope.cols) + // Build a distinct on to ensure there is at most one row in the joined output + // for every row in the table + if usingClausePresent { + var pkCols opt.ColSet + + // We need to ensure that the join has a maximum of one row for every row + // in the table and we ensure this by constructing a distinct on the primary + // key columns. + primaryIndex := mb.tab.Index(cat.PrimaryIndex) + for i := 0; i < primaryIndex.KeyColumnCount(); i++ { + col := primaryIndex.Column(i) + pkCols.Add(mb.fetchColIDs[col.Ordinal()]) + } + + if !pkCols.Empty() { + mb.outScope = mb.b.buildDistinctOn( + pkCols, mb.outScope, false /* nullsAreDistinct */, "" /* errorOnDup */) + } + } } // addTargetColsByName adds one target column for each of the names in the given @@ -1011,8 +1056,9 @@ func (mb *mutationBuilder) buildReturning(returning tree.ReturningExprs) { // extraAccessibleCols contains all the columns that the RETURNING // clause can refer to in addition to the table columns. This is useful for - // UPDATE ... FROM statements, where all columns from tables in the FROM clause - // are in scope for the RETURNING clause. + // UPDATE ... FROM and DELETE ... USING statements, where all columns from + // tables in the FROM clause and USING clause are in scope for the RETURNING + // clause, respectively. inScope.appendColumns(mb.extraAccessibleCols) // Construct the Project operator that projects the RETURNING expressions. diff --git a/pkg/sql/opt/optbuilder/testdata/delete b/pkg/sql/opt/optbuilder/testdata/delete index 2a439a82c5a1..5b3b772969e6 100644 --- a/pkg/sql/opt/optbuilder/testdata/delete +++ b/pkg/sql/opt/optbuilder/testdata/delete @@ -32,6 +32,14 @@ CREATE TABLE mutation ( ) ---- +exec-ddl +CREATE TABLE fgh ( + f INT, + g TEXT, + h INT +) +---- + # ------------------------------------------------------------------------------ # Basic tests. # ------------------------------------------------------------------------------ @@ -455,3 +463,644 @@ build DELETE FROM mutation ORDER BY p LIMIT 2 ---- error (42P10): column "p" is being backfilled + +# ------------------------------------------------------------------------------ +# Test USING. +# ------------------------------------------------------------------------------ + +# Test a simple join with a filter. +build format=show-qual +DELETE FROM abcde USING fgh WHERE c = fgh.h AND fgh.g = 'd' +---- +delete t.public.abcde + ├── columns: + ├── fetch columns: t.public.abcde.a:9 t.public.abcde.b:10 t.public.abcde.c:11 t.public.abcde.d:12 t.public.abcde.e:13 t.public.abcde.rowid:14 + ├── passthrough columns t.public.fgh.f:17 t.public.fgh.g:18 t.public.fgh.h:19 t.public.fgh.rowid:20 t.public.fgh.crdb_internal_mvcc_timestamp:21 t.public.fgh.tableoid:22 + └── distinct-on + ├── columns: t.public.abcde.a:9!null t.public.abcde.b:10 t.public.abcde.c:11!null t.public.abcde.d:12 t.public.abcde.e:13 t.public.abcde.rowid:14!null t.public.abcde.crdb_internal_mvcc_timestamp:15 t.public.abcde.tableoid:16 t.public.fgh.f:17 t.public.fgh.g:18!null t.public.fgh.h:19!null t.public.fgh.rowid:20!null t.public.fgh.crdb_internal_mvcc_timestamp:21 t.public.fgh.tableoid:22 + ├── grouping columns: t.public.abcde.rowid:14!null + ├── select + │ ├── columns: t.public.abcde.a:9!null t.public.abcde.b:10 t.public.abcde.c:11!null t.public.abcde.d:12 t.public.abcde.e:13 t.public.abcde.rowid:14!null t.public.abcde.crdb_internal_mvcc_timestamp:15 t.public.abcde.tableoid:16 t.public.fgh.f:17 t.public.fgh.g:18!null t.public.fgh.h:19!null t.public.fgh.rowid:20!null t.public.fgh.crdb_internal_mvcc_timestamp:21 t.public.fgh.tableoid:22 + │ ├── inner-join (cross) + │ │ ├── columns: t.public.abcde.a:9!null t.public.abcde.b:10 t.public.abcde.c:11 t.public.abcde.d:12 t.public.abcde.e:13 t.public.abcde.rowid:14!null t.public.abcde.crdb_internal_mvcc_timestamp:15 t.public.abcde.tableoid:16 t.public.fgh.f:17 t.public.fgh.g:18 t.public.fgh.h:19 t.public.fgh.rowid:20!null t.public.fgh.crdb_internal_mvcc_timestamp:21 t.public.fgh.tableoid:22 + │ │ ├── scan t.public.abcde + │ │ │ ├── columns: t.public.abcde.a:9!null t.public.abcde.b:10 t.public.abcde.c:11 t.public.abcde.d:12 t.public.abcde.e:13 t.public.abcde.rowid:14!null t.public.abcde.crdb_internal_mvcc_timestamp:15 t.public.abcde.tableoid:16 + │ │ │ └── computed column expressions + │ │ │ ├── t.public.abcde.d:12 + │ │ │ │ └── (t.public.abcde.b:10 + t.public.abcde.c:11) + 1 + │ │ │ └── t.public.abcde.e:13 + │ │ │ └── t.public.abcde.a:9 + │ │ ├── scan t.public.fgh + │ │ │ └── columns: t.public.fgh.f:17 t.public.fgh.g:18 t.public.fgh.h:19 t.public.fgh.rowid:20!null t.public.fgh.crdb_internal_mvcc_timestamp:21 t.public.fgh.tableoid:22 + │ │ └── filters (true) + │ └── filters + │ └── (t.public.abcde.c:11 = t.public.fgh.h:19) AND (t.public.fgh.g:18 = 'd') + └── aggregations + ├── first-agg [as=t.public.abcde.a:9] + │ └── t.public.abcde.a:9 + ├── first-agg [as=t.public.abcde.b:10] + │ └── t.public.abcde.b:10 + ├── first-agg [as=t.public.abcde.c:11] + │ └── t.public.abcde.c:11 + ├── first-agg [as=t.public.abcde.d:12] + │ └── t.public.abcde.d:12 + ├── first-agg [as=t.public.abcde.e:13] + │ └── t.public.abcde.e:13 + ├── first-agg [as=t.public.abcde.crdb_internal_mvcc_timestamp:15] + │ └── t.public.abcde.crdb_internal_mvcc_timestamp:15 + ├── first-agg [as=t.public.abcde.tableoid:16] + │ └── t.public.abcde.tableoid:16 + ├── first-agg [as=t.public.fgh.f:17] + │ └── t.public.fgh.f:17 + ├── first-agg [as=t.public.fgh.g:18] + │ └── t.public.fgh.g:18 + ├── first-agg [as=t.public.fgh.h:19] + │ └── t.public.fgh.h:19 + ├── first-agg [as=t.public.fgh.rowid:20] + │ └── t.public.fgh.rowid:20 + ├── first-agg [as=t.public.fgh.crdb_internal_mvcc_timestamp:21] + │ └── t.public.fgh.crdb_internal_mvcc_timestamp:21 + └── first-agg [as=t.public.fgh.tableoid:22] + └── t.public.fgh.tableoid:22 + +# Test a self join. +build +DELETE FROM abcde USING abcde abcde2 WHERE abcde.a = abcde2.c +---- +delete abcde + ├── columns: + ├── fetch columns: abcde.a:9 abcde.b:10 abcde.c:11 abcde.d:12 abcde.e:13 abcde.rowid:14 + ├── passthrough columns abcde2.a:17 abcde2.b:18 abcde2.c:19 abcde2.d:20 abcde2.e:21 abcde2.rowid:22 abcde2.crdb_internal_mvcc_timestamp:23 abcde2.tableoid:24 + └── distinct-on + ├── columns: abcde.a:9!null abcde.b:10 abcde.c:11 abcde.d:12 abcde.e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 abcde2.a:17!null abcde2.b:18 abcde2.c:19!null abcde2.d:20 abcde2.e:21 abcde2.rowid:22!null abcde2.crdb_internal_mvcc_timestamp:23 abcde2.tableoid:24 + ├── grouping columns: abcde.rowid:14!null + ├── select + │ ├── columns: abcde.a:9!null abcde.b:10 abcde.c:11 abcde.d:12 abcde.e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 abcde2.a:17!null abcde2.b:18 abcde2.c:19!null abcde2.d:20 abcde2.e:21 abcde2.rowid:22!null abcde2.crdb_internal_mvcc_timestamp:23 abcde2.tableoid:24 + │ ├── inner-join (cross) + │ │ ├── columns: abcde.a:9!null abcde.b:10 abcde.c:11 abcde.d:12 abcde.e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 abcde2.a:17!null abcde2.b:18 abcde2.c:19 abcde2.d:20 abcde2.e:21 abcde2.rowid:22!null abcde2.crdb_internal_mvcc_timestamp:23 abcde2.tableoid:24 + │ │ ├── scan abcde + │ │ │ ├── columns: abcde.a:9!null abcde.b:10 abcde.c:11 abcde.d:12 abcde.e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 + │ │ │ └── computed column expressions + │ │ │ ├── abcde.d:12 + │ │ │ │ └── (abcde.b:10 + abcde.c:11) + 1 + │ │ │ └── abcde.e:13 + │ │ │ └── abcde.a:9 + │ │ ├── scan abcde [as=abcde2] + │ │ │ ├── columns: abcde2.a:17!null abcde2.b:18 abcde2.c:19 abcde2.d:20 abcde2.e:21 abcde2.rowid:22!null abcde2.crdb_internal_mvcc_timestamp:23 abcde2.tableoid:24 + │ │ │ └── computed column expressions + │ │ │ ├── abcde2.d:20 + │ │ │ │ └── (abcde2.b:18 + abcde2.c:19) + 1 + │ │ │ └── abcde2.e:21 + │ │ │ └── abcde2.a:17 + │ │ └── filters (true) + │ └── filters + │ └── abcde.a:9 = abcde2.c:19 + └── aggregations + ├── first-agg [as=abcde.a:9] + │ └── abcde.a:9 + ├── first-agg [as=abcde.b:10] + │ └── abcde.b:10 + ├── first-agg [as=abcde.c:11] + │ └── abcde.c:11 + ├── first-agg [as=abcde.d:12] + │ └── abcde.d:12 + ├── first-agg [as=abcde.e:13] + │ └── abcde.e:13 + ├── first-agg [as=abcde.crdb_internal_mvcc_timestamp:15] + │ └── abcde.crdb_internal_mvcc_timestamp:15 + ├── first-agg [as=abcde.tableoid:16] + │ └── abcde.tableoid:16 + ├── first-agg [as=abcde2.a:17] + │ └── abcde2.a:17 + ├── first-agg [as=abcde2.b:18] + │ └── abcde2.b:18 + ├── first-agg [as=abcde2.c:19] + │ └── abcde2.c:19 + ├── first-agg [as=abcde2.d:20] + │ └── abcde2.d:20 + ├── first-agg [as=abcde2.e:21] + │ └── abcde2.e:21 + ├── first-agg [as=abcde2.rowid:22] + │ └── abcde2.rowid:22 + ├── first-agg [as=abcde2.crdb_internal_mvcc_timestamp:23] + │ └── abcde2.crdb_internal_mvcc_timestamp:23 + └── first-agg [as=abcde2.tableoid:24] + └── abcde2.tableoid:24 + +# Test when USING uses multiple tables. +build +DELETE FROM fgh USING abcde, xyz WHERE abcde.c = fgh.f AND xyz.x = fgh.g +---- +delete fgh + ├── columns: + ├── fetch columns: f:7 g:8 h:9 fgh.rowid:10 + ├── passthrough columns a:13 b:14 c:15 d:16 e:17 abcde.rowid:18 abcde.crdb_internal_mvcc_timestamp:19 abcde.tableoid:20 x:21 y:22 z:23 xyz.crdb_internal_mvcc_timestamp:24 xyz.tableoid:25 + └── distinct-on + ├── columns: f:7!null g:8!null h:9 fgh.rowid:10!null fgh.crdb_internal_mvcc_timestamp:11 fgh.tableoid:12 a:13!null b:14 c:15!null d:16 e:17 abcde.rowid:18!null abcde.crdb_internal_mvcc_timestamp:19 abcde.tableoid:20 x:21!null y:22 z:23 xyz.crdb_internal_mvcc_timestamp:24 xyz.tableoid:25 + ├── grouping columns: fgh.rowid:10!null + ├── select + │ ├── columns: f:7!null g:8!null h:9 fgh.rowid:10!null fgh.crdb_internal_mvcc_timestamp:11 fgh.tableoid:12 a:13!null b:14 c:15!null d:16 e:17 abcde.rowid:18!null abcde.crdb_internal_mvcc_timestamp:19 abcde.tableoid:20 x:21!null y:22 z:23 xyz.crdb_internal_mvcc_timestamp:24 xyz.tableoid:25 + │ ├── inner-join (cross) + │ │ ├── columns: f:7 g:8 h:9 fgh.rowid:10!null fgh.crdb_internal_mvcc_timestamp:11 fgh.tableoid:12 a:13!null b:14 c:15 d:16 e:17 abcde.rowid:18!null abcde.crdb_internal_mvcc_timestamp:19 abcde.tableoid:20 x:21!null y:22 z:23 xyz.crdb_internal_mvcc_timestamp:24 xyz.tableoid:25 + │ │ ├── scan fgh + │ │ │ └── columns: f:7 g:8 h:9 fgh.rowid:10!null fgh.crdb_internal_mvcc_timestamp:11 fgh.tableoid:12 + │ │ ├── inner-join (cross) + │ │ │ ├── columns: a:13!null b:14 c:15 d:16 e:17 abcde.rowid:18!null abcde.crdb_internal_mvcc_timestamp:19 abcde.tableoid:20 x:21!null y:22 z:23 xyz.crdb_internal_mvcc_timestamp:24 xyz.tableoid:25 + │ │ │ ├── scan abcde + │ │ │ │ ├── columns: a:13!null b:14 c:15 d:16 e:17 abcde.rowid:18!null abcde.crdb_internal_mvcc_timestamp:19 abcde.tableoid:20 + │ │ │ │ └── computed column expressions + │ │ │ │ ├── d:16 + │ │ │ │ │ └── (b:14 + c:15) + 1 + │ │ │ │ └── e:17 + │ │ │ │ └── a:13 + │ │ │ ├── scan xyz + │ │ │ │ └── columns: x:21!null y:22 z:23 xyz.crdb_internal_mvcc_timestamp:24 xyz.tableoid:25 + │ │ │ └── filters (true) + │ │ └── filters (true) + │ └── filters + │ └── (c:15 = f:7) AND (x:21 = g:8) + └── aggregations + ├── first-agg [as=f:7] + │ └── f:7 + ├── first-agg [as=g:8] + │ └── g:8 + ├── first-agg [as=h:9] + │ └── h:9 + ├── first-agg [as=fgh.crdb_internal_mvcc_timestamp:11] + │ └── fgh.crdb_internal_mvcc_timestamp:11 + ├── first-agg [as=fgh.tableoid:12] + │ └── fgh.tableoid:12 + ├── first-agg [as=a:13] + │ └── a:13 + ├── first-agg [as=b:14] + │ └── b:14 + ├── first-agg [as=c:15] + │ └── c:15 + ├── first-agg [as=d:16] + │ └── d:16 + ├── first-agg [as=e:17] + │ └── e:17 + ├── first-agg [as=abcde.rowid:18] + │ └── abcde.rowid:18 + ├── first-agg [as=abcde.crdb_internal_mvcc_timestamp:19] + │ └── abcde.crdb_internal_mvcc_timestamp:19 + ├── first-agg [as=abcde.tableoid:20] + │ └── abcde.tableoid:20 + ├── first-agg [as=x:21] + │ └── x:21 + ├── first-agg [as=y:22] + │ └── y:22 + ├── first-agg [as=z:23] + │ └── z:23 + ├── first-agg [as=xyz.crdb_internal_mvcc_timestamp:24] + │ └── xyz.crdb_internal_mvcc_timestamp:24 + └── first-agg [as=xyz.tableoid:25] + └── xyz.tableoid:25 + +# Test if USING works well with RETURNING expressions that reference +# the USING table. +build +DELETE FROM + abcde +USING + fgh +WHERE + fgh.h > abcde.b AND fgh.h <= 4 +RETURNING + abcde.a, abcde.b, abcde.c, abcde.d, abcde.e +---- +project + ├── columns: a:1!null b:2!null c:3 d:4 e:5 + └── delete abcde + ├── columns: a:1!null b:2!null c:3 d:4 e:5 abcde.rowid:6!null f:17 g:18 h:19 fgh.rowid:20 fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + ├── fetch columns: a:9 b:10 c:11 d:12 e:13 abcde.rowid:14 + ├── return-mapping: + │ ├── a:9 => a:1 + │ ├── b:10 => b:2 + │ ├── c:11 => c:3 + │ ├── d:12 => d:4 + │ ├── e:13 => e:5 + │ └── abcde.rowid:14 => abcde.rowid:6 + ├── passthrough columns f:17 g:18 h:19 fgh.rowid:20 fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + └── distinct-on + ├── columns: a:9!null b:10!null c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 f:17 g:18 h:19!null fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + ├── grouping columns: abcde.rowid:14!null + ├── select + │ ├── columns: a:9!null b:10!null c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 f:17 g:18 h:19!null fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + │ ├── inner-join (cross) + │ │ ├── columns: a:9!null b:10 c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 f:17 g:18 h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + │ │ ├── scan abcde + │ │ │ ├── columns: a:9!null b:10 c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 + │ │ │ └── computed column expressions + │ │ │ ├── d:12 + │ │ │ │ └── (b:10 + c:11) + 1 + │ │ │ └── e:13 + │ │ │ └── a:9 + │ │ ├── scan fgh + │ │ │ └── columns: f:17 g:18 h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + │ │ └── filters (true) + │ └── filters + │ └── (h:19 > b:10) AND (h:19 <= 4) + └── aggregations + ├── first-agg [as=a:9] + │ └── a:9 + ├── first-agg [as=b:10] + │ └── b:10 + ├── first-agg [as=c:11] + │ └── c:11 + ├── first-agg [as=d:12] + │ └── d:12 + ├── first-agg [as=e:13] + │ └── e:13 + ├── first-agg [as=abcde.crdb_internal_mvcc_timestamp:15] + │ └── abcde.crdb_internal_mvcc_timestamp:15 + ├── first-agg [as=abcde.tableoid:16] + │ └── abcde.tableoid:16 + ├── first-agg [as=f:17] + │ └── f:17 + ├── first-agg [as=g:18] + │ └── g:18 + ├── first-agg [as=h:19] + │ └── h:19 + ├── first-agg [as=fgh.rowid:20] + │ └── fgh.rowid:20 + ├── first-agg [as=fgh.crdb_internal_mvcc_timestamp:21] + │ └── fgh.crdb_internal_mvcc_timestamp:21 + └── first-agg [as=fgh.tableoid:22] + └── fgh.tableoid:22 + +# Test if RETURNING * returns everything. +build +DELETE FROM abcde USING fgh WHERE c = fgh.f AND fgh.g = 'd' RETURNING * +---- +project + ├── columns: a:1!null b:2 c:3!null d:4 e:5 f:17 g:18 h:19 + └── delete abcde + ├── columns: a:1!null b:2 c:3!null d:4 e:5 abcde.rowid:6!null f:17 g:18 h:19 fgh.rowid:20 fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + ├── fetch columns: a:9 b:10 c:11 d:12 e:13 abcde.rowid:14 + ├── return-mapping: + │ ├── a:9 => a:1 + │ ├── b:10 => b:2 + │ ├── c:11 => c:3 + │ ├── d:12 => d:4 + │ ├── e:13 => e:5 + │ └── abcde.rowid:14 => abcde.rowid:6 + ├── passthrough columns f:17 g:18 h:19 fgh.rowid:20 fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + └── distinct-on + ├── columns: a:9!null b:10 c:11!null d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 f:17!null g:18!null h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + ├── grouping columns: abcde.rowid:14!null + ├── select + │ ├── columns: a:9!null b:10 c:11!null d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 f:17!null g:18!null h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + │ ├── inner-join (cross) + │ │ ├── columns: a:9!null b:10 c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 f:17 g:18 h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + │ │ ├── scan abcde + │ │ │ ├── columns: a:9!null b:10 c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 + │ │ │ └── computed column expressions + │ │ │ ├── d:12 + │ │ │ │ └── (b:10 + c:11) + 1 + │ │ │ └── e:13 + │ │ │ └── a:9 + │ │ ├── scan fgh + │ │ │ └── columns: f:17 g:18 h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + │ │ └── filters (true) + │ └── filters + │ └── (c:11 = f:17) AND (g:18 = 'd') + └── aggregations + ├── first-agg [as=a:9] + │ └── a:9 + ├── first-agg [as=b:10] + │ └── b:10 + ├── first-agg [as=c:11] + │ └── c:11 + ├── first-agg [as=d:12] + │ └── d:12 + ├── first-agg [as=e:13] + │ └── e:13 + ├── first-agg [as=abcde.crdb_internal_mvcc_timestamp:15] + │ └── abcde.crdb_internal_mvcc_timestamp:15 + ├── first-agg [as=abcde.tableoid:16] + │ └── abcde.tableoid:16 + ├── first-agg [as=f:17] + │ └── f:17 + ├── first-agg [as=g:18] + │ └── g:18 + ├── first-agg [as=h:19] + │ └── h:19 + ├── first-agg [as=fgh.rowid:20] + │ └── fgh.rowid:20 + ├── first-agg [as=fgh.crdb_internal_mvcc_timestamp:21] + │ └── fgh.crdb_internal_mvcc_timestamp:21 + └── first-agg [as=fgh.tableoid:22] + └── fgh.tableoid:22 + +# Test aliased table names and order by and limit. +build +DELETE FROM abcde AS foo USING xyz AS bar WHERE bar.y > 0 ORDER BY foo.a DESC LIMIT 5; +---- +error (42P10): SELECT DISTINCT ON expressions must match initial ORDER BY expressions + +# Test if DELETE FROM ... USING can return hidden columns. +build +DELETE FROM + abcde +USING + fgh +WHERE + abcde.a = fgh.f +RETURNING + fgh.rowid +---- +project + ├── columns: rowid:20 + └── delete abcde + ├── columns: a:1!null b:2 c:3 d:4 e:5 abcde.rowid:6!null f:17 g:18 h:19 fgh.rowid:20 fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + ├── fetch columns: a:9 b:10 c:11 d:12 e:13 abcde.rowid:14 + ├── return-mapping: + │ ├── a:9 => a:1 + │ ├── b:10 => b:2 + │ ├── c:11 => c:3 + │ ├── d:12 => d:4 + │ ├── e:13 => e:5 + │ └── abcde.rowid:14 => abcde.rowid:6 + ├── passthrough columns f:17 g:18 h:19 fgh.rowid:20 fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + └── distinct-on + ├── columns: a:9!null b:10 c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 f:17!null g:18 h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + ├── grouping columns: abcde.rowid:14!null + ├── select + │ ├── columns: a:9!null b:10 c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 f:17!null g:18 h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + │ ├── inner-join (cross) + │ │ ├── columns: a:9!null b:10 c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 f:17 g:18 h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + │ │ ├── scan abcde + │ │ │ ├── columns: a:9!null b:10 c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 + │ │ │ └── computed column expressions + │ │ │ ├── d:12 + │ │ │ │ └── (b:10 + c:11) + 1 + │ │ │ └── e:13 + │ │ │ └── a:9 + │ │ ├── scan fgh + │ │ │ └── columns: f:17 g:18 h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + │ │ └── filters (true) + │ └── filters + │ └── a:9 = f:17 + └── aggregations + ├── first-agg [as=a:9] + │ └── a:9 + ├── first-agg [as=b:10] + │ └── b:10 + ├── first-agg [as=c:11] + │ └── c:11 + ├── first-agg [as=d:12] + │ └── d:12 + ├── first-agg [as=e:13] + │ └── e:13 + ├── first-agg [as=abcde.crdb_internal_mvcc_timestamp:15] + │ └── abcde.crdb_internal_mvcc_timestamp:15 + ├── first-agg [as=abcde.tableoid:16] + │ └── abcde.tableoid:16 + ├── first-agg [as=f:17] + │ └── f:17 + ├── first-agg [as=g:18] + │ └── g:18 + ├── first-agg [as=h:19] + │ └── h:19 + ├── first-agg [as=fgh.rowid:20] + │ └── fgh.rowid:20 + ├── first-agg [as=fgh.crdb_internal_mvcc_timestamp:21] + │ └── fgh.crdb_internal_mvcc_timestamp:21 + └── first-agg [as=fgh.tableoid:22] + └── fgh.tableoid:22 + +# Test if returning returns columns in the target table and USING table. +build +DELETE FROM abcde USING fgh WHERE abcde.a = fgh.f RETURNING fgh.f, abcde.a +---- +project + ├── columns: f:17 a:1!null + └── delete abcde + ├── columns: a:1!null b:2 c:3 d:4 e:5 abcde.rowid:6!null f:17 g:18 h:19 fgh.rowid:20 fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + ├── fetch columns: a:9 b:10 c:11 d:12 e:13 abcde.rowid:14 + ├── return-mapping: + │ ├── a:9 => a:1 + │ ├── b:10 => b:2 + │ ├── c:11 => c:3 + │ ├── d:12 => d:4 + │ ├── e:13 => e:5 + │ └── abcde.rowid:14 => abcde.rowid:6 + ├── passthrough columns f:17 g:18 h:19 fgh.rowid:20 fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + └── distinct-on + ├── columns: a:9!null b:10 c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 f:17!null g:18 h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + ├── grouping columns: abcde.rowid:14!null + ├── select + │ ├── columns: a:9!null b:10 c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 f:17!null g:18 h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + │ ├── inner-join (cross) + │ │ ├── columns: a:9!null b:10 c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 f:17 g:18 h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + │ │ ├── scan abcde + │ │ │ ├── columns: a:9!null b:10 c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 + │ │ │ └── computed column expressions + │ │ │ ├── d:12 + │ │ │ │ └── (b:10 + c:11) + 1 + │ │ │ └── e:13 + │ │ │ └── a:9 + │ │ ├── scan fgh + │ │ │ └── columns: f:17 g:18 h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + │ │ └── filters (true) + │ └── filters + │ └── a:9 = f:17 + └── aggregations + ├── first-agg [as=a:9] + │ └── a:9 + ├── first-agg [as=b:10] + │ └── b:10 + ├── first-agg [as=c:11] + │ └── c:11 + ├── first-agg [as=d:12] + │ └── d:12 + ├── first-agg [as=e:13] + │ └── e:13 + ├── first-agg [as=abcde.crdb_internal_mvcc_timestamp:15] + │ └── abcde.crdb_internal_mvcc_timestamp:15 + ├── first-agg [as=abcde.tableoid:16] + │ └── abcde.tableoid:16 + ├── first-agg [as=f:17] + │ └── f:17 + ├── first-agg [as=g:18] + │ └── g:18 + ├── first-agg [as=h:19] + │ └── h:19 + ├── first-agg [as=fgh.rowid:20] + │ └── fgh.rowid:20 + ├── first-agg [as=fgh.crdb_internal_mvcc_timestamp:21] + │ └── fgh.crdb_internal_mvcc_timestamp:21 + └── first-agg [as=fgh.tableoid:22] + └── fgh.tableoid:22 + +# Test if DELETE FROM ... USING works with LATERAL. +build +DELETE FROM abcde USING fgh, LATERAL (SELECT x FROM xyz WHERE fgh.g > xyz.x) AS other WHERE other.x = 'a' +---- +delete abcde + ├── columns: + ├── fetch columns: a:9 b:10 c:11 d:12 e:13 abcde.rowid:14 + ├── passthrough columns f:17 g:18 h:19 fgh.rowid:20 fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 x:23 + └── distinct-on + ├── columns: a:9!null b:10 c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 f:17 g:18 h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 x:23!null + ├── grouping columns: abcde.rowid:14!null + ├── select + │ ├── columns: a:9!null b:10 c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 f:17 g:18 h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 x:23!null + │ ├── inner-join (cross) + │ │ ├── columns: a:9!null b:10 c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 f:17 g:18 h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 x:23!null + │ │ ├── scan abcde + │ │ │ ├── columns: a:9!null b:10 c:11 d:12 e:13 abcde.rowid:14!null abcde.crdb_internal_mvcc_timestamp:15 abcde.tableoid:16 + │ │ │ └── computed column expressions + │ │ │ ├── d:12 + │ │ │ │ └── (b:10 + c:11) + 1 + │ │ │ └── e:13 + │ │ │ └── a:9 + │ │ ├── inner-join-apply + │ │ │ ├── columns: f:17 g:18 h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 x:23!null + │ │ │ ├── scan fgh + │ │ │ │ └── columns: f:17 g:18 h:19 fgh.rowid:20!null fgh.crdb_internal_mvcc_timestamp:21 fgh.tableoid:22 + │ │ │ ├── project + │ │ │ │ ├── columns: x:23!null + │ │ │ │ └── select + │ │ │ │ ├── columns: x:23!null y:24 z:25 xyz.crdb_internal_mvcc_timestamp:26 xyz.tableoid:27 + │ │ │ │ ├── scan xyz + │ │ │ │ │ └── columns: x:23!null y:24 z:25 xyz.crdb_internal_mvcc_timestamp:26 xyz.tableoid:27 + │ │ │ │ └── filters + │ │ │ │ └── g:18 > x:23 + │ │ │ └── filters (true) + │ │ └── filters (true) + │ └── filters + │ └── x:23 = 'a' + └── aggregations + ├── first-agg [as=a:9] + │ └── a:9 + ├── first-agg [as=b:10] + │ └── b:10 + ├── first-agg [as=c:11] + │ └── c:11 + ├── first-agg [as=d:12] + │ └── d:12 + ├── first-agg [as=e:13] + │ └── e:13 + ├── first-agg [as=abcde.crdb_internal_mvcc_timestamp:15] + │ └── abcde.crdb_internal_mvcc_timestamp:15 + ├── first-agg [as=abcde.tableoid:16] + │ └── abcde.tableoid:16 + ├── first-agg [as=f:17] + │ └── f:17 + ├── first-agg [as=g:18] + │ └── g:18 + ├── first-agg [as=h:19] + │ └── h:19 + ├── first-agg [as=fgh.rowid:20] + │ └── fgh.rowid:20 + ├── first-agg [as=fgh.crdb_internal_mvcc_timestamp:21] + │ └── fgh.crdb_internal_mvcc_timestamp:21 + ├── first-agg [as=fgh.tableoid:22] + │ └── fgh.tableoid:22 + └── first-agg [as=x:23] + └── x:23 + +# Test if DELETE FROM ... USING works with check constraints. + +exec-ddl +CREATE TABLE ccnstrnt ( + a DECIMAL(10, 2), + CHECK (a > 0) +) +---- + +build +DELETE FROM ccnstrnt c USING (VALUES (1.0)) v(b) WHERE c.a = v.b RETURNING c.a, v.b +---- +project + ├── columns: a:1!null b:9 + └── delete ccnstrnt [as=c] + ├── columns: a:1!null rowid:2!null column1:9 + ├── fetch columns: a:5 rowid:6 + ├── return-mapping: + │ ├── a:5 => a:1 + │ └── rowid:6 => rowid:2 + ├── passthrough columns column1:9 + └── distinct-on + ├── columns: a:5!null rowid:6!null crdb_internal_mvcc_timestamp:7 tableoid:8 column1:9!null + ├── grouping columns: rowid:6!null + ├── select + │ ├── columns: a:5!null rowid:6!null crdb_internal_mvcc_timestamp:7 tableoid:8 column1:9!null + │ ├── inner-join (cross) + │ │ ├── columns: a:5 rowid:6!null crdb_internal_mvcc_timestamp:7 tableoid:8 column1:9!null + │ │ ├── scan ccnstrnt [as=c] + │ │ │ └── columns: a:5 rowid:6!null crdb_internal_mvcc_timestamp:7 tableoid:8 + │ │ ├── values + │ │ │ ├── columns: column1:9!null + │ │ │ └── (1.0,) + │ │ └── filters (true) + │ └── filters + │ └── a:5 = column1:9 + └── aggregations + ├── first-agg [as=a:5] + │ └── a:5 + ├── first-agg [as=crdb_internal_mvcc_timestamp:7] + │ └── crdb_internal_mvcc_timestamp:7 + ├── first-agg [as=tableoid:8] + │ └── tableoid:8 + └── first-agg [as=column1:9] + └── column1:9 + +# Test that multiple of the same table in the USING clause returns an error. +build +DELETE FROM abcde USING xyz, fgh, fgh WHERE fgh.f = abcde.a +---- +error (42712): source name "fgh" specified more than once (missing AS clause) + +# Test if DELETE FROM ... USING works with partial indexes +exec-ddl +CREATE INDEX ON fgh (f, g) WHERE h > 3 +---- + +build +DELETE FROM fgh USING (VALUES (5.0, 6.0)) v(b) WHERE fgh.h = v.b +---- +delete fgh + ├── columns: + ├── fetch columns: f:7 g:8 h:9 rowid:10 + ├── passthrough columns column1:13 column2:14 + ├── partial index del columns: partial_index_del1:15 + └── project + ├── columns: partial_index_del1:15!null f:7 g:8 h:9!null rowid:10!null crdb_internal_mvcc_timestamp:11 tableoid:12 column1:13!null column2:14!null + ├── distinct-on + │ ├── columns: f:7 g:8 h:9!null rowid:10!null crdb_internal_mvcc_timestamp:11 tableoid:12 column1:13!null column2:14!null + │ ├── grouping columns: rowid:10!null + │ ├── select + │ │ ├── columns: f:7 g:8 h:9!null rowid:10!null crdb_internal_mvcc_timestamp:11 tableoid:12 column1:13!null column2:14!null + │ │ ├── inner-join (cross) + │ │ │ ├── columns: f:7 g:8 h:9 rowid:10!null crdb_internal_mvcc_timestamp:11 tableoid:12 column1:13!null column2:14!null + │ │ │ ├── scan fgh + │ │ │ │ ├── columns: f:7 g:8 h:9 rowid:10!null crdb_internal_mvcc_timestamp:11 tableoid:12 + │ │ │ │ └── partial index predicates + │ │ │ │ └── fgh_f_g_idx: filters + │ │ │ │ └── h:9 > 3 + │ │ │ ├── values + │ │ │ │ ├── columns: column1:13!null column2:14!null + │ │ │ │ └── (5.0, 6.0) + │ │ │ └── filters (true) + │ │ └── filters + │ │ └── h:9 = column1:13 + │ └── aggregations + │ ├── first-agg [as=f:7] + │ │ └── f:7 + │ ├── first-agg [as=g:8] + │ │ └── g:8 + │ ├── first-agg [as=h:9] + │ │ └── h:9 + │ ├── first-agg [as=crdb_internal_mvcc_timestamp:11] + │ │ └── crdb_internal_mvcc_timestamp:11 + │ ├── first-agg [as=tableoid:12] + │ │ └── tableoid:12 + │ ├── first-agg [as=column1:13] + │ │ └── column1:13 + │ └── first-agg [as=column2:14] + │ └── column2:14 + └── projections + └── h:9 > 3 [as=partial_index_del1:15]