diff --git a/docs/generated/sql/functions.md b/docs/generated/sql/functions.md index fd56756a8447..6621189e85e9 100644 --- a/docs/generated/sql/functions.md +++ b/docs/generated/sql/functions.md @@ -2829,6 +2829,8 @@ may increase either contention or retry errors, or both.

crdb_internal.approximate_timestamp(timestamp: decimal) → timestamp

Converts the crdb_internal_mvcc_timestamp column into an approximate timestamp.

+crdb_internal.assignment_cast(val: anyelement, type: anyelement) → anyelement

This function is used internally to perform assignment casts during mutations.

+
crdb_internal.check_consistency(stats_only: bool, start_key: bytes, end_key: bytes) → tuple{int AS range_id, bytes AS start_key, string AS start_key_pretty, string AS status, string AS detail}

Runs a consistency check on ranges touching the specified key range. an empty start or end key is treated as the minimum and maximum possible, respectively. stats_only should only be set to false when targeting a small number of ranges to avoid overloading the cluster. Each returned row contains the range ID, the status (a roachpb.CheckConsistencyResponse_Status), and verbose detail.

Example usage: SELECT * FROM crdb_internal.check_consistency(true, ‘\x02’, ‘\x04’)

diff --git a/pkg/sql/colexec/builtin_funcs.go b/pkg/sql/colexec/builtin_funcs.go index 35458d45dfbc..a4818ea6867f 100644 --- a/pkg/sql/colexec/builtin_funcs.go +++ b/pkg/sql/colexec/builtin_funcs.go @@ -20,6 +20,7 @@ import ( "github.com/cockroachdb/cockroach/pkg/sql/execinfra" "github.com/cockroachdb/cockroach/pkg/sql/sem/tree" "github.com/cockroachdb/cockroach/pkg/sql/types" + "github.com/cockroachdb/errors" ) type defaultBuiltinFuncOperator struct { @@ -118,7 +119,11 @@ func NewBuiltinFunctionOperator( outputIdx int, input colexecop.Operator, ) (colexecop.Operator, error) { - switch funcExpr.ResolvedOverload().SpecializedVecBuiltin { + overload := funcExpr.ResolvedOverload() + if overload.FnWithExprs != nil { + return nil, errors.New("builtins with FnWithExprs are not supported in the vectorized engine") + } + switch overload.SpecializedVecBuiltin { case tree.SubstringStringIntInt: input = colexecutils.NewVectorTypeEnforcer(allocator, input, types.String, outputIdx) return newSubstringOperator( diff --git a/pkg/sql/insert.go b/pkg/sql/insert.go index f4c1ce39ad30..670e8c454b6a 100644 --- a/pkg/sql/insert.go +++ b/pkg/sql/insert.go @@ -123,7 +123,7 @@ func (r *insertRun) initRowContainer(params runParams, columns colinfo.ResultCol // processSourceRow processes one row from the source for insertion and, if // result rows are needed, saves it in the result row container. func (r *insertRun) processSourceRow(params runParams, rowVals tree.Datums) error { - if err := enforceLocalColumnConstraints(rowVals, r.insertCols); err != nil { + if err := enforceLocalColumnConstraints(rowVals, r.insertCols, false /* isUpdate */); err != nil { return err } diff --git a/pkg/sql/logictest/testdata/logic_test/alter_column_type b/pkg/sql/logictest/testdata/logic_test/alter_column_type index 44d0ae7c1173..cfad19db8249 100644 --- a/pkg/sql/logictest/testdata/logic_test/alter_column_type +++ b/pkg/sql/logictest/testdata/logic_test/alter_column_type @@ -200,9 +200,6 @@ rowid INT8 false unique_rowid() · {primary} true statement ok INSERT INTO t2 VALUES ('5') -statement error pq: value type int doesn't match type string of column "id" -INSERT INTO t2 VALUES (6) - # Verify ALTER COLUMN TYPE from INT to STRING works correctly. # Column order should stay the same. statement ok diff --git a/pkg/sql/logictest/testdata/logic_test/array b/pkg/sql/logictest/testdata/logic_test/array index b6cbe109cac7..0e2a3a948834 100644 --- a/pkg/sql/logictest/testdata/logic_test/array +++ b/pkg/sql/logictest/testdata/logic_test/array @@ -810,7 +810,7 @@ SELECT * FROM a {hello} {goodbye} -statement error value type collatedstring{fr}\[\] doesn't match type collatedstring{en}\[\] of column "b" +statement ok INSERT INTO a VALUES (ARRAY['hello' COLLATE fr]) statement ok @@ -841,7 +841,7 @@ CREATE TABLE a (b STRING[]) statement ok INSERT INTO a VALUES (ARRAY['foo']) -statement error value type collatedstring{en}\[\] doesn't match type string\[\] of column "b" +statement ok INSERT INTO a VALUES (ARRAY['foo' COLLATE en]) statement ok diff --git a/pkg/sql/logictest/testdata/logic_test/cast b/pkg/sql/logictest/testdata/logic_test/cast index b3724a73a510..266ce86051f3 100644 --- a/pkg/sql/logictest/testdata/logic_test/cast +++ b/pkg/sql/logictest/testdata/logic_test/cast @@ -1,3 +1,179 @@ +# Tests for assignment casts. +subtest assignment_casts + +statement ok +CREATE TABLE assn_cast ( + c CHAR, + vc VARCHAR(1), + qc "char", + b BIT, + i INT, + t timestamp, + d DECIMAL(10, 0), + s STRING +) + +statement ok +INSERT INTO assn_cast(c) VALUES ('a') + +statement ok +INSERT INTO assn_cast(c) VALUES (null), ('b') + +statement error value too long for type CHAR +INSERT INTO assn_cast(c) VALUES ('abc') + +query T +INSERT INTO assn_cast(c) VALUES (1) RETURNING c +---- +1 + +statement error value too long for type CHAR +INSERT INTO assn_cast(c) VALUES (123) + +statement ok +PREPARE insert_c AS INSERT INTO assn_cast(c) VALUES ($1) + +statement error value too long for type CHAR +EXECUTE insert_c('foo') + +statement error value too long for type CHAR +EXECUTE insert_c('foo'::STRING) + +statement ok +DELETE FROM assn_cast + +statement +EXECUTE insert_c(' ') + +statement +EXECUTE insert_c(' '::STRING) + +# Length should be 0 for both rows because CHAR is a blank-padded string type. +query I +SELECT length(c) FROM assn_cast +---- +0 +0 + +statement ok +INSERT INTO assn_cast(vc) VALUES ('a') + +statement ok +INSERT INTO assn_cast(vc) VALUES (null), ('b') + +statement error value too long for type VARCHAR\(1\) +INSERT INTO assn_cast(vc) VALUES ('abc') + +query T +INSERT INTO assn_cast(vc) VALUES (1) RETURNING vc +---- +1 + +statement error value too long for type VARCHAR\(1\) +INSERT INTO assn_cast(vc) VALUES (123) + +statement ok +INSERT INTO assn_cast(qc) VALUES ('a') + +statement ok +INSERT INTO assn_cast(qc) VALUES (null), ('b') + +query T +INSERT INTO assn_cast(qc) VALUES ('abc') RETURNING qc +---- +a + +# Note: This statement fails in Postgres because the default integer type is an +# INT4, and the INT4 -> "char" cast is explicit. Our default integer type +# is an INT8 and INT8 -> "char" is an assignment cast. +query T +INSERT INTO assn_cast(qc) VALUES (123) RETURNING qc +---- +{ + +statement error \"char\" out of range +INSERT INTO assn_cast(qc) VALUES (1234) + +statement ok +PREPARE insert_qc AS INSERT INTO assn_cast(qc) VALUES ($1) + +statement ok +DELETE FROM assn_cast + +statement ok +EXECUTE insert_qc('foo') + +statement ok +EXECUTE insert_qc('foo'::STRING) + +query T +SELECT qc FROM assn_cast +---- +f +f + +statement ok +INSERT into assn_cast(b) VALUES ('1') + +statement ok +INSERT INTO assn_cast(b) VALUES (null), ('1') + +# TODO(mgartner): To match Postgres behavior, this statement should fail with +# the message "value too long for type BIT". +statement ok +INSERT into assn_cast(b) VALUES ('01') + +statement error value type int doesn't match type bit of column \"b\" +INSERT into assn_cast(b) VALUES (1) + +statement ok +INSERT INTO assn_cast(i) VALUES ('1') + +statement ok +INSERT INTO assn_cast(i) VALUES (null), ('1') + +statement ok +PREPARE insert_i AS INSERT INTO assn_cast(i) VALUES ($1) + +statement ok +EXECUTE insert_i('1') + +statement error value type string doesn't match type int of column \"i\" +INSERT INTO assn_cast(i) VALUES ('1'::STRING) + +statement ok +INSERT INTO assn_cast(t) VALUES ('1970-01-01'::timestamptz) + +statement ok +PREPARE insert_d AS INSERT INTO assn_cast(d) VALUES ($1) + +statement ok +EXECUTE insert_d(123.45) + +statement ok +PREPARE insert_d2 AS INSERT INTO assn_cast(d) SELECT * FROM (VALUES ($1::DECIMAL(10, 2))) + +statement ok +EXECUTE insert_d2(67.89) + +query F rowsort +SELECT d FROM assn_cast WHERE d IS NOT NULL +---- +68 +123 + +statement ok +INSERT INTO assn_cast(s) VALUES (1) + +statement ok +PREPARE insert_s AS INSERT INTO assn_cast(s) VALUES ($1) + +# TODO(mgartner): This should succeed to match the behavior of Postgres. +statement error expected EXECUTE parameter expression to have type string, but \'1\' has type int +EXECUTE insert_s(1) + +subtest regressions + statement ok CREATE TABLE t45837 AS SELECT 1.25::decimal AS d diff --git a/pkg/sql/logictest/testdata/logic_test/collatedstring b/pkg/sql/logictest/testdata/logic_test/collatedstring index 2d7c5c94c7b9..79aa830dba7b 100644 --- a/pkg/sql/logictest/testdata/logic_test/collatedstring +++ b/pkg/sql/logictest/testdata/logic_test/collatedstring @@ -231,8 +231,10 @@ INSERT INTO t VALUES ('x' COLLATE en), ('ü' COLLATE en) -statement error value type collatedstring{de} doesn't match type collatedstring{en} of column "a" -INSERT INTO t VALUES ('X' COLLATE de) +statement ok +INSERT INTO t VALUES + ('X' COLLATE de), + ('y' COLLATE de) query T SELECT a FROM t ORDER BY t.a @@ -243,6 +245,8 @@ b B ü x +X +y query T SELECT a FROM t ORDER BY t.a COLLATE da @@ -252,6 +256,8 @@ A b B x +X +y ü query T diff --git a/pkg/sql/logictest/testdata/logic_test/computed b/pkg/sql/logictest/testdata/logic_test/computed index 3162c9edeb70..8df3f2f6a214 100644 --- a/pkg/sql/logictest/testdata/logic_test/computed +++ b/pkg/sql/logictest/testdata/logic_test/computed @@ -883,9 +883,17 @@ CREATE TABLE x ( b INT AS (a+1) STORED ) -query error value type decimal doesn't match type int of column "a" +statement ok INSERT INTO x VALUES(1.4) +query II +SELECT * FROM x +---- +1 2 + +query error value type date doesn't match type int of column "a" +INSERT INTO x VALUES('1970-01-01'::date) + # Regression test for #34901: verify that builtins can be used in computed # column expressions without a "memory budget exceeded" error while backfilling statement ok @@ -1025,3 +1033,33 @@ SET experimental_computed_column_rewrites = "bad" statement error invalid column rewrites expression SET CLUSTER SETTING sql.defaults.experimental_computed_column_rewrites = "bad" + +# Regression test for #69327. Computed columns should be evaluated after +# assignment casts have been performed. +statement ok +CREATE TABLE t69327 ( + c "char", + v STRING AS (c) STORED +); +INSERT INTO t69327 VALUES ('foo'::STRING) + +# Both columns should have a value of "f". +query TT +SELECT * FROM t69327 +---- +f f + +# Regression test for #69665.Computed columns should be evaluated after +# assignment casts have been performed. +statement ok +CREATE TABLE t69665 ( + c CHAR, + v STRING AS (c) STORED +); +INSERT INTO t69665 VALUES (' '::STRING) + +# Both columns should be empty values. +query II +SELECT length(c), length(v) FROM t69665 +---- +0 0 diff --git a/pkg/sql/logictest/testdata/logic_test/insert b/pkg/sql/logictest/testdata/logic_test/insert index 71fe04178406..72cf0b24293a 100644 --- a/pkg/sql/logictest/testdata/logic_test/insert +++ b/pkg/sql/logictest/testdata/logic_test/insert @@ -129,17 +129,20 @@ INSERT INTO kv4 (int, bool) VALUES (3, 'a') statement ok INSERT INTO kv4 (int, bool) VALUES (3, true) -statement error value type int doesn't match type char of column "char" +statement error value too long for type CHAR +INSERT INTO kv4 (int, char) VALUES (4, 11) + +statement ok INSERT INTO kv4 (int, char) VALUES (4, 1) statement ok -INSERT INTO kv4 (int, char) VALUES (4, 'a') +INSERT INTO kv4 (int, char) VALUES (5, 'a') -statement error value type int doesn't match type float of column "float" -INSERT INTO kv4 (int, float) VALUES (5, 1::INT) +statement ok +INSERT INTO kv4 (int, float) VALUES (6, 1::INT) statement ok -INSERT INTO kv4 (int, float) VALUES (5, 2.3) +INSERT INTO kv4 (int, float) VALUES (7, 2.3) query ITBTR rowsort SELECT * from kv4 @@ -147,8 +150,10 @@ SELECT * from kv4 1 NULL NULL NULL NULL 2 1 NULL NULL NULL 3 NULL true NULL NULL -4 NULL NULL a NULL -5 NULL NULL NULL 2.3 +4 NULL NULL 1 NULL +5 NULL NULL a NULL +6 NULL NULL NULL 1 +7 NULL NULL NULL 2.3 statement ok CREATE TABLE kv5 ( @@ -446,7 +451,7 @@ INSERT INTO string_t VALUES ('str') query error value type string doesn't match type bytes of column "b" INSERT INTO bytes_t SELECT * FROM string_t -query error value type bytes doesn't match type string of column "s" +statement ok INSERT INTO string_t SELECT * FROM bytes_t subtest string_width_check diff --git a/pkg/sql/logictest/testdata/logic_test/typing b/pkg/sql/logictest/testdata/logic_test/typing index 33a11d293578..1d0abda00b79 100644 --- a/pkg/sql/logictest/testdata/logic_test/typing +++ b/pkg/sql/logictest/testdata/logic_test/typing @@ -13,8 +13,8 @@ SELECT * FROM f statement ok CREATE TABLE i (x INT) -statement error value type decimal doesn't match type int of column "x" -INSERT INTO i(x) VALUES (4.5) +statement error value type timestamptz doesn't match type int of column "x" +INSERT INTO i(x) VALUES ('1970-01-01'::timestamptz) statement ok INSERT INTO i(x) VALUES (2.0) diff --git a/pkg/sql/opt/exec/execbuilder/format.go b/pkg/sql/opt/exec/execbuilder/format.go index 2d209e37dbdc..117d30280059 100644 --- a/pkg/sql/opt/exec/execbuilder/format.go +++ b/pkg/sql/opt/exec/execbuilder/format.go @@ -29,8 +29,14 @@ func fmtInterceptor(f *memo.ExprFmtCtx, scalar opt.ScalarExpr) string { return "" } - // Let the filters node show up; we will apply the code on each filter. - if scalar.Op() == opt.FiltersOp { + switch scalar.Op() { + case opt.FiltersOp: + // Let the filters node show up; we will apply the code on each filter. + return "" + case opt.AssignmentCastOp: + // Let the AssignmentCast node show up to make it clear in optimizer + // tests that it is a distinct expression and not just a function call + // for crdb_internal.assignment_cast. return "" } diff --git a/pkg/sql/opt/exec/execbuilder/scalar.go b/pkg/sql/opt/exec/execbuilder/scalar.go index ad606e9ebeda..790c893cb782 100644 --- a/pkg/sql/opt/exec/execbuilder/scalar.go +++ b/pkg/sql/opt/exec/execbuilder/scalar.go @@ -14,6 +14,7 @@ import ( "github.com/cockroachdb/cockroach/pkg/sql/opt" "github.com/cockroachdb/cockroach/pkg/sql/opt/exec" "github.com/cockroachdb/cockroach/pkg/sql/opt/memo" + "github.com/cockroachdb/cockroach/pkg/sql/sem/builtins" "github.com/cockroachdb/cockroach/pkg/sql/sem/tree" "github.com/cockroachdb/cockroach/pkg/sql/types" "github.com/cockroachdb/cockroach/pkg/util/log" @@ -37,23 +38,24 @@ func init() { // the functions depend on scalarBuildFuncMap which in turn depends on the // functions). scalarBuildFuncMap = [opt.NumOperators]buildFunc{ - opt.VariableOp: (*Builder).buildVariable, - opt.ConstOp: (*Builder).buildTypedExpr, - opt.NullOp: (*Builder).buildNull, - opt.PlaceholderOp: (*Builder).buildTypedExpr, - opt.TupleOp: (*Builder).buildTuple, - opt.FunctionOp: (*Builder).buildFunction, - opt.CaseOp: (*Builder).buildCase, - opt.CastOp: (*Builder).buildCast, - opt.CoalesceOp: (*Builder).buildCoalesce, - opt.ColumnAccessOp: (*Builder).buildColumnAccess, - opt.ArrayOp: (*Builder).buildArray, - opt.AnyOp: (*Builder).buildAny, - opt.AnyScalarOp: (*Builder).buildAnyScalar, - opt.IndirectionOp: (*Builder).buildIndirection, - opt.CollateOp: (*Builder).buildCollate, - opt.ArrayFlattenOp: (*Builder).buildArrayFlatten, - opt.IfErrOp: (*Builder).buildIfErr, + opt.VariableOp: (*Builder).buildVariable, + opt.ConstOp: (*Builder).buildTypedExpr, + opt.NullOp: (*Builder).buildNull, + opt.PlaceholderOp: (*Builder).buildTypedExpr, + opt.TupleOp: (*Builder).buildTuple, + opt.FunctionOp: (*Builder).buildFunction, + opt.CaseOp: (*Builder).buildCase, + opt.CastOp: (*Builder).buildCast, + opt.AssignmentCastOp: (*Builder).buildAssignmentCast, + opt.CoalesceOp: (*Builder).buildCoalesce, + opt.ColumnAccessOp: (*Builder).buildColumnAccess, + opt.ArrayOp: (*Builder).buildArray, + opt.AnyOp: (*Builder).buildAny, + opt.AnyScalarOp: (*Builder).buildAnyScalar, + opt.IndirectionOp: (*Builder).buildIndirection, + opt.CollateOp: (*Builder).buildCollate, + opt.ArrayFlattenOp: (*Builder).buildArrayFlatten, + opt.IfErrOp: (*Builder).buildIfErr, // Item operators. opt.ProjectionsItemOp: (*Builder).buildItem, @@ -345,6 +347,38 @@ func (b *Builder) buildCast(ctx *buildScalarCtx, scalar opt.ScalarExpr) (tree.Ty return tree.NewTypedCastExpr(input, cast.Typ), nil } +// buildAssignmentCast builds an AssignmentCastExpr with input i and type T into +// a built-in function call crdb_internal.assignment_cast(i, NULL::T). +func (b *Builder) buildAssignmentCast( + ctx *buildScalarCtx, scalar opt.ScalarExpr, +) (tree.TypedExpr, error) { + cast := scalar.(*memo.AssignmentCastExpr) + input, err := b.buildScalar(ctx, cast.Input) + if err != nil { + return nil, err + } + if cast.Typ.Family() == types.TupleFamily { + // TODO(radu): casts to Tuple are not supported (they can't be + // serialized for distsql). This should only happen when the input is + // always NULL so the expression should still be valid without the cast + // (though there could be cornercases where the type does matter). + return input, nil + } + const fnName = "crdb_internal.assignment_cast" + funcRef := tree.WrapFunction(fnName) + props, overloads := builtins.GetBuiltinProperties(fnName) + return tree.NewTypedFuncExpr( + funcRef, + 0, /* aggQualifier */ + tree.TypedExprs{input, tree.NewTypedCastExpr(tree.DNull, cast.Typ)}, + nil, /* filter */ + nil, /* windowDef */ + cast.Typ, + props, + &overloads[0], + ), nil +} + func (b *Builder) buildCoalesce( ctx *buildScalarCtx, scalar opt.ScalarExpr, ) (tree.TypedExpr, error) { diff --git a/pkg/sql/opt/memo/expr_format.go b/pkg/sql/opt/memo/expr_format.go index da9a892d5486..fa4b45c16ddd 100644 --- a/pkg/sql/opt/memo/expr_format.go +++ b/pkg/sql/opt/memo/expr_format.go @@ -1077,8 +1077,9 @@ func (f *ExprFmtCtx) formatScalarPrivate(scalar opt.ScalarExpr) { // We don't want to show the OriginalExpr. private = nil - case *CastExpr: - private = t.Typ.SQLString() + case *CastExpr, *AssignmentCastExpr: + typ := scalar.Private().(*types.T) + private = typ.SQLString() case *KVOptionsItem: fmt.Fprintf(f.Buffer, " %s", t.Key) diff --git a/pkg/sql/opt/memo/logical_props_builder.go b/pkg/sql/opt/memo/logical_props_builder.go index 13be2b781d3a..1367102adac8 100644 --- a/pkg/sql/opt/memo/logical_props_builder.go +++ b/pkg/sql/opt/memo/logical_props_builder.go @@ -1594,8 +1594,9 @@ func BuildSharedProps(e opt.Expr, shared *props.Shared, evalCtx *tree.EvalContex case *FunctionExpr: shared.VolatilitySet.Add(t.Overload.Volatility) - case *CastExpr: - from, to := t.Input.DataType(), t.Typ + case *CastExpr, *AssignmentCastExpr: + from := e.Child(0).(opt.ScalarExpr).DataType() + to := e.Private().(*types.T) volatility, ok := tree.LookupCastVolatility(from, to, evalCtx.SessionData()) if !ok { panic(errors.AssertionFailedf("no volatility for cast %s::%s", from, to)) diff --git a/pkg/sql/opt/ops/scalar.opt b/pkg/sql/opt/ops/scalar.opt index 6319484c3653..dcf85083cc5e 100644 --- a/pkg/sql/opt/ops/scalar.opt +++ b/pkg/sql/opt/ops/scalar.opt @@ -267,7 +267,7 @@ define ZipItem { Cols ColList } -# And is the boolean conjunction operator that evalutes to true only if both of +# And is the boolean conjunction operator that evaluates to true only if both of # its conditions evaluate to true. [Scalar, Bool] define And { @@ -630,8 +630,8 @@ define UnaryCbrt { Input ScalarExpr } -# Cast converts the input expression into an expression of the target type. -# Note that the conversion may cause trunction based on the target types' width, +# Cast converts the input expression into an expression of the target type. Note +# that the conversion may cause truncation based on the target types' width, # such as in this example: # # 'hello'::VARCHAR(2) @@ -645,6 +645,23 @@ define Cast { Typ Type } +# AssignmentCast is similar to CastExpr, but is performed in the context of an +# INSERT, UPDATE, or UPSERT to match the type of a mutation value to the type of +# the target column. An expression separate from CastExpr is required because it +# behaves slightly differently than an explicit cast. For example, while an +# explicit cast will truncate a value to fit the width of a type, an assignment +# cast will error instead if the value does not fit the type. See +# tree.CastContext for more details. +# +# An assignment cast is represented as a distinct expression within the +# optimizer, but is built into a crdb_internal.assignment_cast function call in +# execbuilder. +[Scalar] +define AssignmentCast { + Input ScalarExpr + Typ Type +} + # IfErr is roughly a runtime try-catch operator. It has different semantics # depending on which of its fields are set. # diff --git a/pkg/sql/opt/optbuilder/insert.go b/pkg/sql/opt/optbuilder/insert.go index 3a47a9ecd7e5..c38765b13a12 100644 --- a/pkg/sql/opt/optbuilder/insert.go +++ b/pkg/sql/opt/optbuilder/insert.go @@ -255,6 +255,7 @@ func (b *Builder) buildInsert(ins *tree.Insert, inScope *scope) (outScope *scope // // INSERT INTO DEFAULT VALUES // + isUpsert := ins.OnConflict != nil && !ins.OnConflict.DoNothing if !ins.DefaultValues() { // Replace any DEFAULT expressions in the VALUES clause, if a VALUES clause // exists: @@ -263,15 +264,15 @@ func (b *Builder) buildInsert(ins *tree.Insert, inScope *scope) (outScope *scope // rows := mb.replaceDefaultExprs(ins.Rows) - mb.buildInputForInsert(inScope, rows) + mb.buildInputForInsert(inScope, rows, isUpsert) } else { - mb.buildInputForInsert(inScope, nil /* rows */) + mb.buildInputForInsert(inScope, nil /* rows */, isUpsert) } // Add default columns that were not explicitly specified by name or // implicitly targeted by input columns. Also add any computed columns. In // both cases, include columns undergoing mutations in the write-only state. - mb.addSynthesizedColsForInsert() + mb.addSynthesizedColsForInsert(isUpsert) var returning tree.ReturningExprs if resultsNeeded(ins.Returning) { @@ -553,7 +554,9 @@ func (mb *mutationBuilder) addTargetTableColsForInsert(maxCols int) { // buildInputForInsert constructs the memo group for the input expression and // constructs a new output scope containing that expression's output columns. -func (mb *mutationBuilder) buildInputForInsert(inScope *scope, inputRows *tree.Select) { +func (mb *mutationBuilder) buildInputForInsert( + inScope *scope, inputRows *tree.Select, isUpsert bool, +) { // Handle DEFAULT VALUES case by creating a single empty row as input. if inputRows == nil { mb.outScope = inScope.push() @@ -603,16 +606,23 @@ func (mb *mutationBuilder) buildInputForInsert(inScope *scope, inputRows *tree.S mb.addTargetTableColsForInsert(len(mb.outScope.cols)) } + if !isUpsert { + mb.outScope = mb.addAssignmentCasts(mb.outScope, desiredTypes) + } + // Loop over input columns and: // 1. Type check each column + // 2. Check if the INSERT violates a GENERATED ALWAYS AS IDENTITY column. // 2. Assign name to each column // 3. Add column ID to the insertColIDs list. for i := range mb.outScope.cols { inCol := &mb.outScope.cols[i] ord := mb.tabID.ColumnOrdinal(mb.targetColList[i]) - // Type check the input column against the corresponding table column. - checkDatumTypeFitsColumnType(mb.tab.Column(ord), inCol.typ) + if isUpsert { + // Type check the input column against the corresponding table column. + checkDatumTypeFitsColumnType(mb.tab.Column(ord), inCol.typ) + } // Check if the input column is created with `GENERATED ALWAYS AS IDENTITY` // syntax. If yes, and user does not specify the `OVERRIDING SYSTEM VALUE` @@ -634,7 +644,7 @@ func (mb *mutationBuilder) buildInputForInsert(inScope *scope, inputRows *tree.S // columns that are not yet part of the target column list. This includes all // write-only mutation columns, since they must always have default or computed // values. -func (mb *mutationBuilder) addSynthesizedColsForInsert() { +func (mb *mutationBuilder) addSynthesizedColsForInsert(isUpsert bool) { // Start by adding non-computed columns that have not already been explicitly // specified in the query. Do this before adding computed columns, since those // may depend on non-computed columns. @@ -646,13 +656,17 @@ func (mb *mutationBuilder) addSynthesizedColsForInsert() { // Possibly round DECIMAL-related columns containing insertion values (whether // synthesized or not). - mb.roundDecimalValues(mb.insertColIDs, false /* roundComputedCols */) + if isUpsert { + mb.roundDecimalValues(mb.insertColIDs, false /* roundComputedCols */) + } // Now add all computed columns. mb.addSynthesizedComputedCols(mb.insertColIDs, false /* restrict */) // Possibly round DECIMAL-related computed columns. - mb.roundDecimalValues(mb.insertColIDs, true /* roundComputedCols */) + if isUpsert { + mb.roundDecimalValues(mb.insertColIDs, true /* roundComputedCols */) + } } // buildInsert constructs an Insert operator, possibly wrapped by a Project diff --git a/pkg/sql/opt/optbuilder/mutation_builder.go b/pkg/sql/opt/optbuilder/mutation_builder.go index addf91e903de..b9d2f5d1741f 100644 --- a/pkg/sql/opt/optbuilder/mutation_builder.go +++ b/pkg/sql/opt/optbuilder/mutation_builder.go @@ -1370,6 +1370,7 @@ func resultsNeeded(r tree.ReturningClause) bool { // be different (eg. TEXT and VARCHAR will fit the same scalar type String). // // This is used by the UPDATE, INSERT and UPSERT code. +// TODO(mgartner): Remove this once assignment casts are fully supported. func checkDatumTypeFitsColumnType(col *cat.Column, typ *types.T) { if typ.Equivalent(col.DatumType()) { return @@ -1383,6 +1384,62 @@ func checkDatumTypeFitsColumnType(col *cat.Column, typ *types.T) { panic(err) } +// addAssignmentCasts builds a projection that wraps mutation values with +// assignment casts when possible so that the resulting columns have types +// identical to those in outTypes. If all the columns in inScope already have +// identical types, then no projection is built. If there is no valid assignment +// cast from a column type in inScope to the corresponding target column type, +// then this function will error. +func (mb *mutationBuilder) addAssignmentCasts(inScope *scope, outTypes []*types.T) *scope { + expr := inScope.expr.(memo.RelExpr) + + // Do a quick check to see if any casts are needed. + castRequired := false + for i := 0; i < len(inScope.cols); i++ { + if !inScope.cols[i].typ.Identical(outTypes[i]) { + castRequired = true + break + } + } + if !castRequired { + // No mutation casts are needed. + return inScope + } + + projectionScope := inScope.push() + projectionScope.cols = make([]scopeColumn, 0, len(inScope.cols)) + for i := 0; i < len(inScope.cols); i++ { + srcType := inScope.cols[i].typ + targetType := outTypes[i] + if !srcType.Identical(targetType) { + // Check if an assignment cast is available from the inScope column + // type to the out type. + if !tree.ValidCast(srcType, targetType, tree.CastContextAssignment) { + ord := mb.tabID.ColumnOrdinal(mb.targetColList[i]) + colName := string(mb.tab.Column(ord).ColName()) + err := pgerror.Newf(pgcode.DatatypeMismatch, + "value type %s doesn't match type %s of column %q", + srcType, targetType, tree.ErrNameString(colName)) + err = errors.WithHint(err, "you will need to rewrite or cast the expression") + panic(err) + } + + // Create a new column which casts the input column to the correct + // type. + variable := mb.b.factory.ConstructVariable(inScope.cols[i].id) + cast := mb.b.factory.ConstructAssignmentCast(variable, outTypes[i]) + mb.b.synthesizeColumn(projectionScope, inScope.cols[i].name, outTypes[i], nil /* expr */, cast) + } else { + // The column is already the correct type, so add it as a + // passthrough column. + projectionScope.appendColumn(&inScope.cols[i]) + } + } + + projectionScope.expr = mb.b.constructProject(expr, projectionScope.cols) + return projectionScope +} + // checkColumnIsNotGeneratedAlwaysAsIdentity verifies that if current column // is not created as an IDENTITY column with the // `GENERATED ALWAYS AS IDENTITY` syntax. diff --git a/pkg/sql/opt/optbuilder/testdata/insert b/pkg/sql/opt/optbuilder/testdata/insert index d4874a080430..369e877b861a 100644 --- a/pkg/sql/opt/optbuilder/testdata/insert +++ b/pkg/sql/opt/optbuilder/testdata/insert @@ -53,6 +53,15 @@ CREATE TABLE decimals ( ) ---- +exec-ddl +CREATE TABLE assn_cast ( + c CHAR, + qc "char", + i INT, + s STRING +) +---- + exec-ddl CREATE TABLE on_update_bare ( a INT NOT NULL, @@ -747,7 +756,25 @@ insert abcde build INSERT INTO xyz (x) VALUES (10) ---- -error (42804): value type int doesn't match type string of column "x" +insert xyz + ├── columns: + ├── insert-mapping: + │ ├── column1:7 => x:1 + │ ├── y_default:8 => y:2 + │ └── z_default:9 => z:3 + └── project + ├── columns: y_default:8 z_default:9 column1:7 + ├── project + │ ├── columns: column1:7 + │ ├── values + │ │ ├── columns: column1:6!null + │ │ └── (10,) + │ └── projections + │ └── assignment-cast: STRING [as=column1:7] + │ └── column1:6 + └── projections + ├── NULL::INT8 [as=y_default:8] + └── NULL::FLOAT8 [as=z_default:9] # Try to insert into computed column. build @@ -1154,7 +1181,7 @@ insert checks └── abcde.a:7 > 0 [as=check2:17] # ------------------------------------------------------------------------------ -# Test decimal column rounding. +# Test assignment casts. # ------------------------------------------------------------------------------ build @@ -1163,37 +1190,96 @@ INSERT INTO decimals (a, b) VALUES (1.1, ARRAY[0.95, NULL, 15]) insert decimals ├── columns: ├── insert-mapping: - │ ├── a:10 => decimals.a:1 - │ ├── b:11 => decimals.b:2 - │ ├── c_default:12 => c:3 - │ └── d_comp:14 => d:4 - ├── check columns: check1:15 check2:16 + │ ├── column1:9 => a:1 + │ ├── column2:8 => b:2 + │ ├── c_default:10 => c:3 + │ └── d_comp:11 => d:4 + ├── check columns: check1:12 check2:13 └── project - ├── columns: check1:15 check2:16 a:10 b:11 c_default:12 d_comp:14 + ├── columns: check1:12 check2:13 column2:8 column1:9 c_default:10!null d_comp:11 ├── project - │ ├── columns: d_comp:14 a:10 b:11 c_default:12 + │ ├── columns: d_comp:11 column2:8 column1:9 c_default:10!null │ ├── project - │ │ ├── columns: d_comp:13 a:10 b:11 c_default:12 + │ │ ├── columns: c_default:10!null column2:8 column1:9 │ │ ├── project - │ │ │ ├── columns: a:10 b:11 c_default:12 - │ │ │ ├── project - │ │ │ │ ├── columns: c_default:9!null column1:7!null column2:8 - │ │ │ │ ├── values - │ │ │ │ │ ├── columns: column1:7!null column2:8 - │ │ │ │ │ └── (1.1, ARRAY[0.95,NULL,15]) - │ │ │ │ └── projections - │ │ │ │ └── 1.23::DECIMAL(10,1) [as=c_default:9] + │ │ │ ├── columns: column1:9 column2:8 + │ │ │ ├── values + │ │ │ │ ├── columns: column1:7!null column2:8 + │ │ │ │ └── (1.1, ARRAY[0.95,NULL,15]) │ │ │ └── projections - │ │ │ ├── crdb_internal.round_decimal_values(column1:7, 0) [as=a:10] - │ │ │ ├── crdb_internal.round_decimal_values(column2:8, 1) [as=b:11] - │ │ │ └── crdb_internal.round_decimal_values(c_default:9, 1) [as=c_default:12] + │ │ │ └── assignment-cast: DECIMAL(10) [as=column1:9] + │ │ │ └── column1:7 │ │ └── projections - │ │ └── (a:10 + c_default:12::DECIMAL)::DECIMAL(10,1) [as=d_comp:13] + │ │ └── 1.23::DECIMAL(10,1) [as=c_default:10] + │ └── projections + │ └── (column1:9::DECIMAL + c_default:10::DECIMAL)::DECIMAL(10,1) [as=d_comp:11] + └── projections + ├── round(column1:9) = column1:9 [as=check1:12] + └── column2:8[0] > 1 [as=check2:13] + +assign-placeholders-norm query-args=(1.1, (ARRAY[0.95, NULL, 15])) +INSERT INTO decimals (a, b) VALUES ($1, $2) +---- +insert decimals + ├── columns: + ├── insert-mapping: + │ ├── column1:9 => a:1 + │ ├── column2:8 => b:2 + │ ├── c_default:10 => c:3 + │ └── d_comp:11 => d:4 + ├── check columns: check1:12 check2:13 + └── project + ├── columns: check1:12 check2:13 d_comp:11 column2:8!null column1:9 c_default:10!null + ├── values + │ ├── columns: column2:8!null c_default:10!null column1:9 + │ └── (ARRAY[0.95,NULL,15], 1.2, crdb_internal.assignment_cast(1.1, NULL::DECIMAL(10))) + └── projections + ├── column1:9 = round(column1:9) [as=check1:12] + ├── CAST(NULL AS BOOL) [as=check2:13] + └── (column1:9::DECIMAL + 1.2)::DECIMAL(10,1) [as=d_comp:11] + +build +INSERT INTO assn_cast (c, qc, i, s) VALUES (' ', 'foo', '1', 2) +---- +insert assn_cast + ├── columns: + ├── insert-mapping: + │ ├── column1:12 => c:1 + │ ├── column2:13 => qc:2 + │ ├── column3:10 => i:3 + │ ├── column4:14 => s:4 + │ └── rowid_default:15 => rowid:5 + └── project + ├── columns: rowid_default:15 column3:10!null column1:12 column2:13 column4:14 + ├── project + │ ├── columns: column1:12 column2:13 column4:14 column3:10!null + │ ├── values + │ │ ├── columns: column1:8!null column2:9!null column3:10!null column4:11!null + │ │ └── ('', 'f', 1, 2) │ └── projections - │ └── crdb_internal.round_decimal_values(d_comp:13, 1) [as=d_comp:14] + │ ├── assignment-cast: CHAR [as=column1:12] + │ │ └── column1:8 + │ ├── assignment-cast: "char" [as=column2:13] + │ │ └── column2:9 + │ └── assignment-cast: STRING [as=column4:14] + │ └── column4:11 └── projections - ├── round(a:10) = a:10 [as=check1:15] - └── b:11[0] > 1 [as=check2:16] + └── unique_rowid() [as=rowid_default:15] + +assign-placeholders-norm query-args=(' ', 'foo', '1') +INSERT INTO assn_cast (c, qc, i) VALUES ($1, $2, $3) +---- +insert assn_cast + ├── columns: + ├── insert-mapping: + │ ├── column1:11 => c:1 + │ ├── column2:12 => qc:2 + │ ├── column3:10 => i:3 + │ ├── s_default:13 => s:4 + │ └── rowid_default:14 => rowid:5 + └── values + ├── columns: column3:10!null s_default:13 rowid_default:14 column1:11 column2:12 + └── (1, CAST(NULL AS STRING), unique_rowid(), crdb_internal.assignment_cast(' ', NULL::CHAR), crdb_internal.assignment_cast('foo', NULL::"char")) # Regression test for #38293; the default values should be separate projections. exec-ddl diff --git a/pkg/sql/opt/optbuilder/update.go b/pkg/sql/opt/optbuilder/update.go index 5d132b1ccd82..01db003562b3 100644 --- a/pkg/sql/opt/optbuilder/update.go +++ b/pkg/sql/opt/optbuilder/update.go @@ -230,6 +230,7 @@ func (mb *mutationBuilder) addUpdateCols(exprs tree.UpdateExprs) { } // Add new column to the projections scope. + // TODO(mgartner): Perform an assignment cast if necessary. targetColMeta := mb.md.ColumnMeta(targetColID) desiredType := targetColMeta.Type texpr := inScope.resolveType(expr, desiredType) diff --git a/pkg/sql/opt/xform/testdata/external/hibernate b/pkg/sql/opt/xform/testdata/external/hibernate index 7e6ca57106ef..d5624a352d98 100644 --- a/pkg/sql/opt/xform/testdata/external/hibernate +++ b/pkg/sql/opt/xform/testdata/external/hibernate @@ -980,37 +980,33 @@ where ---- project ├── columns: id1_2_:1!null address2_2_:2 createdo3_2_:3 name4_2_:4 nickname5_2_:5 version6_2_:6!null - ├── cardinality: [0 - 1] - ├── has-placeholder + ├── immutable, has-placeholder ├── key: (1) ├── fd: (1)-->(2-6) - └── project + └── inner-join (lookup person [as=person0_]) ├── columns: person0_.id:1!null address:2 createdon:3 name:4 nickname:5 version:6!null person_id:12!null - ├── cardinality: [0 - 1] - ├── has-placeholder - ├── key: () - ├── fd: ()-->(1-6,12), (1)==(12), (12)==(1) - └── inner-join (lookup person [as=person0_]) - ├── columns: person0_.id:1!null address:2 createdon:3 name:4 nickname:5 version:6!null phones1_.id:9!null person_id:12!null - ├── key columns: [12] = [1] - ├── lookup columns are key - ├── cardinality: [0 - 1] - ├── has-placeholder - ├── key: () - ├── fd: ()-->(1-6,9,12), (12)==(1), (1)==(12) - ├── select - │ ├── columns: phones1_.id:9!null person_id:12 - │ ├── cardinality: [0 - 1] - │ ├── has-placeholder - │ ├── key: () - │ ├── fd: ()-->(9,12) - │ ├── scan phone [as=phones1_] - │ │ ├── columns: phones1_.id:9!null person_id:12 - │ │ ├── key: (9) - │ │ └── fd: (9)-->(12) - │ └── filters - │ └── phones1_.id:9 = $1 [outer=(9), constraints=(/9: (/NULL - ]), fd=()-->(9)] - └── filters (true) + ├── key columns: [12] = [1] + ├── lookup columns are key + ├── immutable, has-placeholder + ├── key: (12) + ├── fd: (1)-->(2-6), (1)==(12), (12)==(1) + ├── distinct-on + │ ├── columns: person_id:12 + │ ├── grouping columns: person_id:12 + │ ├── immutable, has-placeholder + │ ├── key: (12) + │ └── select + │ ├── columns: phones1_.id:9!null person_id:12 + │ ├── immutable, has-placeholder + │ ├── key: (9) + │ ├── fd: (9)-->(12) + │ ├── scan phone [as=phones1_] + │ │ ├── columns: phones1_.id:9!null person_id:12 + │ │ ├── key: (9) + │ │ └── fd: (9)-->(12) + │ └── filters + │ └── phones1_.id:9 = $1::INT8 [outer=(9), immutable, constraints=(/9: (/NULL - ])] + └── filters (true) opt select @@ -1034,37 +1030,33 @@ where ---- project ├── columns: id1_2_:1!null address2_2_:2 createdo3_2_:3 name4_2_:4 nickname5_2_:5 version6_2_:6!null - ├── cardinality: [0 - 1] - ├── has-placeholder + ├── immutable, has-placeholder ├── key: (1) ├── fd: (1)-->(2-6) - └── project + └── inner-join (lookup person [as=person0_]) ├── columns: person0_.id:1!null address:2 createdon:3 name:4 nickname:5 version:6!null person_id:12!null - ├── cardinality: [0 - 1] - ├── has-placeholder - ├── key: () - ├── fd: ()-->(1-6,12), (1)==(12), (12)==(1) - └── inner-join (lookup person [as=person0_]) - ├── columns: person0_.id:1!null address:2 createdon:3 name:4 nickname:5 version:6!null phones1_.id:9!null person_id:12!null - ├── key columns: [12] = [1] - ├── lookup columns are key - ├── cardinality: [0 - 1] - ├── has-placeholder - ├── key: () - ├── fd: ()-->(1-6,9,12), (12)==(1), (1)==(12) - ├── select - │ ├── columns: phones1_.id:9!null person_id:12 - │ ├── cardinality: [0 - 1] - │ ├── has-placeholder - │ ├── key: () - │ ├── fd: ()-->(9,12) - │ ├── scan phone [as=phones1_] - │ │ ├── columns: phones1_.id:9!null person_id:12 - │ │ ├── key: (9) - │ │ └── fd: (9)-->(12) - │ └── filters - │ └── phones1_.id:9 = $1 [outer=(9), constraints=(/9: (/NULL - ]), fd=()-->(9)] - └── filters (true) + ├── key columns: [12] = [1] + ├── lookup columns are key + ├── immutable, has-placeholder + ├── key: (12) + ├── fd: (1)-->(2-6), (1)==(12), (12)==(1) + ├── distinct-on + │ ├── columns: person_id:12 + │ ├── grouping columns: person_id:12 + │ ├── immutable, has-placeholder + │ ├── key: (12) + │ └── select + │ ├── columns: phones1_.id:9!null person_id:12 + │ ├── immutable, has-placeholder + │ ├── key: (9) + │ ├── fd: (9)-->(12) + │ ├── scan phone [as=phones1_] + │ │ ├── columns: phones1_.id:9!null person_id:12 + │ │ ├── key: (9) + │ │ └── fd: (9)-->(12) + │ └── filters + │ └── phones1_.id:9 = $1::INT8 [outer=(9), immutable, constraints=(/9: (/NULL - ])] + └── filters (true) opt select diff --git a/pkg/sql/opt/xform/testdata/external/nova b/pkg/sql/opt/xform/testdata/external/nova index c38a16def0ec..72db37212099 100644 --- a/pkg/sql/opt/xform/testdata/external/nova +++ b/pkg/sql/opt/xform/testdata/external/nova @@ -184,7 +184,7 @@ project │ │ ├── offset │ │ │ ├── columns: flavors.id:1!null name:2!null memory_mb:3!null vcpus:4!null root_gb:5 ephemeral_gb:6 flavorid:7!null swap:8!null rxtx_factor:9 vcpu_weight:10 disabled:11 is_public:12 flavors.created_at:14 flavors.updated_at:15 true_agg:27 │ │ │ ├── cardinality: [0 - 1] - │ │ │ ├── has-placeholder + │ │ │ ├── immutable, has-placeholder │ │ │ ├── key: () │ │ │ ├── fd: ()-->(1-12,14,15,27) │ │ │ ├── select @@ -261,8 +261,8 @@ project │ │ │ │ │ └── flavors.id:1 │ │ │ │ └── filters │ │ │ │ └── is_public:12 OR (true_agg:27 IS NOT NULL) [outer=(12,27)] - │ │ │ └── $3 - │ │ └── $4 + │ │ │ └── $3::INT8 + │ │ └── $4::INT8 │ └── filters (true) └── filters (true) @@ -350,7 +350,7 @@ sort │ ├── offset │ │ ├── columns: flavors.id:1!null name:2!null memory_mb:3!null vcpus:4!null root_gb:5 ephemeral_gb:6 flavorid:7!null swap:8!null rxtx_factor:9 vcpu_weight:10 disabled:11!null is_public:12 flavors.created_at:14 flavors.updated_at:15 true_agg:38 │ │ ├── internal-ordering: +7 opt(11) - │ │ ├── has-placeholder + │ │ ├── immutable, has-placeholder │ │ ├── key: (1) │ │ ├── fd: ()-->(11), (1)-->(2-10,12,14,15,38), (7)-->(1-6,8-10,12,14,15), (2)-->(1,3-10,12,14,15) │ │ ├── ordering: +7 opt(11) [actual: +7] @@ -517,8 +517,8 @@ sort │ │ │ │ └── flavors.updated_at:15 │ │ │ └── filters │ │ │ └── is_public:12 OR (true_agg:38 IS NOT NULL) [outer=(12,38)] - │ │ └── $3 - │ └── $4 + │ │ └── $3::INT8 + │ └── $4::INT8 └── filters └── flavor_extra_specs_1.flavor_id:43 = flavors.id:1 [outer=(1,43), constraints=(/1: (/NULL - ]; /43: (/NULL - ]), fd=(1)==(43), (43)==(1)] @@ -608,7 +608,7 @@ sort │ ├── offset │ │ ├── columns: instance_types.id:1!null name:2 memory_mb:3!null vcpus:4!null root_gb:5 ephemeral_gb:6 flavorid:7 swap:8!null rxtx_factor:9 vcpu_weight:10 disabled:11 is_public:12 instance_types.deleted:13!null instance_types.deleted_at:14 instance_types.created_at:15 instance_types.updated_at:16 true_agg:30 │ │ ├── internal-ordering: +7,+1 opt(13) - │ │ ├── has-placeholder + │ │ ├── immutable, has-placeholder │ │ ├── key: (1) │ │ ├── fd: ()-->(13), (1)-->(2-12,14-16,30), (7,13)~~>(1-6,8-12,14-16), (2,13)~~>(1,3-12,14-16) │ │ ├── ordering: +7,+1 opt(13) [actual: +7,+1] @@ -709,8 +709,8 @@ sort │ │ │ │ └── instance_types.updated_at:16 │ │ │ └── filters │ │ │ └── is_public:12 OR (true_agg:30 IS NOT NULL) [outer=(12,30)] - │ │ └── $5 - │ └── $6 + │ │ └── $5::INT8 + │ └── $6::INT8 ├── select │ ├── columns: instance_type_extra_specs_1.id:32!null key:33 value:34 instance_type_extra_specs_1.instance_type_id:35!null instance_type_extra_specs_1.deleted:36!null instance_type_extra_specs_1.deleted_at:37 instance_type_extra_specs_1.created_at:38 instance_type_extra_specs_1.updated_at:39 │ ├── has-placeholder @@ -968,7 +968,7 @@ project │ │ ├── offset │ │ │ ├── columns: instance_types.id:1!null name:2!null memory_mb:3!null vcpus:4!null root_gb:5 ephemeral_gb:6 flavorid:7 swap:8!null rxtx_factor:9 vcpu_weight:10 disabled:11 is_public:12 instance_types.deleted:13!null instance_types.deleted_at:14 instance_types.created_at:15 instance_types.updated_at:16 true_agg:30 │ │ │ ├── cardinality: [0 - 1] - │ │ │ ├── has-placeholder + │ │ │ ├── immutable, has-placeholder │ │ │ ├── key: () │ │ │ ├── fd: ()-->(1-16,30) │ │ │ ├── select @@ -1058,8 +1058,8 @@ project │ │ │ │ │ └── instance_types.id:1 │ │ │ │ └── filters │ │ │ │ └── is_public:12 OR (true_agg:30 IS NOT NULL) [outer=(12,30)] - │ │ │ └── $5 - │ │ └── $6 + │ │ │ └── $5::INT8 + │ │ └── $6::INT8 │ └── filters │ └── instance_type_extra_specs_1.deleted:36 = $7 [outer=(36), constraints=(/36: (/NULL - ]), fd=()-->(36)] └── filters (true) @@ -1148,7 +1148,7 @@ project │ │ ├── offset │ │ │ ├── columns: instance_types.id:1!null name:2 memory_mb:3!null vcpus:4!null root_gb:5 ephemeral_gb:6 flavorid:7 swap:8!null rxtx_factor:9 vcpu_weight:10 disabled:11 is_public:12 instance_types.deleted:13!null instance_types.deleted_at:14 instance_types.created_at:15 instance_types.updated_at:16 true_agg:30 │ │ │ ├── cardinality: [0 - 1] - │ │ │ ├── has-placeholder + │ │ │ ├── immutable, has-placeholder │ │ │ ├── key: () │ │ │ ├── fd: ()-->(1-16,30) │ │ │ ├── select @@ -1232,8 +1232,8 @@ project │ │ │ │ │ └── instance_types.id:1 │ │ │ │ └── filters │ │ │ │ └── is_public:12 OR (true_agg:30 IS NOT NULL) [outer=(12,30)] - │ │ │ └── $5 - │ │ └── $6 + │ │ │ └── $5::INT8 + │ │ └── $6::INT8 │ └── filters │ └── instance_type_extra_specs_1.deleted:36 = $7 [outer=(36), constraints=(/36: (/NULL - ]), fd=()-->(36)] └── filters (true) @@ -1313,7 +1313,7 @@ project │ │ ├── offset │ │ │ ├── columns: flavors.id:1!null name:2!null memory_mb:3!null vcpus:4!null root_gb:5 ephemeral_gb:6 flavorid:7!null swap:8!null rxtx_factor:9 vcpu_weight:10 disabled:11 is_public:12 flavors.created_at:14 flavors.updated_at:15 true_agg:27 │ │ │ ├── cardinality: [0 - 1] - │ │ │ ├── has-placeholder + │ │ │ ├── immutable, has-placeholder │ │ │ ├── key: () │ │ │ ├── fd: ()-->(1-12,14,15,27) │ │ │ ├── select @@ -1390,8 +1390,8 @@ project │ │ │ │ │ └── flavors.id:1 │ │ │ │ └── filters │ │ │ │ └── is_public:12 OR (true_agg:27 IS NOT NULL) [outer=(12,27)] - │ │ │ └── $3 - │ │ └── $4 + │ │ │ └── $3::INT8 + │ │ └── $4::INT8 │ └── filters (true) └── filters (true) @@ -1470,7 +1470,7 @@ project │ │ ├── offset │ │ │ ├── columns: flavors.id:1!null name:2!null memory_mb:3!null vcpus:4!null root_gb:5 ephemeral_gb:6 flavorid:7!null swap:8!null rxtx_factor:9 vcpu_weight:10 disabled:11 is_public:12 flavors.created_at:14 flavors.updated_at:15 true_agg:27 │ │ │ ├── cardinality: [0 - 1] - │ │ │ ├── has-placeholder + │ │ │ ├── immutable, has-placeholder │ │ │ ├── key: () │ │ │ ├── fd: ()-->(1-12,14,15,27) │ │ │ ├── select @@ -1547,8 +1547,8 @@ project │ │ │ │ │ └── flavors.id:1 │ │ │ │ └── filters │ │ │ │ └── is_public:12 OR (true_agg:27 IS NOT NULL) [outer=(12,27)] - │ │ │ └── $3 - │ │ └── $4 + │ │ │ └── $3::INT8 + │ │ └── $4::INT8 │ └── filters (true) └── filters (true) @@ -1633,7 +1633,7 @@ sort │ ├── offset │ │ ├── columns: flavors.id:1!null name:2!null memory_mb:3!null vcpus:4!null root_gb:5 ephemeral_gb:6 flavorid:7!null swap:8!null rxtx_factor:9 vcpu_weight:10 disabled:11 is_public:12 flavors.created_at:14 flavors.updated_at:15 true_agg:27 │ │ ├── internal-ordering: +7 - │ │ ├── has-placeholder + │ │ ├── immutable, has-placeholder │ │ ├── key: (1) │ │ ├── fd: (1)-->(2-12,14,15,27), (7)-->(1-6,8-12,14,15), (2)-->(1,3-12,14,15) │ │ ├── ordering: +7 @@ -1728,8 +1728,8 @@ sort │ │ │ │ └── flavors.updated_at:15 │ │ │ └── filters │ │ │ └── is_public:12 OR (true_agg:27 IS NOT NULL) [outer=(12,27)] - │ │ └── $5 - │ └── $6 + │ │ └── $5::INT8 + │ └── $6::INT8 └── filters └── flavor_extra_specs_1.flavor_id:32 = flavors.id:1 [outer=(1,32), constraints=(/1: (/NULL - ]; /32: (/NULL - ]), fd=(1)==(32), (32)==(1)] @@ -1818,7 +1818,7 @@ sort │ ├── offset │ │ ├── columns: instance_types.id:1!null name:2 memory_mb:3!null vcpus:4!null root_gb:5 ephemeral_gb:6 flavorid:7 swap:8!null rxtx_factor:9 vcpu_weight:10 disabled:11 is_public:12 instance_types.deleted:13!null instance_types.deleted_at:14 instance_types.created_at:15 instance_types.updated_at:16 true_agg:30 │ │ ├── internal-ordering: +7,+1 opt(13) - │ │ ├── has-placeholder + │ │ ├── immutable, has-placeholder │ │ ├── key: (1) │ │ ├── fd: ()-->(13), (1)-->(2-12,14-16,30), (7,13)~~>(1-6,8-12,14-16), (2,13)~~>(1,3-12,14-16) │ │ ├── ordering: +7,+1 opt(13) [actual: +7,+1] @@ -1918,8 +1918,8 @@ sort │ │ │ │ └── instance_types.updated_at:16 │ │ │ └── filters │ │ │ └── is_public:12 OR (true_agg:30 IS NOT NULL) [outer=(12,30)] - │ │ └── $4 - │ └── $5 + │ │ └── $4::INT8 + │ └── $5::INT8 ├── select │ ├── columns: instance_type_extra_specs_1.id:32!null key:33 value:34 instance_type_extra_specs_1.instance_type_id:35!null instance_type_extra_specs_1.deleted:36!null instance_type_extra_specs_1.deleted_at:37 instance_type_extra_specs_1.created_at:38 instance_type_extra_specs_1.updated_at:39 │ ├── has-placeholder @@ -2018,7 +2018,7 @@ project │ │ ├── offset │ │ │ ├── columns: instance_types.id:1!null name:2 memory_mb:3!null vcpus:4!null root_gb:5 ephemeral_gb:6 flavorid:7!null swap:8!null rxtx_factor:9 vcpu_weight:10 disabled:11 is_public:12 instance_types.deleted:13!null instance_types.deleted_at:14 instance_types.created_at:15 instance_types.updated_at:16 true_agg:30 │ │ │ ├── cardinality: [0 - 1] - │ │ │ ├── has-placeholder + │ │ │ ├── immutable, has-placeholder │ │ │ ├── key: () │ │ │ ├── fd: ()-->(1-16,30) │ │ │ ├── select @@ -2108,8 +2108,8 @@ project │ │ │ │ │ └── instance_types.id:1 │ │ │ │ └── filters │ │ │ │ └── is_public:12 OR (true_agg:30 IS NOT NULL) [outer=(12,30)] - │ │ │ └── $5 - │ │ └── $6 + │ │ │ └── $5::INT8 + │ │ └── $6::INT8 │ └── filters │ └── instance_type_extra_specs_1.deleted:36 = $7 [outer=(36), constraints=(/36: (/NULL - ]), fd=()-->(36)] └── filters (true) @@ -2344,7 +2344,7 @@ sort │ ├── offset │ │ ├── columns: instance_types.id:1!null name:2 memory_mb:3!null vcpus:4!null root_gb:5 ephemeral_gb:6 flavorid:7!null swap:8!null rxtx_factor:9 vcpu_weight:10 disabled:11 is_public:12 instance_types.deleted:13!null instance_types.deleted_at:14 instance_types.created_at:15 instance_types.updated_at:16 true_agg:30 │ │ ├── internal-ordering: +7 opt(13) - │ │ ├── has-placeholder + │ │ ├── immutable, has-placeholder │ │ ├── key: (1) │ │ ├── fd: ()-->(13), (1)-->(2-12,14-16,30), (7)-->(1-6,8-12,14-16), (2,13)~~>(1,3-12,14-16) │ │ ├── ordering: +7 opt(13) [actual: +7] @@ -2445,8 +2445,8 @@ sort │ │ │ │ └── instance_types.updated_at:16 │ │ │ └── filters │ │ │ └── is_public:12 OR (true_agg:30 IS NOT NULL) [outer=(12,30)] - │ │ └── $7 - │ └── $8 + │ │ └── $7::INT8 + │ └── $8::INT8 └── filters └── instance_type_extra_specs_1.instance_type_id:35 = instance_types.id:1 [outer=(1,35), constraints=(/1: (/NULL - ]; /35: (/NULL - ]), fd=(1)==(35), (35)==(1)] @@ -2525,7 +2525,7 @@ sort │ ├── offset │ │ ├── columns: flavors.id:1!null name:2!null memory_mb:3!null vcpus:4!null root_gb:5 ephemeral_gb:6 flavorid:7!null swap:8!null rxtx_factor:9 vcpu_weight:10 disabled:11 is_public:12 flavors.created_at:14 flavors.updated_at:15 true_agg:27 │ │ ├── internal-ordering: +7 - │ │ ├── has-placeholder + │ │ ├── immutable, has-placeholder │ │ ├── key: (1) │ │ ├── fd: (1)-->(2-12,14,15,27), (7)-->(1-6,8-12,14,15), (2)-->(1,3-12,14,15) │ │ ├── ordering: +7 @@ -2612,8 +2612,8 @@ sort │ │ │ │ └── flavors.updated_at:15 │ │ │ └── filters │ │ │ └── is_public:12 OR (true_agg:27 IS NOT NULL) [outer=(12,27)] - │ │ └── $2 - │ └── $3 + │ │ └── $2::INT8 + │ └── $3::INT8 ├── scan flavor_extra_specs [as=flavor_extra_specs_1] │ ├── columns: flavor_extra_specs_1.id:29!null key:30!null value:31 flavor_extra_specs_1.flavor_id:32!null flavor_extra_specs_1.created_at:33 flavor_extra_specs_1.updated_at:34 │ ├── key: (29) @@ -2724,7 +2724,7 @@ sort │ ├── offset │ │ ├── columns: instance_types.id:1!null name:2 memory_mb:3!null vcpus:4!null root_gb:5 ephemeral_gb:6 flavorid:7 swap:8!null rxtx_factor:9 vcpu_weight:10 disabled:11!null is_public:12 instance_types.deleted:13!null instance_types.deleted_at:14 instance_types.created_at:15 instance_types.updated_at:16 true_agg:43 │ │ ├── internal-ordering: +7,+1 opt(11,13) - │ │ ├── has-placeholder + │ │ ├── immutable, has-placeholder │ │ ├── key: (1) │ │ ├── fd: ()-->(11,13), (1)-->(2-10,12,14-16,43), (7,13)~~>(1-6,8-10,12,14-16), (2,13)~~>(1,3-10,12,14-16) │ │ ├── ordering: +7,+1 opt(11,13) [actual: +7,+1] @@ -2904,8 +2904,8 @@ sort │ │ │ │ └── instance_types.updated_at:16 │ │ │ └── filters │ │ │ └── is_public:12 OR (true_agg:43 IS NOT NULL) [outer=(12,43)] - │ │ └── $7 - │ └── $8 + │ │ └── $7::INT8 + │ └── $8::INT8 └── filters └── instance_type_extra_specs_1.instance_type_id:48 = instance_types.id:1 [outer=(1,48), constraints=(/1: (/NULL - ]; /48: (/NULL - ]), fd=(1)==(48), (48)==(1)] @@ -2996,7 +2996,7 @@ project │ │ ├── offset │ │ │ ├── columns: instance_types.id:1!null name:2 memory_mb:3!null vcpus:4!null root_gb:5 ephemeral_gb:6 flavorid:7!null swap:8!null rxtx_factor:9 vcpu_weight:10 disabled:11 is_public:12 instance_types.deleted:13!null instance_types.deleted_at:14 instance_types.created_at:15 instance_types.updated_at:16 true_agg:30 │ │ │ ├── cardinality: [0 - 1] - │ │ │ ├── has-placeholder + │ │ │ ├── immutable, has-placeholder │ │ │ ├── key: () │ │ │ ├── fd: ()-->(1-16,30) │ │ │ ├── select @@ -3086,8 +3086,8 @@ project │ │ │ │ │ └── instance_types.id:1 │ │ │ │ └── filters │ │ │ │ └── is_public:12 OR (true_agg:30 IS NOT NULL) [outer=(12,30)] - │ │ │ └── $5 - │ │ └── $6 + │ │ │ └── $5::INT8 + │ │ └── $6::INT8 │ └── filters │ └── instance_type_extra_specs_1.deleted:36 = $7 [outer=(36), constraints=(/36: (/NULL - ]), fd=()-->(36)] └── filters (true) @@ -3167,7 +3167,7 @@ project │ │ ├── offset │ │ │ ├── columns: flavors.id:1!null name:2!null memory_mb:3!null vcpus:4!null root_gb:5 ephemeral_gb:6 flavorid:7!null swap:8!null rxtx_factor:9 vcpu_weight:10 disabled:11 is_public:12 flavors.created_at:14 flavors.updated_at:15 true_agg:27 │ │ │ ├── cardinality: [0 - 1] - │ │ │ ├── has-placeholder + │ │ │ ├── immutable, has-placeholder │ │ │ ├── key: () │ │ │ ├── fd: ()-->(1-12,14,15,27) │ │ │ ├── select @@ -3245,8 +3245,8 @@ project │ │ │ │ │ └── flavors.id:1 │ │ │ │ └── filters │ │ │ │ └── is_public:12 OR (true_agg:27 IS NOT NULL) [outer=(12,27)] - │ │ │ └── $3 - │ │ └── $4 + │ │ │ └── $3::INT8 + │ │ └── $4::INT8 │ └── filters (true) └── filters (true) @@ -3408,7 +3408,7 @@ sort │ │ │ └── flavors.updated_at:15 │ │ └── filters │ │ └── is_public:12 OR (true_agg:27 IS NOT NULL) [outer=(12,27)] - │ └── $2 + │ └── $2::INT8 ├── scan flavor_extra_specs [as=flavor_extra_specs_1] │ ├── columns: flavor_extra_specs_1.id:29!null key:30!null value:31 flavor_extra_specs_1.flavor_id:32!null flavor_extra_specs_1.created_at:33 flavor_extra_specs_1.updated_at:34 │ ├── key: (29) diff --git a/pkg/sql/opt/xform/testdata/external/tpcc b/pkg/sql/opt/xform/testdata/external/tpcc index f72e41ab254e..599e13bb30bd 100644 --- a/pkg/sql/opt/xform/testdata/external/tpcc +++ b/pkg/sql/opt/xform/testdata/external/tpcc @@ -364,18 +364,18 @@ insert order_line │ ├── column4:16 => ol_number:4 │ ├── column5:17 => order_line.ol_i_id:5 │ ├── column6:18 => order_line.ol_supply_w_id:6 - │ ├── ol_delivery_d_default:22 => ol_delivery_d:7 + │ ├── ol_delivery_d_default:24 => ol_delivery_d:7 │ ├── column7:19 => ol_quantity:8 - │ ├── ol_amount:23 => order_line.ol_amount:9 - │ └── column9:21 => ol_dist_info:10 + │ ├── column8:22 => ol_amount:9 + │ └── column9:23 => ol_dist_info:10 ├── input binding: &1 ├── cardinality: [0 - 0] ├── volatile, mutations ├── project - │ ├── columns: ol_amount:23 ol_delivery_d_default:22 column1:13!null column2:14!null column3:15!null column4:16!null column5:17!null column6:18!null column7:19!null column9:21!null + │ ├── columns: ol_delivery_d_default:24 column8:22 column9:23 column1:13!null column2:14!null column3:15!null column4:16!null column5:17!null column6:18!null column7:19!null │ ├── cardinality: [6 - 6] │ ├── immutable - │ ├── fd: ()-->(22) + │ ├── fd: ()-->(24) │ ├── values │ │ ├── columns: column1:13!null column2:14!null column3:15!null column4:16!null column5:17!null column6:18!null column7:19!null column8:20!null column9:21!null │ │ ├── cardinality: [6 - 6] @@ -386,34 +386,37 @@ insert order_line │ │ ├── (3045, 2, 10, 4, 56624, 0, 6, 273.360000, 'RsaCXoEzmssaF9m9cdLXe0Yh') │ │ └── (3045, 2, 10, 6, 92966, 0, 4, 366.760000, 'saCXoEzmssaF9m9cdLXe0Yhg') │ └── projections - │ ├── crdb_internal.round_decimal_values(column8:20, 2) [as=ol_amount:23, outer=(20), immutable] - │ └── CAST(NULL AS TIMESTAMP) [as=ol_delivery_d_default:22] + │ ├── CAST(NULL AS TIMESTAMP) [as=ol_delivery_d_default:24] + │ ├── assignment-cast: DECIMAL(6,2) [as=column8:22, outer=(20), immutable] + │ │ └── column8:20 + │ └── assignment-cast: CHAR(24) [as=column9:23, outer=(21), immutable] + │ └── column9:21 └── f-k-checks ├── f-k-checks-item: order_line(ol_w_id,ol_d_id,ol_o_id) -> order(o_w_id,o_d_id,o_id) │ └── anti-join (lookup order) - │ ├── columns: ol_w_id:24!null ol_d_id:25!null ol_o_id:26!null - │ ├── key columns: [24 25 26] = [29 28 27] + │ ├── columns: ol_w_id:25!null ol_d_id:26!null ol_o_id:27!null + │ ├── key columns: [25 26 27] = [30 29 28] │ ├── lookup columns are key │ ├── cardinality: [0 - 6] │ ├── with-scan &1 - │ │ ├── columns: ol_w_id:24!null ol_d_id:25!null ol_o_id:26!null + │ │ ├── columns: ol_w_id:25!null ol_d_id:26!null ol_o_id:27!null │ │ ├── mapping: - │ │ │ ├── column3:15 => ol_w_id:24 - │ │ │ ├── column2:14 => ol_d_id:25 - │ │ │ └── column1:13 => ol_o_id:26 + │ │ │ ├── column3:15 => ol_w_id:25 + │ │ │ ├── column2:14 => ol_d_id:26 + │ │ │ └── column1:13 => ol_o_id:27 │ │ └── cardinality: [6 - 6] │ └── filters (true) └── f-k-checks-item: order_line(ol_supply_w_id,ol_i_id) -> stock(s_w_id,s_i_id) └── anti-join (lookup stock) - ├── columns: ol_supply_w_id:37!null ol_i_id:38!null - ├── key columns: [37 38] = [40 39] + ├── columns: ol_supply_w_id:38!null ol_i_id:39!null + ├── key columns: [38 39] = [41 40] ├── lookup columns are key ├── cardinality: [0 - 6] ├── with-scan &1 - │ ├── columns: ol_supply_w_id:37!null ol_i_id:38!null + │ ├── columns: ol_supply_w_id:38!null ol_i_id:39!null │ ├── mapping: - │ │ ├── column6:18 => ol_supply_w_id:37 - │ │ └── column5:17 => ol_i_id:38 + │ │ ├── column6:18 => ol_supply_w_id:38 + │ │ └── column5:17 => ol_i_id:39 │ └── cardinality: [6 - 6] └── filters (true) @@ -600,60 +603,60 @@ VALUES insert history ├── columns: ├── insert-mapping: - │ ├── rowid_default:20 => rowid:1 + │ ├── rowid_default:22 => rowid:1 │ ├── column1:12 => history.h_c_id:2 │ ├── column2:13 => history.h_c_d_id:3 │ ├── column3:14 => history.h_c_w_id:4 │ ├── column4:15 => history.h_d_id:5 │ ├── column5:16 => history.h_w_id:6 │ ├── column7:18 => h_date:7 - │ ├── h_amount:21 => history.h_amount:8 - │ └── column8:19 => h_data:9 + │ ├── column6:20 => h_amount:8 + │ └── column8:21 => h_data:9 ├── input binding: &1 ├── cardinality: [0 - 0] ├── volatile, mutations ├── values - │ ├── columns: column1:12!null column2:13!null column3:14!null column4:15!null column5:16!null column7:18!null column8:19!null rowid_default:20 h_amount:21!null + │ ├── columns: column1:12!null column2:13!null column3:14!null column4:15!null column5:16!null column7:18!null column6:20 column8:21 rowid_default:22 │ ├── cardinality: [1 - 1] │ ├── volatile │ ├── key: () - │ ├── fd: ()-->(12-16,18-21) - │ └── (1343, 5, 10, 5, 10, '2019-08-26 16:50:41', '8 Kdcgphy3', gen_random_uuid(), 3860.61) + │ ├── fd: ()-->(12-16,18,20-22) + │ └── (1343, 5, 10, 5, 10, '2019-08-26 16:50:41', crdb_internal.assignment_cast(3860.61, NULL::DECIMAL(6,2)), crdb_internal.assignment_cast('8 Kdcgphy3', NULL::VARCHAR(24)), gen_random_uuid()) └── f-k-checks ├── f-k-checks-item: history(h_c_w_id,h_c_d_id,h_c_id) -> customer(c_w_id,c_d_id,c_id) │ └── anti-join (lookup customer) - │ ├── columns: h_c_w_id:22!null h_c_d_id:23!null h_c_id:24!null - │ ├── key columns: [22 23 24] = [27 26 25] + │ ├── columns: h_c_w_id:23!null h_c_d_id:24!null h_c_id:25!null + │ ├── key columns: [23 24 25] = [28 27 26] │ ├── lookup columns are key │ ├── cardinality: [0 - 1] │ ├── key: () - │ ├── fd: ()-->(22-24) + │ ├── fd: ()-->(23-25) │ ├── with-scan &1 - │ │ ├── columns: h_c_w_id:22!null h_c_d_id:23!null h_c_id:24!null + │ │ ├── columns: h_c_w_id:23!null h_c_d_id:24!null h_c_id:25!null │ │ ├── mapping: - │ │ │ ├── column3:14 => h_c_w_id:22 - │ │ │ ├── column2:13 => h_c_d_id:23 - │ │ │ └── column1:12 => h_c_id:24 + │ │ │ ├── column3:14 => h_c_w_id:23 + │ │ │ ├── column2:13 => h_c_d_id:24 + │ │ │ └── column1:12 => h_c_id:25 │ │ ├── cardinality: [1 - 1] │ │ ├── key: () - │ │ └── fd: ()-->(22-24) + │ │ └── fd: ()-->(23-25) │ └── filters (true) └── f-k-checks-item: history(h_w_id,h_d_id) -> district(d_w_id,d_id) └── anti-join (lookup district) - ├── columns: h_w_id:48!null h_d_id:49!null - ├── key columns: [48 49] = [51 50] + ├── columns: h_w_id:49!null h_d_id:50!null + ├── key columns: [49 50] = [52 51] ├── lookup columns are key ├── cardinality: [0 - 1] ├── key: () - ├── fd: ()-->(48,49) + ├── fd: ()-->(49,50) ├── with-scan &1 - │ ├── columns: h_w_id:48!null h_d_id:49!null + │ ├── columns: h_w_id:49!null h_d_id:50!null │ ├── mapping: - │ │ ├── column5:16 => h_w_id:48 - │ │ └── column4:15 => h_d_id:49 + │ │ ├── column5:16 => h_w_id:49 + │ │ └── column4:15 => h_d_id:50 │ ├── cardinality: [1 - 1] │ ├── key: () - │ └── fd: ()-->(48,49) + │ └── fd: ()-->(49,50) └── filters (true) # -------------------------------------------------- diff --git a/pkg/sql/opt/xform/testdata/external/tpcc-later-stats b/pkg/sql/opt/xform/testdata/external/tpcc-later-stats index 305a3e63ded6..ce24b1c8368d 100644 --- a/pkg/sql/opt/xform/testdata/external/tpcc-later-stats +++ b/pkg/sql/opt/xform/testdata/external/tpcc-later-stats @@ -367,18 +367,18 @@ insert order_line │ ├── column4:16 => ol_number:4 │ ├── column5:17 => order_line.ol_i_id:5 │ ├── column6:18 => order_line.ol_supply_w_id:6 - │ ├── ol_delivery_d_default:22 => ol_delivery_d:7 + │ ├── ol_delivery_d_default:24 => ol_delivery_d:7 │ ├── column7:19 => ol_quantity:8 - │ ├── ol_amount:23 => order_line.ol_amount:9 - │ └── column9:21 => ol_dist_info:10 + │ ├── column8:22 => ol_amount:9 + │ └── column9:23 => ol_dist_info:10 ├── input binding: &1 ├── cardinality: [0 - 0] ├── volatile, mutations ├── project - │ ├── columns: ol_amount:23 ol_delivery_d_default:22 column1:13!null column2:14!null column3:15!null column4:16!null column5:17!null column6:18!null column7:19!null column9:21!null + │ ├── columns: ol_delivery_d_default:24 column8:22 column9:23 column1:13!null column2:14!null column3:15!null column4:16!null column5:17!null column6:18!null column7:19!null │ ├── cardinality: [6 - 6] │ ├── immutable - │ ├── fd: ()-->(22) + │ ├── fd: ()-->(24) │ ├── values │ │ ├── columns: column1:13!null column2:14!null column3:15!null column4:16!null column5:17!null column6:18!null column7:19!null column8:20!null column9:21!null │ │ ├── cardinality: [6 - 6] @@ -389,34 +389,37 @@ insert order_line │ │ ├── (3045, 2, 10, 4, 56624, 0, 6, 273.360000, 'RsaCXoEzmssaF9m9cdLXe0Yh') │ │ └── (3045, 2, 10, 6, 92966, 0, 4, 366.760000, 'saCXoEzmssaF9m9cdLXe0Yhg') │ └── projections - │ ├── crdb_internal.round_decimal_values(column8:20, 2) [as=ol_amount:23, outer=(20), immutable] - │ └── CAST(NULL AS TIMESTAMP) [as=ol_delivery_d_default:22] + │ ├── CAST(NULL AS TIMESTAMP) [as=ol_delivery_d_default:24] + │ ├── assignment-cast: DECIMAL(6,2) [as=column8:22, outer=(20), immutable] + │ │ └── column8:20 + │ └── assignment-cast: CHAR(24) [as=column9:23, outer=(21), immutable] + │ └── column9:21 └── f-k-checks ├── f-k-checks-item: order_line(ol_w_id,ol_d_id,ol_o_id) -> order(o_w_id,o_d_id,o_id) │ └── anti-join (lookup order) - │ ├── columns: ol_w_id:24!null ol_d_id:25!null ol_o_id:26!null - │ ├── key columns: [24 25 26] = [29 28 27] + │ ├── columns: ol_w_id:25!null ol_d_id:26!null ol_o_id:27!null + │ ├── key columns: [25 26 27] = [30 29 28] │ ├── lookup columns are key │ ├── cardinality: [0 - 6] │ ├── with-scan &1 - │ │ ├── columns: ol_w_id:24!null ol_d_id:25!null ol_o_id:26!null + │ │ ├── columns: ol_w_id:25!null ol_d_id:26!null ol_o_id:27!null │ │ ├── mapping: - │ │ │ ├── column3:15 => ol_w_id:24 - │ │ │ ├── column2:14 => ol_d_id:25 - │ │ │ └── column1:13 => ol_o_id:26 + │ │ │ ├── column3:15 => ol_w_id:25 + │ │ │ ├── column2:14 => ol_d_id:26 + │ │ │ └── column1:13 => ol_o_id:27 │ │ └── cardinality: [6 - 6] │ └── filters (true) └── f-k-checks-item: order_line(ol_supply_w_id,ol_i_id) -> stock(s_w_id,s_i_id) └── anti-join (lookup stock) - ├── columns: ol_supply_w_id:37!null ol_i_id:38!null - ├── key columns: [37 38] = [40 39] + ├── columns: ol_supply_w_id:38!null ol_i_id:39!null + ├── key columns: [38 39] = [41 40] ├── lookup columns are key ├── cardinality: [0 - 6] ├── with-scan &1 - │ ├── columns: ol_supply_w_id:37!null ol_i_id:38!null + │ ├── columns: ol_supply_w_id:38!null ol_i_id:39!null │ ├── mapping: - │ │ ├── column6:18 => ol_supply_w_id:37 - │ │ └── column5:17 => ol_i_id:38 + │ │ ├── column6:18 => ol_supply_w_id:38 + │ │ └── column5:17 => ol_i_id:39 │ └── cardinality: [6 - 6] └── filters (true) @@ -603,60 +606,60 @@ VALUES insert history ├── columns: ├── insert-mapping: - │ ├── rowid_default:20 => rowid:1 + │ ├── rowid_default:22 => rowid:1 │ ├── column1:12 => history.h_c_id:2 │ ├── column2:13 => history.h_c_d_id:3 │ ├── column3:14 => history.h_c_w_id:4 │ ├── column4:15 => history.h_d_id:5 │ ├── column5:16 => history.h_w_id:6 │ ├── column7:18 => h_date:7 - │ ├── h_amount:21 => history.h_amount:8 - │ └── column8:19 => h_data:9 + │ ├── column6:20 => h_amount:8 + │ └── column8:21 => h_data:9 ├── input binding: &1 ├── cardinality: [0 - 0] ├── volatile, mutations ├── values - │ ├── columns: column1:12!null column2:13!null column3:14!null column4:15!null column5:16!null column7:18!null column8:19!null rowid_default:20 h_amount:21!null + │ ├── columns: column1:12!null column2:13!null column3:14!null column4:15!null column5:16!null column7:18!null column6:20 column8:21 rowid_default:22 │ ├── cardinality: [1 - 1] │ ├── volatile │ ├── key: () - │ ├── fd: ()-->(12-16,18-21) - │ └── (1343, 5, 10, 5, 10, '2019-08-26 16:50:41', '8 Kdcgphy3', gen_random_uuid(), 3860.61) + │ ├── fd: ()-->(12-16,18,20-22) + │ └── (1343, 5, 10, 5, 10, '2019-08-26 16:50:41', crdb_internal.assignment_cast(3860.61, NULL::DECIMAL(6,2)), crdb_internal.assignment_cast('8 Kdcgphy3', NULL::VARCHAR(24)), gen_random_uuid()) └── f-k-checks ├── f-k-checks-item: history(h_c_w_id,h_c_d_id,h_c_id) -> customer(c_w_id,c_d_id,c_id) │ └── anti-join (lookup customer) - │ ├── columns: h_c_w_id:22!null h_c_d_id:23!null h_c_id:24!null - │ ├── key columns: [22 23 24] = [27 26 25] + │ ├── columns: h_c_w_id:23!null h_c_d_id:24!null h_c_id:25!null + │ ├── key columns: [23 24 25] = [28 27 26] │ ├── lookup columns are key │ ├── cardinality: [0 - 1] │ ├── key: () - │ ├── fd: ()-->(22-24) + │ ├── fd: ()-->(23-25) │ ├── with-scan &1 - │ │ ├── columns: h_c_w_id:22!null h_c_d_id:23!null h_c_id:24!null + │ │ ├── columns: h_c_w_id:23!null h_c_d_id:24!null h_c_id:25!null │ │ ├── mapping: - │ │ │ ├── column3:14 => h_c_w_id:22 - │ │ │ ├── column2:13 => h_c_d_id:23 - │ │ │ └── column1:12 => h_c_id:24 + │ │ │ ├── column3:14 => h_c_w_id:23 + │ │ │ ├── column2:13 => h_c_d_id:24 + │ │ │ └── column1:12 => h_c_id:25 │ │ ├── cardinality: [1 - 1] │ │ ├── key: () - │ │ └── fd: ()-->(22-24) + │ │ └── fd: ()-->(23-25) │ └── filters (true) └── f-k-checks-item: history(h_w_id,h_d_id) -> district(d_w_id,d_id) └── anti-join (lookup district) - ├── columns: h_w_id:48!null h_d_id:49!null - ├── key columns: [48 49] = [51 50] + ├── columns: h_w_id:49!null h_d_id:50!null + ├── key columns: [49 50] = [52 51] ├── lookup columns are key ├── cardinality: [0 - 1] ├── key: () - ├── fd: ()-->(48,49) + ├── fd: ()-->(49,50) ├── with-scan &1 - │ ├── columns: h_w_id:48!null h_d_id:49!null + │ ├── columns: h_w_id:49!null h_d_id:50!null │ ├── mapping: - │ │ ├── column5:16 => h_w_id:48 - │ │ └── column4:15 => h_d_id:49 + │ │ ├── column5:16 => h_w_id:49 + │ │ └── column4:15 => h_d_id:50 │ ├── cardinality: [1 - 1] │ ├── key: () - │ └── fd: ()-->(48,49) + │ └── fd: ()-->(49,50) └── filters (true) # -------------------------------------------------- diff --git a/pkg/sql/opt/xform/testdata/external/tpcc-no-stats b/pkg/sql/opt/xform/testdata/external/tpcc-no-stats index 0fb3c349396e..5275153bb373 100644 --- a/pkg/sql/opt/xform/testdata/external/tpcc-no-stats +++ b/pkg/sql/opt/xform/testdata/external/tpcc-no-stats @@ -361,18 +361,18 @@ insert order_line │ ├── column4:16 => ol_number:4 │ ├── column5:17 => order_line.ol_i_id:5 │ ├── column6:18 => order_line.ol_supply_w_id:6 - │ ├── ol_delivery_d_default:22 => ol_delivery_d:7 + │ ├── ol_delivery_d_default:24 => ol_delivery_d:7 │ ├── column7:19 => ol_quantity:8 - │ ├── ol_amount:23 => order_line.ol_amount:9 - │ └── column9:21 => ol_dist_info:10 + │ ├── column8:22 => ol_amount:9 + │ └── column9:23 => ol_dist_info:10 ├── input binding: &1 ├── cardinality: [0 - 0] ├── volatile, mutations ├── project - │ ├── columns: ol_amount:23 ol_delivery_d_default:22 column1:13!null column2:14!null column3:15!null column4:16!null column5:17!null column6:18!null column7:19!null column9:21!null + │ ├── columns: ol_delivery_d_default:24 column8:22 column9:23 column1:13!null column2:14!null column3:15!null column4:16!null column5:17!null column6:18!null column7:19!null │ ├── cardinality: [6 - 6] │ ├── immutable - │ ├── fd: ()-->(22) + │ ├── fd: ()-->(24) │ ├── values │ │ ├── columns: column1:13!null column2:14!null column3:15!null column4:16!null column5:17!null column6:18!null column7:19!null column8:20!null column9:21!null │ │ ├── cardinality: [6 - 6] @@ -383,34 +383,37 @@ insert order_line │ │ ├── (3045, 2, 10, 4, 56624, 0, 6, 273.360000, 'RsaCXoEzmssaF9m9cdLXe0Yh') │ │ └── (3045, 2, 10, 6, 92966, 0, 4, 366.760000, 'saCXoEzmssaF9m9cdLXe0Yhg') │ └── projections - │ ├── crdb_internal.round_decimal_values(column8:20, 2) [as=ol_amount:23, outer=(20), immutable] - │ └── CAST(NULL AS TIMESTAMP) [as=ol_delivery_d_default:22] + │ ├── CAST(NULL AS TIMESTAMP) [as=ol_delivery_d_default:24] + │ ├── assignment-cast: DECIMAL(6,2) [as=column8:22, outer=(20), immutable] + │ │ └── column8:20 + │ └── assignment-cast: CHAR(24) [as=column9:23, outer=(21), immutable] + │ └── column9:21 └── f-k-checks ├── f-k-checks-item: order_line(ol_w_id,ol_d_id,ol_o_id) -> order(o_w_id,o_d_id,o_id) │ └── anti-join (lookup order) - │ ├── columns: ol_w_id:24!null ol_d_id:25!null ol_o_id:26!null - │ ├── key columns: [24 25 26] = [29 28 27] + │ ├── columns: ol_w_id:25!null ol_d_id:26!null ol_o_id:27!null + │ ├── key columns: [25 26 27] = [30 29 28] │ ├── lookup columns are key │ ├── cardinality: [0 - 6] │ ├── with-scan &1 - │ │ ├── columns: ol_w_id:24!null ol_d_id:25!null ol_o_id:26!null + │ │ ├── columns: ol_w_id:25!null ol_d_id:26!null ol_o_id:27!null │ │ ├── mapping: - │ │ │ ├── column3:15 => ol_w_id:24 - │ │ │ ├── column2:14 => ol_d_id:25 - │ │ │ └── column1:13 => ol_o_id:26 + │ │ │ ├── column3:15 => ol_w_id:25 + │ │ │ ├── column2:14 => ol_d_id:26 + │ │ │ └── column1:13 => ol_o_id:27 │ │ └── cardinality: [6 - 6] │ └── filters (true) └── f-k-checks-item: order_line(ol_supply_w_id,ol_i_id) -> stock(s_w_id,s_i_id) └── anti-join (lookup stock) - ├── columns: ol_supply_w_id:37!null ol_i_id:38!null - ├── key columns: [37 38] = [40 39] + ├── columns: ol_supply_w_id:38!null ol_i_id:39!null + ├── key columns: [38 39] = [41 40] ├── lookup columns are key ├── cardinality: [0 - 6] ├── with-scan &1 - │ ├── columns: ol_supply_w_id:37!null ol_i_id:38!null + │ ├── columns: ol_supply_w_id:38!null ol_i_id:39!null │ ├── mapping: - │ │ ├── column6:18 => ol_supply_w_id:37 - │ │ └── column5:17 => ol_i_id:38 + │ │ ├── column6:18 => ol_supply_w_id:38 + │ │ └── column5:17 => ol_i_id:39 │ └── cardinality: [6 - 6] └── filters (true) @@ -597,60 +600,60 @@ VALUES insert history ├── columns: ├── insert-mapping: - │ ├── rowid_default:20 => rowid:1 + │ ├── rowid_default:22 => rowid:1 │ ├── column1:12 => history.h_c_id:2 │ ├── column2:13 => history.h_c_d_id:3 │ ├── column3:14 => history.h_c_w_id:4 │ ├── column4:15 => history.h_d_id:5 │ ├── column5:16 => history.h_w_id:6 │ ├── column7:18 => h_date:7 - │ ├── h_amount:21 => history.h_amount:8 - │ └── column8:19 => h_data:9 + │ ├── column6:20 => h_amount:8 + │ └── column8:21 => h_data:9 ├── input binding: &1 ├── cardinality: [0 - 0] ├── volatile, mutations ├── values - │ ├── columns: column1:12!null column2:13!null column3:14!null column4:15!null column5:16!null column7:18!null column8:19!null rowid_default:20 h_amount:21!null + │ ├── columns: column1:12!null column2:13!null column3:14!null column4:15!null column5:16!null column7:18!null column6:20 column8:21 rowid_default:22 │ ├── cardinality: [1 - 1] │ ├── volatile │ ├── key: () - │ ├── fd: ()-->(12-16,18-21) - │ └── (1343, 5, 10, 5, 10, '2019-08-26 16:50:41', '8 Kdcgphy3', gen_random_uuid(), 3860.61) + │ ├── fd: ()-->(12-16,18,20-22) + │ └── (1343, 5, 10, 5, 10, '2019-08-26 16:50:41', crdb_internal.assignment_cast(3860.61, NULL::DECIMAL(6,2)), crdb_internal.assignment_cast('8 Kdcgphy3', NULL::VARCHAR(24)), gen_random_uuid()) └── f-k-checks ├── f-k-checks-item: history(h_c_w_id,h_c_d_id,h_c_id) -> customer(c_w_id,c_d_id,c_id) │ └── anti-join (lookup customer) - │ ├── columns: h_c_w_id:22!null h_c_d_id:23!null h_c_id:24!null - │ ├── key columns: [22 23 24] = [27 26 25] + │ ├── columns: h_c_w_id:23!null h_c_d_id:24!null h_c_id:25!null + │ ├── key columns: [23 24 25] = [28 27 26] │ ├── lookup columns are key │ ├── cardinality: [0 - 1] │ ├── key: () - │ ├── fd: ()-->(22-24) + │ ├── fd: ()-->(23-25) │ ├── with-scan &1 - │ │ ├── columns: h_c_w_id:22!null h_c_d_id:23!null h_c_id:24!null + │ │ ├── columns: h_c_w_id:23!null h_c_d_id:24!null h_c_id:25!null │ │ ├── mapping: - │ │ │ ├── column3:14 => h_c_w_id:22 - │ │ │ ├── column2:13 => h_c_d_id:23 - │ │ │ └── column1:12 => h_c_id:24 + │ │ │ ├── column3:14 => h_c_w_id:23 + │ │ │ ├── column2:13 => h_c_d_id:24 + │ │ │ └── column1:12 => h_c_id:25 │ │ ├── cardinality: [1 - 1] │ │ ├── key: () - │ │ └── fd: ()-->(22-24) + │ │ └── fd: ()-->(23-25) │ └── filters (true) └── f-k-checks-item: history(h_w_id,h_d_id) -> district(d_w_id,d_id) └── anti-join (lookup district) - ├── columns: h_w_id:48!null h_d_id:49!null - ├── key columns: [48 49] = [51 50] + ├── columns: h_w_id:49!null h_d_id:50!null + ├── key columns: [49 50] = [52 51] ├── lookup columns are key ├── cardinality: [0 - 1] ├── key: () - ├── fd: ()-->(48,49) + ├── fd: ()-->(49,50) ├── with-scan &1 - │ ├── columns: h_w_id:48!null h_d_id:49!null + │ ├── columns: h_w_id:49!null h_d_id:50!null │ ├── mapping: - │ │ ├── column5:16 => h_w_id:48 - │ │ └── column4:15 => h_d_id:49 + │ │ ├── column5:16 => h_w_id:49 + │ │ └── column4:15 => h_d_id:50 │ ├── cardinality: [1 - 1] │ ├── key: () - │ └── fd: ()-->(48,49) + │ └── fd: ()-->(49,50) └── filters (true) # -------------------------------------------------- diff --git a/pkg/sql/opt/xform/testdata/external/tpce b/pkg/sql/opt/xform/testdata/external/tpce index ca9625df40fd..4afd4d5f7d51 100644 --- a/pkg/sql/opt/xform/testdata/external/tpce +++ b/pkg/sql/opt/xform/testdata/external/tpce @@ -552,10 +552,10 @@ update_trade_submitted AS ( SELECT * FROM request_list; ---- with &2 (update_last_trade) - ├── columns: tr_t_id:137!null tr_bid_price:138!null tr_tt_id:139!null tr_qty:140!null + ├── columns: tr_t_id:138!null tr_bid_price:139!null tr_tt_id:140!null tr_qty:141!null ├── volatile, mutations - ├── key: (137) - ├── fd: (137)-->(138-140) + ├── key: (138) + ├── fd: (138)-->(139-141) ├── project │ ├── columns: "?column?":19 │ ├── cardinality: [0 - 1] @@ -592,10 +592,10 @@ with &2 (update_last_trade) │ └── projections │ └── NULL [as="?column?":19] └── with &3 (request_list) - ├── columns: tr_t_id:137!null tr_bid_price:138!null tr_tt_id:139!null tr_qty:140!null + ├── columns: tr_t_id:138!null tr_bid_price:139!null tr_tt_id:140!null tr_qty:141!null ├── volatile, mutations - ├── key: (137) - ├── fd: (137)-->(138-140) + ├── key: (138) + ├── fd: (138)-->(139-141) ├── project │ ├── columns: tr_bid_price:28!null trade_request.tr_t_id:20!null trade_request.tr_tt_id:21!null trade_request.tr_qty:23!null │ ├── immutable @@ -622,10 +622,10 @@ with &2 (update_last_trade) │ └── projections │ └── trade_request.tr_bid_price:24::FLOAT8 [as=tr_bid_price:28, outer=(24), immutable] └── with &4 (delete_trade_request) - ├── columns: tr_t_id:137!null tr_bid_price:138!null tr_tt_id:139!null tr_qty:140!null + ├── columns: tr_t_id:138!null tr_bid_price:139!null tr_tt_id:140!null tr_qty:141!null ├── volatile, mutations - ├── key: (137) - ├── fd: (137)-->(138-140) + ├── key: (138) + ├── fd: (138)-->(139-141) ├── project │ ├── columns: "?column?":50 │ ├── volatile, mutations @@ -661,128 +661,130 @@ with &2 (update_last_trade) │ └── projections │ └── NULL [as="?column?":50] └── with &6 (insert_trade_history) - ├── columns: tr_t_id:137!null tr_bid_price:138!null tr_tt_id:139!null tr_qty:140!null + ├── columns: tr_t_id:138!null tr_bid_price:139!null tr_tt_id:140!null tr_qty:141!null ├── volatile, mutations - ├── key: (137) - ├── fd: (137)-->(138-140) + ├── key: (138) + ├── fd: (138)-->(139-141) ├── project - │ ├── columns: "?column?":85 + │ ├── columns: "?column?":86 │ ├── volatile, mutations - │ ├── fd: ()-->(85) + │ ├── fd: ()-->(86) │ ├── insert trade_history │ │ ├── columns: trade_history.th_t_id:51!null trade_history.th_st_id:53!null │ │ ├── insert-mapping: │ │ │ ├── tr_t_id:56 => trade_history.th_t_id:51 │ │ │ ├── timestamp:61 => th_dts:52 - │ │ │ └── "?column?":60 => trade_history.th_st_id:53 + │ │ │ └── "?column?":62 => trade_history.th_st_id:53 │ │ ├── input binding: &5 │ │ ├── volatile, mutations │ │ ├── key: (51) │ │ ├── fd: ()-->(53) │ │ ├── project - │ │ │ ├── columns: "?column?":60!null timestamp:61!null tr_t_id:56!null + │ │ │ ├── columns: "?column?":62 timestamp:61!null tr_t_id:56!null + │ │ │ ├── immutable │ │ │ ├── key: (56) - │ │ │ ├── fd: ()-->(60,61) + │ │ │ ├── fd: ()-->(61,62) │ │ │ ├── with-scan &3 (request_list) │ │ │ │ ├── columns: tr_t_id:56!null │ │ │ │ ├── mapping: │ │ │ │ │ └── trade_request.tr_t_id:20 => tr_t_id:56 │ │ │ │ └── key: (56) │ │ │ └── projections - │ │ │ ├── 'SBMT' [as="?column?":60] + │ │ │ ├── assignment-cast: VARCHAR(4) [as="?column?":62, immutable] + │ │ │ │ └── 'SBMT' │ │ │ └── '2020-06-15 22:27:42.148484' [as=timestamp:61] │ │ └── f-k-checks │ │ ├── f-k-checks-item: trade_history(th_t_id) -> trade(t_id) │ │ │ └── anti-join (lookup trade) - │ │ │ ├── columns: th_t_id:62!null - │ │ │ ├── key columns: [62] = [63] + │ │ │ ├── columns: th_t_id:63!null + │ │ │ ├── key columns: [63] = [64] │ │ │ ├── lookup columns are key - │ │ │ ├── key: (62) + │ │ │ ├── key: (63) │ │ │ ├── with-scan &5 - │ │ │ │ ├── columns: th_t_id:62!null + │ │ │ │ ├── columns: th_t_id:63!null │ │ │ │ ├── mapping: - │ │ │ │ │ └── tr_t_id:56 => th_t_id:62 - │ │ │ │ └── key: (62) + │ │ │ │ │ └── tr_t_id:56 => th_t_id:63 + │ │ │ │ └── key: (63) │ │ │ └── filters (true) │ │ └── f-k-checks-item: trade_history(th_st_id) -> status_type(st_id) │ │ └── anti-join (lookup status_type) - │ │ ├── columns: th_st_id:80!null - │ │ ├── key columns: [80] = [81] + │ │ ├── columns: th_st_id:81 + │ │ ├── key columns: [81] = [82] │ │ ├── lookup columns are key - │ │ ├── fd: ()-->(80) + │ │ ├── fd: ()-->(81) │ │ ├── with-scan &5 - │ │ │ ├── columns: th_st_id:80!null + │ │ │ ├── columns: th_st_id:81 │ │ │ ├── mapping: - │ │ │ │ └── "?column?":60 => th_st_id:80 - │ │ │ └── fd: ()-->(80) + │ │ │ │ └── "?column?":62 => th_st_id:81 + │ │ │ └── fd: ()-->(81) │ │ └── filters (true) │ └── projections - │ └── NULL [as="?column?":85] + │ └── NULL [as="?column?":86] └── with &8 (update_trade_submitted) - ├── columns: tr_t_id:137!null tr_bid_price:138!null tr_tt_id:139!null tr_qty:140!null + ├── columns: tr_t_id:138!null tr_bid_price:139!null tr_tt_id:140!null tr_qty:141!null ├── volatile, mutations - ├── key: (137) - ├── fd: (137)-->(138-140) + ├── key: (138) + ├── fd: (138)-->(139-141) ├── project - │ ├── columns: "?column?":136 + │ ├── columns: "?column?":137 │ ├── volatile, mutations - │ ├── fd: ()-->(136) + │ ├── fd: ()-->(137) │ ├── update trade - │ │ ├── columns: t_id:86!null - │ │ ├── fetch columns: t_id:103 t_dts:104 trade.t_st_id:105 t_tt_id:106 t_is_cash:107 t_s_symb:108 t_qty:109 t_bid_price:110 t_ca_id:111 t_exec_name:112 t_trade_price:113 t_chrg:114 t_comm:115 t_lifo:117 + │ │ ├── columns: t_id:87!null + │ │ ├── fetch columns: t_id:104 t_dts:105 trade.t_st_id:106 t_tt_id:107 t_is_cash:108 t_s_symb:109 t_qty:110 t_bid_price:111 t_ca_id:112 t_exec_name:113 t_trade_price:114 t_chrg:115 t_comm:116 t_lifo:118 │ │ ├── update-mapping: - │ │ │ ├── t_dts_new:125 => t_dts:87 - │ │ │ └── t_st_id_new:124 => trade.t_st_id:88 + │ │ │ ├── t_dts_new:126 => t_dts:88 + │ │ │ └── t_st_id_new:125 => trade.t_st_id:89 │ │ ├── input binding: &7 │ │ ├── volatile, mutations - │ │ ├── key: (86) + │ │ ├── key: (87) │ │ ├── project - │ │ │ ├── columns: t_st_id_new:124!null t_dts_new:125!null t_id:103!null t_dts:104!null trade.t_st_id:105!null t_tt_id:106!null t_is_cash:107!null t_s_symb:108!null t_qty:109!null t_bid_price:110!null t_ca_id:111!null t_exec_name:112!null t_trade_price:113 t_chrg:114!null t_comm:115!null t_lifo:117!null - │ │ │ ├── key: (103) - │ │ │ ├── fd: ()-->(124,125), (103)-->(104-115,117) + │ │ │ ├── columns: t_st_id_new:125!null t_dts_new:126!null t_id:104!null t_dts:105!null trade.t_st_id:106!null t_tt_id:107!null t_is_cash:108!null t_s_symb:109!null t_qty:110!null t_bid_price:111!null t_ca_id:112!null t_exec_name:113!null t_trade_price:114 t_chrg:115!null t_comm:116!null t_lifo:118!null + │ │ │ ├── key: (104) + │ │ │ ├── fd: ()-->(125,126), (104)-->(105-116,118) │ │ │ ├── project - │ │ │ │ ├── columns: t_id:103!null t_dts:104!null trade.t_st_id:105!null t_tt_id:106!null t_is_cash:107!null t_s_symb:108!null t_qty:109!null t_bid_price:110!null t_ca_id:111!null t_exec_name:112!null t_trade_price:113 t_chrg:114!null t_comm:115!null t_lifo:117!null - │ │ │ │ ├── key: (103) - │ │ │ │ ├── fd: (103)-->(104-115,117) + │ │ │ │ ├── columns: t_id:104!null t_dts:105!null trade.t_st_id:106!null t_tt_id:107!null t_is_cash:108!null t_s_symb:109!null t_qty:110!null t_bid_price:111!null t_ca_id:112!null t_exec_name:113!null t_trade_price:114 t_chrg:115!null t_comm:116!null t_lifo:118!null + │ │ │ │ ├── key: (104) + │ │ │ │ ├── fd: (104)-->(105-116,118) │ │ │ │ └── inner-join (lookup trade) - │ │ │ │ ├── columns: t_id:103!null t_dts:104!null trade.t_st_id:105!null t_tt_id:106!null t_is_cash:107!null t_s_symb:108!null t_qty:109!null t_bid_price:110!null t_ca_id:111!null t_exec_name:112!null t_trade_price:113 t_chrg:114!null t_comm:115!null t_lifo:117!null tr_t_id:120!null - │ │ │ │ ├── key columns: [120] = [103] + │ │ │ │ ├── columns: t_id:104!null t_dts:105!null trade.t_st_id:106!null t_tt_id:107!null t_is_cash:108!null t_s_symb:109!null t_qty:110!null t_bid_price:111!null t_ca_id:112!null t_exec_name:113!null t_trade_price:114 t_chrg:115!null t_comm:116!null t_lifo:118!null tr_t_id:121!null + │ │ │ │ ├── key columns: [121] = [104] │ │ │ │ ├── lookup columns are key - │ │ │ │ ├── key: (120) - │ │ │ │ ├── fd: (103)-->(104-115,117), (103)==(120), (120)==(103) + │ │ │ │ ├── key: (121) + │ │ │ │ ├── fd: (104)-->(105-116,118), (104)==(121), (121)==(104) │ │ │ │ ├── with-scan &3 (request_list) - │ │ │ │ │ ├── columns: tr_t_id:120!null + │ │ │ │ │ ├── columns: tr_t_id:121!null │ │ │ │ │ ├── mapping: - │ │ │ │ │ │ └── trade_request.tr_t_id:20 => tr_t_id:120 - │ │ │ │ │ └── key: (120) + │ │ │ │ │ │ └── trade_request.tr_t_id:20 => tr_t_id:121 + │ │ │ │ │ └── key: (121) │ │ │ │ └── filters (true) │ │ │ └── projections - │ │ │ ├── 'SBMT' [as=t_st_id_new:124] - │ │ │ └── '2020-06-15 22:27:42.148484' [as=t_dts_new:125] + │ │ │ ├── 'SBMT' [as=t_st_id_new:125] + │ │ │ └── '2020-06-15 22:27:42.148484' [as=t_dts_new:126] │ │ └── f-k-checks │ │ └── f-k-checks-item: trade(t_st_id) -> status_type(st_id) │ │ └── anti-join (lookup status_type) - │ │ ├── columns: t_st_id:131!null - │ │ ├── key columns: [131] = [132] + │ │ ├── columns: t_st_id:132!null + │ │ ├── key columns: [132] = [133] │ │ ├── lookup columns are key - │ │ ├── fd: ()-->(131) + │ │ ├── fd: ()-->(132) │ │ ├── with-scan &7 - │ │ │ ├── columns: t_st_id:131!null + │ │ │ ├── columns: t_st_id:132!null │ │ │ ├── mapping: - │ │ │ │ └── t_st_id_new:124 => t_st_id:131 - │ │ │ └── fd: ()-->(131) + │ │ │ │ └── t_st_id_new:125 => t_st_id:132 + │ │ │ └── fd: ()-->(132) │ │ └── filters (true) │ └── projections - │ └── NULL [as="?column?":136] + │ └── NULL [as="?column?":137] └── with-scan &3 (request_list) - ├── columns: tr_t_id:137!null tr_bid_price:138!null tr_tt_id:139!null tr_qty:140!null + ├── columns: tr_t_id:138!null tr_bid_price:139!null tr_tt_id:140!null tr_qty:141!null ├── mapping: - │ ├── trade_request.tr_t_id:20 => tr_t_id:137 - │ ├── tr_bid_price:28 => tr_bid_price:138 - │ ├── trade_request.tr_tt_id:21 => tr_tt_id:139 - │ └── trade_request.tr_qty:23 => tr_qty:140 - ├── key: (137) - └── fd: (137)-->(138-140) + │ ├── trade_request.tr_t_id:20 => tr_t_id:138 + │ ├── tr_bid_price:28 => tr_bid_price:139 + │ ├── trade_request.tr_tt_id:21 => tr_tt_id:140 + │ └── trade_request.tr_qty:23 => tr_qty:141 + ├── key: (138) + └── fd: (138)-->(139-141) # -------------------------------------------------- # T4 @@ -2921,183 +2923,197 @@ insert_trade_history AS ( SELECT 1; ---- with &2 (insert_trade) - ├── columns: "?column?":116!null + ├── columns: "?column?":121!null ├── cardinality: [1 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(116) + ├── fd: ()-->(121) ├── project - │ ├── columns: "?column?":83!null + │ ├── columns: "?column?":87!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(83) + │ ├── fd: ()-->(87) │ ├── insert trade │ │ ├── columns: t_id:1!null │ │ ├── insert-mapping: │ │ │ ├── column1:18 => t_id:1 │ │ │ ├── column2:19 => t_dts:2 - │ │ │ ├── column3:20 => trade.t_st_id:3 - │ │ │ ├── column4:21 => trade.t_tt_id:4 + │ │ │ ├── column3:33 => trade.t_st_id:3 + │ │ │ ├── column4:34 => trade.t_tt_id:4 │ │ │ ├── column5:22 => t_is_cash:5 - │ │ │ ├── column6:23 => trade.t_s_symb:6 - │ │ │ ├── column7:24 => t_qty:7 - │ │ │ ├── t_bid_price:33 => trade.t_bid_price:8 + │ │ │ ├── column6:35 => trade.t_s_symb:6 + │ │ │ ├── column7:36 => t_qty:7 + │ │ │ ├── column8:37 => t_bid_price:8 │ │ │ ├── column9:26 => trade.t_ca_id:9 - │ │ │ ├── column10:27 => t_exec_name:10 - │ │ │ ├── t_trade_price:34 => trade.t_trade_price:11 - │ │ │ ├── t_chrg:35 => trade.t_chrg:12 - │ │ │ ├── t_comm:36 => trade.t_comm:13 - │ │ │ ├── t_tax:37 => trade.t_tax:14 + │ │ │ ├── column10:38 => t_exec_name:10 + │ │ │ ├── column11:28 => t_trade_price:11 + │ │ │ ├── column12:39 => t_chrg:12 + │ │ │ ├── column13:40 => t_comm:13 + │ │ │ ├── column14:41 => t_tax:14 │ │ │ └── column15:32 => t_lifo:15 - │ │ ├── check columns: check1:38 check2:39 check3:40 check4:41 check5:42 + │ │ ├── check columns: check1:42 check2:43 check3:44 check4:45 check5:46 │ │ ├── input binding: &1 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () │ │ ├── fd: ()-->(1) - │ │ ├── values - │ │ │ ├── columns: column1:18!null column2:19!null column3:20!null column4:21!null column5:22!null column6:23!null column7:24!null column9:26!null column10:27!null column15:32!null t_bid_price:33!null t_trade_price:34 t_chrg:35!null t_comm:36!null t_tax:37!null check1:38!null check2:39!null check3:40!null check4:41!null check5:42!null + │ │ ├── project + │ │ │ ├── columns: check1:42 check2:43 check3:44 check4:45 check5:46 column1:18!null column2:19!null column5:22!null column9:26!null column11:28 column15:32!null column3:33 column4:34 column6:35 column7:36 column8:37 column10:38 column12:39 column13:40 column14:41 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(18-24,26,27,32-42) - │ │ │ └── (0, '2020-06-17 22:27:42.148484', 'SBMT', 'TMB', true, 'SYMB', 10, 0, 'Name', true, 1E+2, NULL, 1, 0, 0, true, true, true, true, true) + │ │ │ ├── fd: ()-->(18,19,22,26,28,32-46) + │ │ │ ├── values + │ │ │ │ ├── columns: column1:18!null column2:19!null column5:22!null column9:26!null column11:28 column15:32!null column3:33 column4:34 column6:35 column7:36 column8:37 column10:38 column12:39 column13:40 column14:41 + │ │ │ │ ├── cardinality: [1 - 1] + │ │ │ │ ├── immutable + │ │ │ │ ├── key: () + │ │ │ │ ├── fd: ()-->(18,19,22,26,28,32-41) + │ │ │ │ └── (0, '2020-06-17 22:27:42.148484', true, 0, CAST(NULL AS DECIMAL(8,2)), true, crdb_internal.assignment_cast('SBMT', NULL::VARCHAR(4)), crdb_internal.assignment_cast('TMB', NULL::VARCHAR(3)), crdb_internal.assignment_cast('SYMB', NULL::VARCHAR(15)), crdb_internal.assignment_cast(10, NULL::INT4), crdb_internal.assignment_cast(1E+2, NULL::DECIMAL(8,2)), crdb_internal.assignment_cast('Name', NULL::VARCHAR(49)), crdb_internal.assignment_cast(1, NULL::DECIMAL(10,2)), crdb_internal.assignment_cast(0, NULL::DECIMAL(10,2)), crdb_internal.assignment_cast(0, NULL::DECIMAL(10,2))) + │ │ │ └── projections + │ │ │ ├── column7:36 > 0 [as=check1:42, outer=(36)] + │ │ │ ├── column8:37 > 0 [as=check2:43, outer=(37), immutable] + │ │ │ ├── column12:39 >= 0 [as=check3:44, outer=(39), immutable] + │ │ │ ├── column13:40 >= 0 [as=check4:45, outer=(40), immutable] + │ │ │ └── column14:41 >= 0 [as=check5:46, outer=(41), immutable] │ │ └── f-k-checks │ │ ├── f-k-checks-item: trade(t_st_id) -> status_type(st_id) │ │ │ └── anti-join (lookup status_type) - │ │ │ ├── columns: t_st_id:43!null - │ │ │ ├── key columns: [43] = [44] + │ │ │ ├── columns: t_st_id:47 + │ │ │ ├── key columns: [47] = [48] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(43) + │ │ │ ├── fd: ()-->(47) │ │ │ ├── with-scan &1 - │ │ │ │ ├── columns: t_st_id:43!null + │ │ │ │ ├── columns: t_st_id:47 │ │ │ │ ├── mapping: - │ │ │ │ │ └── column3:20 => t_st_id:43 + │ │ │ │ │ └── column3:33 => t_st_id:47 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(43) + │ │ │ │ └── fd: ()-->(47) │ │ │ └── filters (true) │ │ ├── f-k-checks-item: trade(t_tt_id) -> trade_type(tt_id) │ │ │ └── anti-join (lookup trade_type) - │ │ │ ├── columns: t_tt_id:48!null - │ │ │ ├── key columns: [48] = [49] + │ │ │ ├── columns: t_tt_id:52 + │ │ │ ├── key columns: [52] = [53] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(48) + │ │ │ ├── fd: ()-->(52) │ │ │ ├── with-scan &1 - │ │ │ │ ├── columns: t_tt_id:48!null + │ │ │ │ ├── columns: t_tt_id:52 │ │ │ │ ├── mapping: - │ │ │ │ │ └── column4:21 => t_tt_id:48 + │ │ │ │ │ └── column4:34 => t_tt_id:52 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(48) + │ │ │ │ └── fd: ()-->(52) │ │ │ └── filters (true) │ │ ├── f-k-checks-item: trade(t_s_symb) -> security(s_symb) │ │ │ └── anti-join (lookup security) - │ │ │ ├── columns: t_s_symb:55!null - │ │ │ ├── key columns: [55] = [56] + │ │ │ ├── columns: t_s_symb:59 + │ │ │ ├── key columns: [59] = [60] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(55) + │ │ │ ├── fd: ()-->(59) │ │ │ ├── with-scan &1 - │ │ │ │ ├── columns: t_s_symb:55!null + │ │ │ │ ├── columns: t_s_symb:59 │ │ │ │ ├── mapping: - │ │ │ │ │ └── column6:23 => t_s_symb:55 + │ │ │ │ │ └── column6:35 => t_s_symb:59 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(55) + │ │ │ │ └── fd: ()-->(59) │ │ │ └── filters (true) │ │ └── f-k-checks-item: trade(t_ca_id) -> customer_account(ca_id) │ │ └── anti-join (lookup customer_account) - │ │ ├── columns: t_ca_id:74!null - │ │ ├── key columns: [74] = [75] + │ │ ├── columns: t_ca_id:78!null + │ │ ├── key columns: [78] = [79] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(74) + │ │ ├── fd: ()-->(78) │ │ ├── with-scan &1 - │ │ │ ├── columns: t_ca_id:74!null + │ │ │ ├── columns: t_ca_id:78!null │ │ │ ├── mapping: - │ │ │ │ └── column9:26 => t_ca_id:74 + │ │ │ │ └── column9:26 => t_ca_id:78 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(74) + │ │ │ └── fd: ()-->(78) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":83] + │ └── 1 [as="?column?":87] └── with &4 (insert_trade_history) - ├── columns: "?column?":116!null + ├── columns: "?column?":121!null ├── cardinality: [1 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(116) + ├── fd: ()-->(121) ├── project - │ ├── columns: "?column?":115!null + │ ├── columns: "?column?":120!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(115) + │ ├── fd: ()-->(120) │ ├── insert trade_history - │ │ ├── columns: trade_history.th_t_id:84!null trade_history.th_st_id:86!null + │ │ ├── columns: trade_history.th_t_id:88!null trade_history.th_st_id:90!null │ │ ├── insert-mapping: - │ │ │ ├── column1:89 => trade_history.th_t_id:84 - │ │ │ ├── column2:90 => th_dts:85 - │ │ │ └── column3:91 => trade_history.th_st_id:86 + │ │ │ ├── column1:93 => trade_history.th_t_id:88 + │ │ │ ├── column2:94 => th_dts:89 + │ │ │ └── column3:96 => trade_history.th_st_id:90 │ │ ├── input binding: &3 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () - │ │ ├── fd: ()-->(84,86) + │ │ ├── fd: ()-->(88,90) │ │ ├── values - │ │ │ ├── columns: column1:89!null column2:90!null column3:91!null + │ │ │ ├── columns: column1:93!null column2:94!null column3:96 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(89-91) - │ │ │ └── (0, '2020-06-15 22:27:42.148484', 'SBMT') + │ │ │ ├── fd: ()-->(93,94,96) + │ │ │ └── (0, '2020-06-15 22:27:42.148484', crdb_internal.assignment_cast('SBMT', NULL::VARCHAR(4))) │ │ └── f-k-checks │ │ ├── f-k-checks-item: trade_history(th_t_id) -> trade(t_id) │ │ │ └── anti-join (lookup trade) - │ │ │ ├── columns: th_t_id:92!null - │ │ │ ├── key columns: [92] = [93] + │ │ │ ├── columns: th_t_id:97!null + │ │ │ ├── key columns: [97] = [98] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(92) + │ │ │ ├── fd: ()-->(97) │ │ │ ├── with-scan &3 - │ │ │ │ ├── columns: th_t_id:92!null + │ │ │ │ ├── columns: th_t_id:97!null │ │ │ │ ├── mapping: - │ │ │ │ │ └── column1:89 => th_t_id:92 + │ │ │ │ │ └── column1:93 => th_t_id:97 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(92) + │ │ │ │ └── fd: ()-->(97) │ │ │ └── filters (true) │ │ └── f-k-checks-item: trade_history(th_st_id) -> status_type(st_id) │ │ └── anti-join (lookup status_type) - │ │ ├── columns: th_st_id:110!null - │ │ ├── key columns: [110] = [111] + │ │ ├── columns: th_st_id:115 + │ │ ├── key columns: [115] = [116] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(110) + │ │ ├── fd: ()-->(115) │ │ ├── with-scan &3 - │ │ │ ├── columns: th_st_id:110!null + │ │ │ ├── columns: th_st_id:115 │ │ │ ├── mapping: - │ │ │ │ └── column3:91 => th_st_id:110 + │ │ │ │ └── column3:96 => th_st_id:115 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(110) + │ │ │ └── fd: ()-->(115) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":115] + │ └── 1 [as="?column?":120] └── values - ├── columns: "?column?":116!null + ├── columns: "?column?":121!null ├── cardinality: [1 - 1] ├── key: () - ├── fd: ()-->(116) + ├── fd: ()-->(121) └── (1,) # Q12 @@ -3171,284 +3187,309 @@ insert_trade_request AS ( SELECT 1; ---- with &2 (insert_trade) - ├── columns: "?column?":187!null + ├── columns: "?column?":195!null ├── cardinality: [1 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(187) + ├── fd: ()-->(195) ├── project - │ ├── columns: "?column?":83!null + │ ├── columns: "?column?":87!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(83) + │ ├── fd: ()-->(87) │ ├── insert trade │ │ ├── columns: t_id:1!null │ │ ├── insert-mapping: │ │ │ ├── column1:18 => t_id:1 │ │ │ ├── column2:19 => t_dts:2 - │ │ │ ├── column3:20 => trade.t_st_id:3 - │ │ │ ├── column4:21 => trade.t_tt_id:4 + │ │ │ ├── column3:33 => trade.t_st_id:3 + │ │ │ ├── column4:34 => trade.t_tt_id:4 │ │ │ ├── column5:22 => t_is_cash:5 - │ │ │ ├── column6:23 => trade.t_s_symb:6 - │ │ │ ├── column7:24 => t_qty:7 - │ │ │ ├── t_bid_price:33 => trade.t_bid_price:8 + │ │ │ ├── column6:35 => trade.t_s_symb:6 + │ │ │ ├── column7:36 => t_qty:7 + │ │ │ ├── column8:37 => t_bid_price:8 │ │ │ ├── column9:26 => trade.t_ca_id:9 - │ │ │ ├── column10:27 => t_exec_name:10 - │ │ │ ├── t_trade_price:34 => trade.t_trade_price:11 - │ │ │ ├── t_chrg:35 => trade.t_chrg:12 - │ │ │ ├── t_comm:36 => trade.t_comm:13 - │ │ │ ├── t_tax:37 => trade.t_tax:14 + │ │ │ ├── column10:38 => t_exec_name:10 + │ │ │ ├── column11:28 => t_trade_price:11 + │ │ │ ├── column12:39 => t_chrg:12 + │ │ │ ├── column13:40 => t_comm:13 + │ │ │ ├── column14:41 => t_tax:14 │ │ │ └── column15:32 => t_lifo:15 - │ │ ├── check columns: check1:38 check2:39 check3:40 check4:41 check5:42 + │ │ ├── check columns: check1:42 check2:43 check3:44 check4:45 check5:46 │ │ ├── input binding: &1 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () │ │ ├── fd: ()-->(1) - │ │ ├── values - │ │ │ ├── columns: column1:18!null column2:19!null column3:20!null column4:21!null column5:22!null column6:23!null column7:24!null column9:26!null column10:27!null column15:32!null t_bid_price:33!null t_trade_price:34 t_chrg:35!null t_comm:36!null t_tax:37!null check1:38!null check2:39!null check3:40!null check4:41!null check5:42!null + │ │ ├── project + │ │ │ ├── columns: check1:42 check2:43 check3:44 check4:45 check5:46 column1:18!null column2:19!null column5:22!null column9:26!null column11:28 column15:32!null column3:33 column4:34 column6:35 column7:36 column8:37 column10:38 column12:39 column13:40 column14:41 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(18-24,26,27,32-42) - │ │ │ └── (0, '2020-06-17 22:27:42.148484', 'SBMT', 'TMB', true, 'SYMB', 10, 0, 'Name', true, 1E+2, NULL, 1, 0, 0, true, true, true, true, true) + │ │ │ ├── fd: ()-->(18,19,22,26,28,32-46) + │ │ │ ├── values + │ │ │ │ ├── columns: column1:18!null column2:19!null column5:22!null column9:26!null column11:28 column15:32!null column3:33 column4:34 column6:35 column7:36 column8:37 column10:38 column12:39 column13:40 column14:41 + │ │ │ │ ├── cardinality: [1 - 1] + │ │ │ │ ├── immutable + │ │ │ │ ├── key: () + │ │ │ │ ├── fd: ()-->(18,19,22,26,28,32-41) + │ │ │ │ └── (0, '2020-06-17 22:27:42.148484', true, 0, CAST(NULL AS DECIMAL(8,2)), true, crdb_internal.assignment_cast('SBMT', NULL::VARCHAR(4)), crdb_internal.assignment_cast('TMB', NULL::VARCHAR(3)), crdb_internal.assignment_cast('SYMB', NULL::VARCHAR(15)), crdb_internal.assignment_cast(10, NULL::INT4), crdb_internal.assignment_cast(1E+2, NULL::DECIMAL(8,2)), crdb_internal.assignment_cast('Name', NULL::VARCHAR(49)), crdb_internal.assignment_cast(1, NULL::DECIMAL(10,2)), crdb_internal.assignment_cast(0, NULL::DECIMAL(10,2)), crdb_internal.assignment_cast(0, NULL::DECIMAL(10,2))) + │ │ │ └── projections + │ │ │ ├── column7:36 > 0 [as=check1:42, outer=(36)] + │ │ │ ├── column8:37 > 0 [as=check2:43, outer=(37), immutable] + │ │ │ ├── column12:39 >= 0 [as=check3:44, outer=(39), immutable] + │ │ │ ├── column13:40 >= 0 [as=check4:45, outer=(40), immutable] + │ │ │ └── column14:41 >= 0 [as=check5:46, outer=(41), immutable] │ │ └── f-k-checks │ │ ├── f-k-checks-item: trade(t_st_id) -> status_type(st_id) │ │ │ └── anti-join (lookup status_type) - │ │ │ ├── columns: t_st_id:43!null - │ │ │ ├── key columns: [43] = [44] + │ │ │ ├── columns: t_st_id:47 + │ │ │ ├── key columns: [47] = [48] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(43) + │ │ │ ├── fd: ()-->(47) │ │ │ ├── with-scan &1 - │ │ │ │ ├── columns: t_st_id:43!null + │ │ │ │ ├── columns: t_st_id:47 │ │ │ │ ├── mapping: - │ │ │ │ │ └── column3:20 => t_st_id:43 + │ │ │ │ │ └── column3:33 => t_st_id:47 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(43) + │ │ │ │ └── fd: ()-->(47) │ │ │ └── filters (true) │ │ ├── f-k-checks-item: trade(t_tt_id) -> trade_type(tt_id) │ │ │ └── anti-join (lookup trade_type) - │ │ │ ├── columns: t_tt_id:48!null - │ │ │ ├── key columns: [48] = [49] + │ │ │ ├── columns: t_tt_id:52 + │ │ │ ├── key columns: [52] = [53] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(48) + │ │ │ ├── fd: ()-->(52) │ │ │ ├── with-scan &1 - │ │ │ │ ├── columns: t_tt_id:48!null + │ │ │ │ ├── columns: t_tt_id:52 │ │ │ │ ├── mapping: - │ │ │ │ │ └── column4:21 => t_tt_id:48 + │ │ │ │ │ └── column4:34 => t_tt_id:52 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(48) + │ │ │ │ └── fd: ()-->(52) │ │ │ └── filters (true) │ │ ├── f-k-checks-item: trade(t_s_symb) -> security(s_symb) │ │ │ └── anti-join (lookup security) - │ │ │ ├── columns: t_s_symb:55!null - │ │ │ ├── key columns: [55] = [56] + │ │ │ ├── columns: t_s_symb:59 + │ │ │ ├── key columns: [59] = [60] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(55) + │ │ │ ├── fd: ()-->(59) │ │ │ ├── with-scan &1 - │ │ │ │ ├── columns: t_s_symb:55!null + │ │ │ │ ├── columns: t_s_symb:59 │ │ │ │ ├── mapping: - │ │ │ │ │ └── column6:23 => t_s_symb:55 + │ │ │ │ │ └── column6:35 => t_s_symb:59 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(55) + │ │ │ │ └── fd: ()-->(59) │ │ │ └── filters (true) │ │ └── f-k-checks-item: trade(t_ca_id) -> customer_account(ca_id) │ │ └── anti-join (lookup customer_account) - │ │ ├── columns: t_ca_id:74!null - │ │ ├── key columns: [74] = [75] + │ │ ├── columns: t_ca_id:78!null + │ │ ├── key columns: [78] = [79] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(74) + │ │ ├── fd: ()-->(78) │ │ ├── with-scan &1 - │ │ │ ├── columns: t_ca_id:74!null + │ │ │ ├── columns: t_ca_id:78!null │ │ │ ├── mapping: - │ │ │ │ └── column9:26 => t_ca_id:74 + │ │ │ │ └── column9:26 => t_ca_id:78 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(74) + │ │ │ └── fd: ()-->(78) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":83] + │ └── 1 [as="?column?":87] └── with &4 (insert_trade_history) - ├── columns: "?column?":187!null + ├── columns: "?column?":195!null ├── cardinality: [1 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(187) + ├── fd: ()-->(195) ├── project - │ ├── columns: "?column?":115!null + │ ├── columns: "?column?":120!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(115) + │ ├── fd: ()-->(120) │ ├── insert trade_history - │ │ ├── columns: trade_history.th_t_id:84!null trade_history.th_st_id:86!null + │ │ ├── columns: trade_history.th_t_id:88!null trade_history.th_st_id:90!null │ │ ├── insert-mapping: - │ │ │ ├── column1:89 => trade_history.th_t_id:84 - │ │ │ ├── column2:90 => th_dts:85 - │ │ │ └── column3:91 => trade_history.th_st_id:86 + │ │ │ ├── column1:93 => trade_history.th_t_id:88 + │ │ │ ├── column2:94 => th_dts:89 + │ │ │ └── column3:96 => trade_history.th_st_id:90 │ │ ├── input binding: &3 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () - │ │ ├── fd: ()-->(84,86) + │ │ ├── fd: ()-->(88,90) │ │ ├── values - │ │ │ ├── columns: column1:89!null column2:90!null column3:91!null + │ │ │ ├── columns: column1:93!null column2:94!null column3:96 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(89-91) - │ │ │ └── (0, '2020-06-15 22:27:42.148484', 'SBMT') + │ │ │ ├── fd: ()-->(93,94,96) + │ │ │ └── (0, '2020-06-15 22:27:42.148484', crdb_internal.assignment_cast('SBMT', NULL::VARCHAR(4))) │ │ └── f-k-checks │ │ ├── f-k-checks-item: trade_history(th_t_id) -> trade(t_id) │ │ │ └── anti-join (lookup trade) - │ │ │ ├── columns: th_t_id:92!null - │ │ │ ├── key columns: [92] = [93] + │ │ │ ├── columns: th_t_id:97!null + │ │ │ ├── key columns: [97] = [98] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(92) + │ │ │ ├── fd: ()-->(97) │ │ │ ├── with-scan &3 - │ │ │ │ ├── columns: th_t_id:92!null + │ │ │ │ ├── columns: th_t_id:97!null │ │ │ │ ├── mapping: - │ │ │ │ │ └── column1:89 => th_t_id:92 + │ │ │ │ │ └── column1:93 => th_t_id:97 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(92) + │ │ │ │ └── fd: ()-->(97) │ │ │ └── filters (true) │ │ └── f-k-checks-item: trade_history(th_st_id) -> status_type(st_id) │ │ └── anti-join (lookup status_type) - │ │ ├── columns: th_st_id:110!null - │ │ ├── key columns: [110] = [111] + │ │ ├── columns: th_st_id:115 + │ │ ├── key columns: [115] = [116] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(110) + │ │ ├── fd: ()-->(115) │ │ ├── with-scan &3 - │ │ │ ├── columns: th_st_id:110!null + │ │ │ ├── columns: th_st_id:115 │ │ │ ├── mapping: - │ │ │ │ └── column3:91 => th_st_id:110 + │ │ │ │ └── column3:96 => th_st_id:115 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(110) + │ │ │ └── fd: ()-->(115) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":115] + │ └── 1 [as="?column?":120] └── with &6 (insert_trade_request) - ├── columns: "?column?":187!null + ├── columns: "?column?":195!null ├── cardinality: [1 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(187) + ├── fd: ()-->(195) ├── project - │ ├── columns: "?column?":186!null + │ ├── columns: "?column?":194!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(186) + │ ├── fd: ()-->(194) │ ├── insert trade_request - │ │ ├── columns: trade_request.tr_t_id:116!null + │ │ ├── columns: trade_request.tr_t_id:121!null │ │ ├── insert-mapping: - │ │ │ ├── column1:124 => trade_request.tr_t_id:116 - │ │ │ ├── column2:125 => trade_request.tr_tt_id:117 - │ │ │ ├── column3:126 => trade_request.tr_s_symb:118 - │ │ │ ├── column4:127 => tr_qty:119 - │ │ │ ├── tr_bid_price:130 => trade_request.tr_bid_price:120 - │ │ │ └── column6:129 => trade_request.tr_b_id:121 - │ │ ├── check columns: check1:131 check2:132 - │ │ ├── partial index put columns: partial_index_put1:133 + │ │ │ ├── column1:129 => trade_request.tr_t_id:121 + │ │ │ ├── column2:135 => trade_request.tr_tt_id:122 + │ │ │ ├── column3:136 => trade_request.tr_s_symb:123 + │ │ │ ├── column4:137 => tr_qty:124 + │ │ │ ├── column5:138 => tr_bid_price:125 + │ │ │ └── column6:134 => trade_request.tr_b_id:126 + │ │ ├── check columns: check1:139 check2:140 + │ │ ├── partial index put columns: partial_index_put1:141 │ │ ├── input binding: &5 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () - │ │ ├── fd: ()-->(116) - │ │ ├── values - │ │ │ ├── columns: column1:124!null column2:125!null column3:126!null column4:127!null column6:129!null tr_bid_price:130!null check1:131!null check2:132!null partial_index_put1:133!null + │ │ ├── fd: ()-->(121) + │ │ ├── project + │ │ │ ├── columns: partial_index_put1:141 check1:139 check2:140 column1:129!null column6:134!null column2:135 column3:136 column4:137 column5:138 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(124-127,129-133) - │ │ │ └── (0, 'TMB', 'SYMB', 10, 0, 1E+2, true, true, false) + │ │ │ ├── fd: ()-->(129,134-141) + │ │ │ ├── values + │ │ │ │ ├── columns: column1:129!null column6:134!null column2:135 column3:136 column4:137 column5:138 + │ │ │ │ ├── cardinality: [1 - 1] + │ │ │ │ ├── immutable + │ │ │ │ ├── key: () + │ │ │ │ ├── fd: ()-->(129,134-138) + │ │ │ │ └── (0, 0, crdb_internal.assignment_cast('TMB', NULL::VARCHAR(3)), crdb_internal.assignment_cast('SYMB', NULL::VARCHAR(15)), crdb_internal.assignment_cast(10, NULL::INT4), crdb_internal.assignment_cast(1E+2, NULL::DECIMAL(8,2))) + │ │ │ └── projections + │ │ │ ├── column2:135 IN ('TLB', 'TLS', 'TSL') [as=partial_index_put1:141, outer=(135)] + │ │ │ ├── column4:137 > 0 [as=check1:139, outer=(137)] + │ │ │ └── column5:138 > 0 [as=check2:140, outer=(138), immutable] │ │ └── f-k-checks │ │ ├── f-k-checks-item: trade_request(tr_t_id) -> trade(t_id) │ │ │ └── anti-join (lookup trade) - │ │ │ ├── columns: tr_t_id:134!null - │ │ │ ├── key columns: [134] = [135] + │ │ │ ├── columns: tr_t_id:142!null + │ │ │ ├── key columns: [142] = [143] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(134) + │ │ │ ├── fd: ()-->(142) │ │ │ ├── with-scan &5 - │ │ │ │ ├── columns: tr_t_id:134!null + │ │ │ │ ├── columns: tr_t_id:142!null │ │ │ │ ├── mapping: - │ │ │ │ │ └── column1:124 => tr_t_id:134 + │ │ │ │ │ └── column1:129 => tr_t_id:142 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(134) + │ │ │ │ └── fd: ()-->(142) │ │ │ └── filters (true) │ │ ├── f-k-checks-item: trade_request(tr_tt_id) -> trade_type(tt_id) │ │ │ └── anti-join (lookup trade_type) - │ │ │ ├── columns: tr_tt_id:152!null - │ │ │ ├── key columns: [152] = [153] + │ │ │ ├── columns: tr_tt_id:160 + │ │ │ ├── key columns: [160] = [161] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(152) + │ │ │ ├── fd: ()-->(160) │ │ │ ├── with-scan &5 - │ │ │ │ ├── columns: tr_tt_id:152!null + │ │ │ │ ├── columns: tr_tt_id:160 │ │ │ │ ├── mapping: - │ │ │ │ │ └── column2:125 => tr_tt_id:152 + │ │ │ │ │ └── column2:135 => tr_tt_id:160 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(152) + │ │ │ │ └── fd: ()-->(160) │ │ │ └── filters (true) │ │ ├── f-k-checks-item: trade_request(tr_s_symb) -> security(s_symb) │ │ │ └── anti-join (lookup security) - │ │ │ ├── columns: tr_s_symb:159!null - │ │ │ ├── key columns: [159] = [160] + │ │ │ ├── columns: tr_s_symb:167 + │ │ │ ├── key columns: [167] = [168] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(159) + │ │ │ ├── fd: ()-->(167) │ │ │ ├── with-scan &5 - │ │ │ │ ├── columns: tr_s_symb:159!null + │ │ │ │ ├── columns: tr_s_symb:167 │ │ │ │ ├── mapping: - │ │ │ │ │ └── column3:126 => tr_s_symb:159 + │ │ │ │ │ └── column3:136 => tr_s_symb:167 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(159) + │ │ │ │ └── fd: ()-->(167) │ │ │ └── filters (true) │ │ └── f-k-checks-item: trade_request(tr_b_id) -> broker(b_id) │ │ └── anti-join (lookup broker) - │ │ ├── columns: tr_b_id:178!null - │ │ ├── key columns: [178] = [179] + │ │ ├── columns: tr_b_id:186!null + │ │ ├── key columns: [186] = [187] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(178) + │ │ ├── fd: ()-->(186) │ │ ├── with-scan &5 - │ │ │ ├── columns: tr_b_id:178!null + │ │ │ ├── columns: tr_b_id:186!null │ │ │ ├── mapping: - │ │ │ │ └── column6:129 => tr_b_id:178 + │ │ │ │ └── column6:134 => tr_b_id:186 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(178) + │ │ │ └── fd: ()-->(186) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":186] + │ └── 1 [as="?column?":194] └── values - ├── columns: "?column?":187!null + ├── columns: "?column?":195!null ├── cardinality: [1 - 1] ├── key: () - ├── fd: ()-->(187) + ├── fd: ()-->(195) └── (1,) # -------------------------------------------------- @@ -3599,49 +3640,50 @@ insert holding_summary ├── columns: ├── insert-mapping: │ ├── column1:6 => holding_summary.hs_ca_id:1 - │ ├── column2:7 => holding_summary.hs_s_symb:2 - │ └── column3:8 => hs_qty:3 + │ ├── column2:9 => holding_summary.hs_s_symb:2 + │ └── column3:10 => hs_qty:3 ├── input binding: &1 ├── cardinality: [0 - 0] ├── volatile, mutations ├── values - │ ├── columns: column1:6!null column2:7!null column3:8!null + │ ├── columns: column1:6!null column2:9 column3:10 │ ├── cardinality: [1 - 1] + │ ├── immutable │ ├── key: () - │ ├── fd: ()-->(6-8) - │ └── (0, 'ROACH', 100) + │ ├── fd: ()-->(6,9,10) + │ └── (0, crdb_internal.assignment_cast('ROACH', NULL::VARCHAR(15)), crdb_internal.assignment_cast(100, NULL::INT4)) └── f-k-checks ├── f-k-checks-item: holding_summary(hs_ca_id) -> customer_account(ca_id) │ └── anti-join (lookup customer_account) - │ ├── columns: hs_ca_id:9!null - │ ├── key columns: [9] = [10] + │ ├── columns: hs_ca_id:11!null + │ ├── key columns: [11] = [12] │ ├── lookup columns are key │ ├── cardinality: [0 - 1] │ ├── key: () - │ ├── fd: ()-->(9) + │ ├── fd: ()-->(11) │ ├── with-scan &1 - │ │ ├── columns: hs_ca_id:9!null + │ │ ├── columns: hs_ca_id:11!null │ │ ├── mapping: - │ │ │ └── column1:6 => hs_ca_id:9 + │ │ │ └── column1:6 => hs_ca_id:11 │ │ ├── cardinality: [1 - 1] │ │ ├── key: () - │ │ └── fd: ()-->(9) + │ │ └── fd: ()-->(11) │ └── filters (true) └── f-k-checks-item: holding_summary(hs_s_symb) -> security(s_symb) └── anti-join (lookup security) - ├── columns: hs_s_symb:18!null - ├── key columns: [18] = [19] + ├── columns: hs_s_symb:20 + ├── key columns: [20] = [21] ├── lookup columns are key ├── cardinality: [0 - 1] ├── key: () - ├── fd: ()-->(18) + ├── fd: ()-->(20) ├── with-scan &1 - │ ├── columns: hs_s_symb:18!null + │ ├── columns: hs_s_symb:20 │ ├── mapping: - │ │ └── column2:7 => hs_s_symb:18 + │ │ └── column2:9 => hs_s_symb:20 │ ├── cardinality: [1 - 1] │ ├── key: () - │ └── fd: ()-->(18) + │ └── fd: ()-->(20) └── filters (true) # Q4 @@ -3837,53 +3879,62 @@ insert holding ├── insert-mapping: │ ├── column1:9 => holding.h_t_id:1 │ ├── column2:10 => holding.h_ca_id:2 - │ ├── column3:11 => holding.h_s_symb:3 + │ ├── column3:15 => holding.h_s_symb:3 │ ├── column4:12 => h_dts:4 - │ ├── h_price:15 => holding.h_price:5 - │ └── column6:14 => h_qty:6 - ├── check columns: check1:16 + │ ├── column5:16 => h_price:5 + │ └── column6:17 => h_qty:6 + ├── check columns: check1:18 ├── input binding: &1 ├── cardinality: [0 - 0] ├── volatile, mutations - ├── values - │ ├── columns: column1:9!null column2:10!null column3:11!null column4:12!null column6:14!null h_price:15!null check1:16!null + ├── project + │ ├── columns: check1:18 column1:9!null column2:10!null column4:12!null column3:15 column5:16 column6:17 │ ├── cardinality: [1 - 1] + │ ├── immutable │ ├── key: () - │ ├── fd: ()-->(9-12,14-16) - │ └── (0, 0, 'ROACH', '2020-06-15 22:27:42.148484', 10, 1E+2, true) + │ ├── fd: ()-->(9,10,12,15-18) + │ ├── values + │ │ ├── columns: column1:9!null column2:10!null column4:12!null column3:15 column5:16 column6:17 + │ │ ├── cardinality: [1 - 1] + │ │ ├── immutable + │ │ ├── key: () + │ │ ├── fd: ()-->(9,10,12,15-17) + │ │ └── (0, 0, '2020-06-15 22:27:42.148484', crdb_internal.assignment_cast('ROACH', NULL::VARCHAR(15)), crdb_internal.assignment_cast(1E+2, NULL::DECIMAL(8,2)), crdb_internal.assignment_cast(10, NULL::INT4)) + │ └── projections + │ └── column5:16 > 0 [as=check1:18, outer=(16), immutable] └── f-k-checks ├── f-k-checks-item: holding(h_t_id) -> trade(t_id) │ └── anti-join (lookup trade) - │ ├── columns: h_t_id:17!null - │ ├── key columns: [17] = [18] + │ ├── columns: h_t_id:19!null + │ ├── key columns: [19] = [20] │ ├── lookup columns are key │ ├── cardinality: [0 - 1] │ ├── key: () - │ ├── fd: ()-->(17) + │ ├── fd: ()-->(19) │ ├── with-scan &1 - │ │ ├── columns: h_t_id:17!null + │ │ ├── columns: h_t_id:19!null │ │ ├── mapping: - │ │ │ └── column1:9 => h_t_id:17 + │ │ │ └── column1:9 => h_t_id:19 │ │ ├── cardinality: [1 - 1] │ │ ├── key: () - │ │ └── fd: ()-->(17) + │ │ └── fd: ()-->(19) │ └── filters (true) └── f-k-checks-item: holding(h_ca_id,h_s_symb) -> holding_summary(hs_ca_id,hs_s_symb) └── anti-join (lookup holding_summary) - ├── columns: h_ca_id:35!null h_s_symb:36!null - ├── key columns: [35 36] = [37 38] + ├── columns: h_ca_id:37!null h_s_symb:38 + ├── key columns: [37 38] = [39 40] ├── lookup columns are key ├── cardinality: [0 - 1] ├── key: () - ├── fd: ()-->(35,36) + ├── fd: ()-->(37,38) ├── with-scan &1 - │ ├── columns: h_ca_id:35!null h_s_symb:36!null + │ ├── columns: h_ca_id:37!null h_s_symb:38 │ ├── mapping: - │ │ ├── column2:10 => h_ca_id:35 - │ │ └── column3:11 => h_s_symb:36 + │ │ ├── column2:10 => h_ca_id:37 + │ │ └── column3:15 => h_s_symb:38 │ ├── cardinality: [1 - 1] │ ├── key: () - │ └── fd: ()-->(35,36) + │ └── fd: ()-->(37,38) └── filters (true) # Q11 @@ -4157,11 +4208,11 @@ insert_trade_history AS ( SELECT 1 ---- with &2 (update_trade_commission) - ├── columns: "?column?":102!null + ├── columns: "?column?":103!null ├── cardinality: [1 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(102) + ├── fd: ()-->(103) ├── project │ ├── columns: "?column?":51!null │ ├── cardinality: [0 - 1] @@ -4219,11 +4270,11 @@ with &2 (update_trade_commission) │ └── projections │ └── 1 [as="?column?":51] └── with &4 (update_broker_commission) - ├── columns: "?column?":102!null + ├── columns: "?column?":103!null ├── cardinality: [1 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(102) + ├── fd: ()-->(103) ├── project │ ├── columns: "?column?":69!null │ ├── cardinality: [0 - 1] @@ -4258,74 +4309,75 @@ with &2 (update_trade_commission) │ └── projections │ └── 1 [as="?column?":69] └── with &6 (insert_trade_history) - ├── columns: "?column?":102!null + ├── columns: "?column?":103!null ├── cardinality: [1 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(102) + ├── fd: ()-->(103) ├── project - │ ├── columns: "?column?":101!null + │ ├── columns: "?column?":102!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(101) + │ ├── fd: ()-->(102) │ ├── insert trade_history │ │ ├── columns: trade_history.th_t_id:70!null trade_history.th_st_id:72!null │ │ ├── insert-mapping: │ │ │ ├── column1:75 => trade_history.th_t_id:70 │ │ │ ├── column2:76 => th_dts:71 - │ │ │ └── column3:77 => trade_history.th_st_id:72 + │ │ │ └── column3:78 => trade_history.th_st_id:72 │ │ ├── input binding: &5 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () │ │ ├── fd: ()-->(70,72) │ │ ├── values - │ │ │ ├── columns: column1:75!null column2:76!null column3:77!null + │ │ │ ├── columns: column1:75!null column2:76!null column3:78 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(75-77) - │ │ │ └── (0, '2020-06-15 22:27:42.148484', 'ACTV') + │ │ │ ├── fd: ()-->(75,76,78) + │ │ │ └── (0, '2020-06-15 22:27:42.148484', crdb_internal.assignment_cast('ACTV', NULL::VARCHAR(4))) │ │ └── f-k-checks │ │ ├── f-k-checks-item: trade_history(th_t_id) -> trade(t_id) │ │ │ └── anti-join (lookup trade) - │ │ │ ├── columns: th_t_id:78!null - │ │ │ ├── key columns: [78] = [79] + │ │ │ ├── columns: th_t_id:79!null + │ │ │ ├── key columns: [79] = [80] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(78) + │ │ │ ├── fd: ()-->(79) │ │ │ ├── with-scan &5 - │ │ │ │ ├── columns: th_t_id:78!null + │ │ │ │ ├── columns: th_t_id:79!null │ │ │ │ ├── mapping: - │ │ │ │ │ └── column1:75 => th_t_id:78 + │ │ │ │ │ └── column1:75 => th_t_id:79 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(78) + │ │ │ │ └── fd: ()-->(79) │ │ │ └── filters (true) │ │ └── f-k-checks-item: trade_history(th_st_id) -> status_type(st_id) │ │ └── anti-join (lookup status_type) - │ │ ├── columns: th_st_id:96!null - │ │ ├── key columns: [96] = [97] + │ │ ├── columns: th_st_id:97 + │ │ ├── key columns: [97] = [98] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(96) + │ │ ├── fd: ()-->(97) │ │ ├── with-scan &5 - │ │ │ ├── columns: th_st_id:96!null + │ │ │ ├── columns: th_st_id:97 │ │ │ ├── mapping: - │ │ │ │ └── column3:77 => th_st_id:96 + │ │ │ │ └── column3:78 => th_st_id:97 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(96) + │ │ │ └── fd: ()-->(97) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":101] + │ └── 1 [as="?column?":102] └── values - ├── columns: "?column?":102!null + ├── columns: "?column?":103!null ├── cardinality: [1 - 1] ├── key: () - ├── fd: ()-->(102) + ├── fd: ()-->(103) └── (1,) @@ -4355,134 +4407,136 @@ WHERE ca_id = 0 RETURNING ca_bal::FLOAT8; ---- with &2 (insert_settlement) - ├── columns: ca_bal:80!null + ├── columns: ca_bal:82!null ├── cardinality: [0 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(80) + ├── fd: ()-->(82) ├── project - │ ├── columns: "?column?":30!null + │ ├── columns: "?column?":31!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(30) + │ ├── fd: ()-->(31) │ ├── insert settlement │ │ ├── columns: settlement.se_t_id:1!null │ │ ├── insert-mapping: │ │ │ ├── column1:7 => settlement.se_t_id:1 - │ │ │ ├── column2:8 => se_cash_type:2 + │ │ │ ├── column2:11 => se_cash_type:2 │ │ │ ├── column3:9 => se_cash_due_date:3 - │ │ │ └── se_amt:11 => settlement.se_amt:4 + │ │ │ └── column4:12 => se_amt:4 │ │ ├── input binding: &1 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () │ │ ├── fd: ()-->(1) │ │ ├── values - │ │ │ ├── columns: column1:7!null column2:8!null column3:9!null se_amt:11!null + │ │ │ ├── columns: column1:7!null column3:9!null column2:11 column4:12 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(7-9,11) - │ │ │ └── (0, 'Margin', '2020-06-15', 1E+2) + │ │ │ ├── fd: ()-->(7,9,11,12) + │ │ │ └── (0, '2020-06-15', crdb_internal.assignment_cast('Margin', NULL::VARCHAR(40)), crdb_internal.assignment_cast(1E+2, NULL::DECIMAL(10,2))) │ │ └── f-k-checks │ │ └── f-k-checks-item: settlement(se_t_id) -> trade(t_id) │ │ └── anti-join (lookup trade) - │ │ ├── columns: se_t_id:12!null - │ │ ├── key columns: [12] = [13] + │ │ ├── columns: se_t_id:13!null + │ │ ├── key columns: [13] = [14] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(12) + │ │ ├── fd: ()-->(13) │ │ ├── with-scan &1 - │ │ │ ├── columns: se_t_id:12!null + │ │ │ ├── columns: se_t_id:13!null │ │ │ ├── mapping: - │ │ │ │ └── column1:7 => se_t_id:12 + │ │ │ │ └── column1:7 => se_t_id:13 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(12) + │ │ │ └── fd: ()-->(13) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":30] + │ └── 1 [as="?column?":31] └── with &4 (insert_cash_transaction) - ├── columns: ca_bal:80!null + ├── columns: ca_bal:82!null ├── cardinality: [0 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(80) + ├── fd: ()-->(82) ├── project - │ ├── columns: "?column?":60!null + │ ├── columns: "?column?":62!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(60) + │ ├── fd: ()-->(62) │ ├── insert cash_transaction - │ │ ├── columns: cash_transaction.ct_t_id:31!null + │ │ ├── columns: cash_transaction.ct_t_id:32!null │ │ ├── insert-mapping: - │ │ │ ├── column1:37 => cash_transaction.ct_t_id:31 - │ │ │ ├── column2:38 => ct_dts:32 - │ │ │ ├── ct_amt:41 => cash_transaction.ct_amt:33 - │ │ │ └── column4:40 => ct_name:34 + │ │ │ ├── column1:38 => cash_transaction.ct_t_id:32 + │ │ │ ├── column2:39 => ct_dts:33 + │ │ │ ├── column3:42 => ct_amt:34 + │ │ │ └── column4:43 => ct_name:35 │ │ ├── input binding: &3 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () - │ │ ├── fd: ()-->(31) + │ │ ├── fd: ()-->(32) │ │ ├── values - │ │ │ ├── columns: column1:37!null column2:38!null column4:40!null ct_amt:41!null + │ │ │ ├── columns: column1:38!null column2:39!null column3:42 column4:43 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(37,38,40,41) - │ │ │ └── (0, '2020-06-10 22:27:42.148484', 'Buy 2 shares of ROACH', 1E+2) + │ │ │ ├── fd: ()-->(38,39,42,43) + │ │ │ └── (0, '2020-06-10 22:27:42.148484', crdb_internal.assignment_cast(1E+2, NULL::DECIMAL(10,2)), crdb_internal.assignment_cast('Buy 2 shares of ROACH', NULL::VARCHAR(100))) │ │ └── f-k-checks │ │ └── f-k-checks-item: cash_transaction(ct_t_id) -> trade(t_id) │ │ └── anti-join (lookup trade) - │ │ ├── columns: ct_t_id:42!null - │ │ ├── key columns: [42] = [43] + │ │ ├── columns: ct_t_id:44!null + │ │ ├── key columns: [44] = [45] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(42) + │ │ ├── fd: ()-->(44) │ │ ├── with-scan &3 - │ │ │ ├── columns: ct_t_id:42!null + │ │ │ ├── columns: ct_t_id:44!null │ │ │ ├── mapping: - │ │ │ │ └── column1:37 => ct_t_id:42 + │ │ │ │ └── column1:38 => ct_t_id:44 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(42) + │ │ │ └── fd: ()-->(44) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":60] + │ └── 1 [as="?column?":62] └── project - ├── columns: ca_bal:80!null + ├── columns: ca_bal:82!null ├── cardinality: [0 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(80) + ├── fd: ()-->(82) ├── update customer_account - │ ├── columns: ca_id:61!null customer_account.ca_bal:66!null - │ ├── fetch columns: ca_id:69 ca_b_id:70 ca_c_id:71 ca_name:72 ca_tax_st:73 customer_account.ca_bal:74 + │ ├── columns: ca_id:63!null customer_account.ca_bal:68!null + │ ├── fetch columns: ca_id:71 ca_b_id:72 ca_c_id:73 ca_name:74 ca_tax_st:75 customer_account.ca_bal:76 │ ├── update-mapping: - │ │ └── ca_bal_new:78 => customer_account.ca_bal:66 + │ │ └── ca_bal_new:80 => customer_account.ca_bal:68 │ ├── cardinality: [0 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(61,66) + │ ├── fd: ()-->(63,68) │ └── project - │ ├── columns: ca_bal_new:78 ca_id:69!null ca_b_id:70!null ca_c_id:71!null ca_name:72 ca_tax_st:73!null customer_account.ca_bal:74!null + │ ├── columns: ca_bal_new:80 ca_id:71!null ca_b_id:72!null ca_c_id:73!null ca_name:74 ca_tax_st:75!null customer_account.ca_bal:76!null │ ├── cardinality: [0 - 1] │ ├── immutable │ ├── key: () - │ ├── fd: ()-->(69-74,78) + │ ├── fd: ()-->(71-76,80) │ ├── scan customer_account - │ │ ├── columns: ca_id:69!null ca_b_id:70!null ca_c_id:71!null ca_name:72 ca_tax_st:73!null customer_account.ca_bal:74!null - │ │ ├── constraint: /69: [/0 - /0] + │ │ ├── columns: ca_id:71!null ca_b_id:72!null ca_c_id:73!null ca_name:74 ca_tax_st:75!null customer_account.ca_bal:76!null + │ │ ├── constraint: /71: [/0 - /0] │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ └── fd: ()-->(69-74) + │ │ └── fd: ()-->(71-76) │ └── projections - │ └── crdb_internal.round_decimal_values(customer_account.ca_bal:74::DECIMAL + 1E+2, 2) [as=ca_bal_new:78, outer=(74), immutable] + │ └── crdb_internal.round_decimal_values(customer_account.ca_bal:76::DECIMAL + 1E+2, 2) [as=ca_bal_new:80, outer=(76), immutable] └── projections - └── customer_account.ca_bal:66::FLOAT8 [as=ca_bal:80, outer=(66), immutable] + └── customer_account.ca_bal:68::FLOAT8 [as=ca_bal:82, outer=(68), immutable] # Q16 opt @@ -4496,68 +4550,69 @@ insert_settlement AS ( SELECT ca_bal::FLOAT8 FROM customer_account WHERE ca_id = 0; ---- with &2 (insert_settlement) - ├── columns: ca_bal:39!null + ├── columns: ca_bal:40!null ├── cardinality: [0 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(39) + ├── fd: ()-->(40) ├── project - │ ├── columns: "?column?":30!null + │ ├── columns: "?column?":31!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(30) + │ ├── fd: ()-->(31) │ ├── insert settlement │ │ ├── columns: settlement.se_t_id:1!null │ │ ├── insert-mapping: │ │ │ ├── column1:7 => settlement.se_t_id:1 - │ │ │ ├── column2:8 => se_cash_type:2 + │ │ │ ├── column2:11 => se_cash_type:2 │ │ │ ├── column3:9 => se_cash_due_date:3 - │ │ │ └── se_amt:11 => settlement.se_amt:4 + │ │ │ └── column4:12 => se_amt:4 │ │ ├── input binding: &1 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () │ │ ├── fd: ()-->(1) │ │ ├── values - │ │ │ ├── columns: column1:7!null column2:8!null column3:9!null se_amt:11!null + │ │ │ ├── columns: column1:7!null column3:9!null column2:11 column4:12 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(7-9,11) - │ │ │ └── (0, 'Margin', '2020-06-15', 1E+2) + │ │ │ ├── fd: ()-->(7,9,11,12) + │ │ │ └── (0, '2020-06-15', crdb_internal.assignment_cast('Margin', NULL::VARCHAR(40)), crdb_internal.assignment_cast(1E+2, NULL::DECIMAL(10,2))) │ │ └── f-k-checks │ │ └── f-k-checks-item: settlement(se_t_id) -> trade(t_id) │ │ └── anti-join (lookup trade) - │ │ ├── columns: se_t_id:12!null - │ │ ├── key columns: [12] = [13] + │ │ ├── columns: se_t_id:13!null + │ │ ├── key columns: [13] = [14] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(12) + │ │ ├── fd: ()-->(13) │ │ ├── with-scan &1 - │ │ │ ├── columns: se_t_id:12!null + │ │ │ ├── columns: se_t_id:13!null │ │ │ ├── mapping: - │ │ │ │ └── column1:7 => se_t_id:12 + │ │ │ │ └── column1:7 => se_t_id:13 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(12) + │ │ │ └── fd: ()-->(13) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":30] + │ └── 1 [as="?column?":31] └── project - ├── columns: ca_bal:39!null + ├── columns: ca_bal:40!null ├── cardinality: [0 - 1] ├── immutable ├── key: () - ├── fd: ()-->(39) + ├── fd: ()-->(40) ├── scan customer_account - │ ├── columns: ca_id:31!null customer_account.ca_bal:36!null - │ ├── constraint: /31: [/0 - /0] + │ ├── columns: ca_id:32!null customer_account.ca_bal:37!null + │ ├── constraint: /32: [/0 - /0] │ ├── cardinality: [0 - 1] │ ├── key: () - │ └── fd: ()-->(31,36) + │ └── fd: ()-->(32,37) └── projections - └── customer_account.ca_bal:36::FLOAT8 [as=ca_bal:39, outer=(36), immutable] + └── customer_account.ca_bal:37::FLOAT8 [as=ca_bal:40, outer=(37), immutable] # -------------------------------------------------- # T9 diff --git a/pkg/sql/opt/xform/testdata/external/tpce-no-stats b/pkg/sql/opt/xform/testdata/external/tpce-no-stats index 8d25e672b3eb..01f147523b85 100644 --- a/pkg/sql/opt/xform/testdata/external/tpce-no-stats +++ b/pkg/sql/opt/xform/testdata/external/tpce-no-stats @@ -570,10 +570,10 @@ update_trade_submitted AS ( SELECT * FROM request_list; ---- with &2 (update_last_trade) - ├── columns: tr_t_id:137!null tr_bid_price:138!null tr_tt_id:139!null tr_qty:140!null + ├── columns: tr_t_id:138!null tr_bid_price:139!null tr_tt_id:140!null tr_qty:141!null ├── volatile, mutations - ├── key: (137) - ├── fd: (137)-->(138-140) + ├── key: (138) + ├── fd: (138)-->(139-141) ├── project │ ├── columns: "?column?":19 │ ├── cardinality: [0 - 1] @@ -610,10 +610,10 @@ with &2 (update_last_trade) │ └── projections │ └── NULL [as="?column?":19] └── with &3 (request_list) - ├── columns: tr_t_id:137!null tr_bid_price:138!null tr_tt_id:139!null tr_qty:140!null + ├── columns: tr_t_id:138!null tr_bid_price:139!null tr_tt_id:140!null tr_qty:141!null ├── volatile, mutations - ├── key: (137) - ├── fd: (137)-->(138-140) + ├── key: (138) + ├── fd: (138)-->(139-141) ├── project │ ├── columns: tr_bid_price:28!null trade_request.tr_t_id:20!null trade_request.tr_tt_id:21!null trade_request.tr_qty:23!null │ ├── immutable @@ -640,10 +640,10 @@ with &2 (update_last_trade) │ └── projections │ └── trade_request.tr_bid_price:24::FLOAT8 [as=tr_bid_price:28, outer=(24), immutable] └── with &4 (delete_trade_request) - ├── columns: tr_t_id:137!null tr_bid_price:138!null tr_tt_id:139!null tr_qty:140!null + ├── columns: tr_t_id:138!null tr_bid_price:139!null tr_tt_id:140!null tr_qty:141!null ├── volatile, mutations - ├── key: (137) - ├── fd: (137)-->(138-140) + ├── key: (138) + ├── fd: (138)-->(139-141) ├── project │ ├── columns: "?column?":50 │ ├── volatile, mutations @@ -679,128 +679,130 @@ with &2 (update_last_trade) │ └── projections │ └── NULL [as="?column?":50] └── with &6 (insert_trade_history) - ├── columns: tr_t_id:137!null tr_bid_price:138!null tr_tt_id:139!null tr_qty:140!null + ├── columns: tr_t_id:138!null tr_bid_price:139!null tr_tt_id:140!null tr_qty:141!null ├── volatile, mutations - ├── key: (137) - ├── fd: (137)-->(138-140) + ├── key: (138) + ├── fd: (138)-->(139-141) ├── project - │ ├── columns: "?column?":85 + │ ├── columns: "?column?":86 │ ├── volatile, mutations - │ ├── fd: ()-->(85) + │ ├── fd: ()-->(86) │ ├── insert trade_history │ │ ├── columns: trade_history.th_t_id:51!null trade_history.th_st_id:53!null │ │ ├── insert-mapping: │ │ │ ├── tr_t_id:56 => trade_history.th_t_id:51 │ │ │ ├── timestamp:61 => th_dts:52 - │ │ │ └── "?column?":60 => trade_history.th_st_id:53 + │ │ │ └── "?column?":62 => trade_history.th_st_id:53 │ │ ├── input binding: &5 │ │ ├── volatile, mutations │ │ ├── key: (51) │ │ ├── fd: ()-->(53) │ │ ├── project - │ │ │ ├── columns: "?column?":60!null timestamp:61!null tr_t_id:56!null + │ │ │ ├── columns: "?column?":62 timestamp:61!null tr_t_id:56!null + │ │ │ ├── immutable │ │ │ ├── key: (56) - │ │ │ ├── fd: ()-->(60,61) + │ │ │ ├── fd: ()-->(61,62) │ │ │ ├── with-scan &3 (request_list) │ │ │ │ ├── columns: tr_t_id:56!null │ │ │ │ ├── mapping: │ │ │ │ │ └── trade_request.tr_t_id:20 => tr_t_id:56 │ │ │ │ └── key: (56) │ │ │ └── projections - │ │ │ ├── 'SBMT' [as="?column?":60] + │ │ │ ├── assignment-cast: VARCHAR(4) [as="?column?":62, immutable] + │ │ │ │ └── 'SBMT' │ │ │ └── '2020-06-15 22:27:42.148484' [as=timestamp:61] │ │ └── f-k-checks │ │ ├── f-k-checks-item: trade_history(th_t_id) -> trade(t_id) │ │ │ └── anti-join (lookup trade) - │ │ │ ├── columns: th_t_id:62!null - │ │ │ ├── key columns: [62] = [63] + │ │ │ ├── columns: th_t_id:63!null + │ │ │ ├── key columns: [63] = [64] │ │ │ ├── lookup columns are key - │ │ │ ├── key: (62) + │ │ │ ├── key: (63) │ │ │ ├── with-scan &5 - │ │ │ │ ├── columns: th_t_id:62!null + │ │ │ │ ├── columns: th_t_id:63!null │ │ │ │ ├── mapping: - │ │ │ │ │ └── tr_t_id:56 => th_t_id:62 - │ │ │ │ └── key: (62) + │ │ │ │ │ └── tr_t_id:56 => th_t_id:63 + │ │ │ │ └── key: (63) │ │ │ └── filters (true) │ │ └── f-k-checks-item: trade_history(th_st_id) -> status_type(st_id) │ │ └── anti-join (lookup status_type) - │ │ ├── columns: th_st_id:80!null - │ │ ├── key columns: [80] = [81] + │ │ ├── columns: th_st_id:81 + │ │ ├── key columns: [81] = [82] │ │ ├── lookup columns are key - │ │ ├── fd: ()-->(80) + │ │ ├── fd: ()-->(81) │ │ ├── with-scan &5 - │ │ │ ├── columns: th_st_id:80!null + │ │ │ ├── columns: th_st_id:81 │ │ │ ├── mapping: - │ │ │ │ └── "?column?":60 => th_st_id:80 - │ │ │ └── fd: ()-->(80) + │ │ │ │ └── "?column?":62 => th_st_id:81 + │ │ │ └── fd: ()-->(81) │ │ └── filters (true) │ └── projections - │ └── NULL [as="?column?":85] + │ └── NULL [as="?column?":86] └── with &8 (update_trade_submitted) - ├── columns: tr_t_id:137!null tr_bid_price:138!null tr_tt_id:139!null tr_qty:140!null + ├── columns: tr_t_id:138!null tr_bid_price:139!null tr_tt_id:140!null tr_qty:141!null ├── volatile, mutations - ├── key: (137) - ├── fd: (137)-->(138-140) + ├── key: (138) + ├── fd: (138)-->(139-141) ├── project - │ ├── columns: "?column?":136 + │ ├── columns: "?column?":137 │ ├── volatile, mutations - │ ├── fd: ()-->(136) + │ ├── fd: ()-->(137) │ ├── update trade - │ │ ├── columns: t_id:86!null - │ │ ├── fetch columns: t_id:103 t_dts:104 trade.t_st_id:105 t_tt_id:106 t_is_cash:107 t_s_symb:108 t_qty:109 t_bid_price:110 t_ca_id:111 t_exec_name:112 t_trade_price:113 t_chrg:114 t_comm:115 t_lifo:117 + │ │ ├── columns: t_id:87!null + │ │ ├── fetch columns: t_id:104 t_dts:105 trade.t_st_id:106 t_tt_id:107 t_is_cash:108 t_s_symb:109 t_qty:110 t_bid_price:111 t_ca_id:112 t_exec_name:113 t_trade_price:114 t_chrg:115 t_comm:116 t_lifo:118 │ │ ├── update-mapping: - │ │ │ ├── t_dts_new:125 => t_dts:87 - │ │ │ └── t_st_id_new:124 => trade.t_st_id:88 + │ │ │ ├── t_dts_new:126 => t_dts:88 + │ │ │ └── t_st_id_new:125 => trade.t_st_id:89 │ │ ├── input binding: &7 │ │ ├── volatile, mutations - │ │ ├── key: (86) + │ │ ├── key: (87) │ │ ├── project - │ │ │ ├── columns: t_st_id_new:124!null t_dts_new:125!null t_id:103!null t_dts:104!null trade.t_st_id:105!null t_tt_id:106!null t_is_cash:107!null t_s_symb:108!null t_qty:109!null t_bid_price:110!null t_ca_id:111!null t_exec_name:112!null t_trade_price:113 t_chrg:114!null t_comm:115!null t_lifo:117!null - │ │ │ ├── key: (103) - │ │ │ ├── fd: ()-->(124,125), (103)-->(104-115,117) + │ │ │ ├── columns: t_st_id_new:125!null t_dts_new:126!null t_id:104!null t_dts:105!null trade.t_st_id:106!null t_tt_id:107!null t_is_cash:108!null t_s_symb:109!null t_qty:110!null t_bid_price:111!null t_ca_id:112!null t_exec_name:113!null t_trade_price:114 t_chrg:115!null t_comm:116!null t_lifo:118!null + │ │ │ ├── key: (104) + │ │ │ ├── fd: ()-->(125,126), (104)-->(105-116,118) │ │ │ ├── project - │ │ │ │ ├── columns: t_id:103!null t_dts:104!null trade.t_st_id:105!null t_tt_id:106!null t_is_cash:107!null t_s_symb:108!null t_qty:109!null t_bid_price:110!null t_ca_id:111!null t_exec_name:112!null t_trade_price:113 t_chrg:114!null t_comm:115!null t_lifo:117!null - │ │ │ │ ├── key: (103) - │ │ │ │ ├── fd: (103)-->(104-115,117) + │ │ │ │ ├── columns: t_id:104!null t_dts:105!null trade.t_st_id:106!null t_tt_id:107!null t_is_cash:108!null t_s_symb:109!null t_qty:110!null t_bid_price:111!null t_ca_id:112!null t_exec_name:113!null t_trade_price:114 t_chrg:115!null t_comm:116!null t_lifo:118!null + │ │ │ │ ├── key: (104) + │ │ │ │ ├── fd: (104)-->(105-116,118) │ │ │ │ └── inner-join (lookup trade) - │ │ │ │ ├── columns: t_id:103!null t_dts:104!null trade.t_st_id:105!null t_tt_id:106!null t_is_cash:107!null t_s_symb:108!null t_qty:109!null t_bid_price:110!null t_ca_id:111!null t_exec_name:112!null t_trade_price:113 t_chrg:114!null t_comm:115!null t_lifo:117!null tr_t_id:120!null - │ │ │ │ ├── key columns: [120] = [103] + │ │ │ │ ├── columns: t_id:104!null t_dts:105!null trade.t_st_id:106!null t_tt_id:107!null t_is_cash:108!null t_s_symb:109!null t_qty:110!null t_bid_price:111!null t_ca_id:112!null t_exec_name:113!null t_trade_price:114 t_chrg:115!null t_comm:116!null t_lifo:118!null tr_t_id:121!null + │ │ │ │ ├── key columns: [121] = [104] │ │ │ │ ├── lookup columns are key - │ │ │ │ ├── key: (120) - │ │ │ │ ├── fd: (103)-->(104-115,117), (103)==(120), (120)==(103) + │ │ │ │ ├── key: (121) + │ │ │ │ ├── fd: (104)-->(105-116,118), (104)==(121), (121)==(104) │ │ │ │ ├── with-scan &3 (request_list) - │ │ │ │ │ ├── columns: tr_t_id:120!null + │ │ │ │ │ ├── columns: tr_t_id:121!null │ │ │ │ │ ├── mapping: - │ │ │ │ │ │ └── trade_request.tr_t_id:20 => tr_t_id:120 - │ │ │ │ │ └── key: (120) + │ │ │ │ │ │ └── trade_request.tr_t_id:20 => tr_t_id:121 + │ │ │ │ │ └── key: (121) │ │ │ │ └── filters (true) │ │ │ └── projections - │ │ │ ├── 'SBMT' [as=t_st_id_new:124] - │ │ │ └── '2020-06-15 22:27:42.148484' [as=t_dts_new:125] + │ │ │ ├── 'SBMT' [as=t_st_id_new:125] + │ │ │ └── '2020-06-15 22:27:42.148484' [as=t_dts_new:126] │ │ └── f-k-checks │ │ └── f-k-checks-item: trade(t_st_id) -> status_type(st_id) │ │ └── anti-join (lookup status_type) - │ │ ├── columns: t_st_id:131!null - │ │ ├── key columns: [131] = [132] + │ │ ├── columns: t_st_id:132!null + │ │ ├── key columns: [132] = [133] │ │ ├── lookup columns are key - │ │ ├── fd: ()-->(131) + │ │ ├── fd: ()-->(132) │ │ ├── with-scan &7 - │ │ │ ├── columns: t_st_id:131!null + │ │ │ ├── columns: t_st_id:132!null │ │ │ ├── mapping: - │ │ │ │ └── t_st_id_new:124 => t_st_id:131 - │ │ │ └── fd: ()-->(131) + │ │ │ │ └── t_st_id_new:125 => t_st_id:132 + │ │ │ └── fd: ()-->(132) │ │ └── filters (true) │ └── projections - │ └── NULL [as="?column?":136] + │ └── NULL [as="?column?":137] └── with-scan &3 (request_list) - ├── columns: tr_t_id:137!null tr_bid_price:138!null tr_tt_id:139!null tr_qty:140!null + ├── columns: tr_t_id:138!null tr_bid_price:139!null tr_tt_id:140!null tr_qty:141!null ├── mapping: - │ ├── trade_request.tr_t_id:20 => tr_t_id:137 - │ ├── tr_bid_price:28 => tr_bid_price:138 - │ ├── trade_request.tr_tt_id:21 => tr_tt_id:139 - │ └── trade_request.tr_qty:23 => tr_qty:140 - ├── key: (137) - └── fd: (137)-->(138-140) + │ ├── trade_request.tr_t_id:20 => tr_t_id:138 + │ ├── tr_bid_price:28 => tr_bid_price:139 + │ ├── trade_request.tr_tt_id:21 => tr_tt_id:140 + │ └── trade_request.tr_qty:23 => tr_qty:141 + ├── key: (138) + └── fd: (138)-->(139-141) # -------------------------------------------------- # T4 @@ -2952,183 +2954,197 @@ insert_trade_history AS ( SELECT 1; ---- with &2 (insert_trade) - ├── columns: "?column?":116!null + ├── columns: "?column?":121!null ├── cardinality: [1 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(116) + ├── fd: ()-->(121) ├── project - │ ├── columns: "?column?":83!null + │ ├── columns: "?column?":87!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(83) + │ ├── fd: ()-->(87) │ ├── insert trade │ │ ├── columns: t_id:1!null │ │ ├── insert-mapping: │ │ │ ├── column1:18 => t_id:1 │ │ │ ├── column2:19 => t_dts:2 - │ │ │ ├── column3:20 => trade.t_st_id:3 - │ │ │ ├── column4:21 => trade.t_tt_id:4 + │ │ │ ├── column3:33 => trade.t_st_id:3 + │ │ │ ├── column4:34 => trade.t_tt_id:4 │ │ │ ├── column5:22 => t_is_cash:5 - │ │ │ ├── column6:23 => trade.t_s_symb:6 - │ │ │ ├── column7:24 => t_qty:7 - │ │ │ ├── t_bid_price:33 => trade.t_bid_price:8 + │ │ │ ├── column6:35 => trade.t_s_symb:6 + │ │ │ ├── column7:36 => t_qty:7 + │ │ │ ├── column8:37 => t_bid_price:8 │ │ │ ├── column9:26 => trade.t_ca_id:9 - │ │ │ ├── column10:27 => t_exec_name:10 - │ │ │ ├── t_trade_price:34 => trade.t_trade_price:11 - │ │ │ ├── t_chrg:35 => trade.t_chrg:12 - │ │ │ ├── t_comm:36 => trade.t_comm:13 - │ │ │ ├── t_tax:37 => trade.t_tax:14 + │ │ │ ├── column10:38 => t_exec_name:10 + │ │ │ ├── column11:28 => t_trade_price:11 + │ │ │ ├── column12:39 => t_chrg:12 + │ │ │ ├── column13:40 => t_comm:13 + │ │ │ ├── column14:41 => t_tax:14 │ │ │ └── column15:32 => t_lifo:15 - │ │ ├── check columns: check1:38 check2:39 check3:40 check4:41 check5:42 + │ │ ├── check columns: check1:42 check2:43 check3:44 check4:45 check5:46 │ │ ├── input binding: &1 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () │ │ ├── fd: ()-->(1) - │ │ ├── values - │ │ │ ├── columns: column1:18!null column2:19!null column3:20!null column4:21!null column5:22!null column6:23!null column7:24!null column9:26!null column10:27!null column15:32!null t_bid_price:33!null t_trade_price:34 t_chrg:35!null t_comm:36!null t_tax:37!null check1:38!null check2:39!null check3:40!null check4:41!null check5:42!null + │ │ ├── project + │ │ │ ├── columns: check1:42 check2:43 check3:44 check4:45 check5:46 column1:18!null column2:19!null column5:22!null column9:26!null column11:28 column15:32!null column3:33 column4:34 column6:35 column7:36 column8:37 column10:38 column12:39 column13:40 column14:41 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(18-24,26,27,32-42) - │ │ │ └── (0, '2020-06-17 22:27:42.148484', 'SBMT', 'TMB', true, 'SYMB', 10, 0, 'Name', true, 1E+2, NULL, 1, 0, 0, true, true, true, true, true) + │ │ │ ├── fd: ()-->(18,19,22,26,28,32-46) + │ │ │ ├── values + │ │ │ │ ├── columns: column1:18!null column2:19!null column5:22!null column9:26!null column11:28 column15:32!null column3:33 column4:34 column6:35 column7:36 column8:37 column10:38 column12:39 column13:40 column14:41 + │ │ │ │ ├── cardinality: [1 - 1] + │ │ │ │ ├── immutable + │ │ │ │ ├── key: () + │ │ │ │ ├── fd: ()-->(18,19,22,26,28,32-41) + │ │ │ │ └── (0, '2020-06-17 22:27:42.148484', true, 0, CAST(NULL AS DECIMAL(8,2)), true, crdb_internal.assignment_cast('SBMT', NULL::VARCHAR(4)), crdb_internal.assignment_cast('TMB', NULL::VARCHAR(3)), crdb_internal.assignment_cast('SYMB', NULL::VARCHAR(15)), crdb_internal.assignment_cast(10, NULL::INT4), crdb_internal.assignment_cast(1E+2, NULL::DECIMAL(8,2)), crdb_internal.assignment_cast('Name', NULL::VARCHAR(49)), crdb_internal.assignment_cast(1, NULL::DECIMAL(10,2)), crdb_internal.assignment_cast(0, NULL::DECIMAL(10,2)), crdb_internal.assignment_cast(0, NULL::DECIMAL(10,2))) + │ │ │ └── projections + │ │ │ ├── column7:36 > 0 [as=check1:42, outer=(36)] + │ │ │ ├── column8:37 > 0 [as=check2:43, outer=(37), immutable] + │ │ │ ├── column12:39 >= 0 [as=check3:44, outer=(39), immutable] + │ │ │ ├── column13:40 >= 0 [as=check4:45, outer=(40), immutable] + │ │ │ └── column14:41 >= 0 [as=check5:46, outer=(41), immutable] │ │ └── f-k-checks │ │ ├── f-k-checks-item: trade(t_st_id) -> status_type(st_id) │ │ │ └── anti-join (lookup status_type) - │ │ │ ├── columns: t_st_id:43!null - │ │ │ ├── key columns: [43] = [44] + │ │ │ ├── columns: t_st_id:47 + │ │ │ ├── key columns: [47] = [48] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(43) + │ │ │ ├── fd: ()-->(47) │ │ │ ├── with-scan &1 - │ │ │ │ ├── columns: t_st_id:43!null + │ │ │ │ ├── columns: t_st_id:47 │ │ │ │ ├── mapping: - │ │ │ │ │ └── column3:20 => t_st_id:43 + │ │ │ │ │ └── column3:33 => t_st_id:47 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(43) + │ │ │ │ └── fd: ()-->(47) │ │ │ └── filters (true) │ │ ├── f-k-checks-item: trade(t_tt_id) -> trade_type(tt_id) │ │ │ └── anti-join (lookup trade_type) - │ │ │ ├── columns: t_tt_id:48!null - │ │ │ ├── key columns: [48] = [49] + │ │ │ ├── columns: t_tt_id:52 + │ │ │ ├── key columns: [52] = [53] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(48) + │ │ │ ├── fd: ()-->(52) │ │ │ ├── with-scan &1 - │ │ │ │ ├── columns: t_tt_id:48!null + │ │ │ │ ├── columns: t_tt_id:52 │ │ │ │ ├── mapping: - │ │ │ │ │ └── column4:21 => t_tt_id:48 + │ │ │ │ │ └── column4:34 => t_tt_id:52 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(48) + │ │ │ │ └── fd: ()-->(52) │ │ │ └── filters (true) │ │ ├── f-k-checks-item: trade(t_s_symb) -> security(s_symb) │ │ │ └── anti-join (lookup security) - │ │ │ ├── columns: t_s_symb:55!null - │ │ │ ├── key columns: [55] = [56] + │ │ │ ├── columns: t_s_symb:59 + │ │ │ ├── key columns: [59] = [60] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(55) + │ │ │ ├── fd: ()-->(59) │ │ │ ├── with-scan &1 - │ │ │ │ ├── columns: t_s_symb:55!null + │ │ │ │ ├── columns: t_s_symb:59 │ │ │ │ ├── mapping: - │ │ │ │ │ └── column6:23 => t_s_symb:55 + │ │ │ │ │ └── column6:35 => t_s_symb:59 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(55) + │ │ │ │ └── fd: ()-->(59) │ │ │ └── filters (true) │ │ └── f-k-checks-item: trade(t_ca_id) -> customer_account(ca_id) │ │ └── anti-join (lookup customer_account) - │ │ ├── columns: t_ca_id:74!null - │ │ ├── key columns: [74] = [75] + │ │ ├── columns: t_ca_id:78!null + │ │ ├── key columns: [78] = [79] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(74) + │ │ ├── fd: ()-->(78) │ │ ├── with-scan &1 - │ │ │ ├── columns: t_ca_id:74!null + │ │ │ ├── columns: t_ca_id:78!null │ │ │ ├── mapping: - │ │ │ │ └── column9:26 => t_ca_id:74 + │ │ │ │ └── column9:26 => t_ca_id:78 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(74) + │ │ │ └── fd: ()-->(78) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":83] + │ └── 1 [as="?column?":87] └── with &4 (insert_trade_history) - ├── columns: "?column?":116!null + ├── columns: "?column?":121!null ├── cardinality: [1 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(116) + ├── fd: ()-->(121) ├── project - │ ├── columns: "?column?":115!null + │ ├── columns: "?column?":120!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(115) + │ ├── fd: ()-->(120) │ ├── insert trade_history - │ │ ├── columns: trade_history.th_t_id:84!null trade_history.th_st_id:86!null + │ │ ├── columns: trade_history.th_t_id:88!null trade_history.th_st_id:90!null │ │ ├── insert-mapping: - │ │ │ ├── column1:89 => trade_history.th_t_id:84 - │ │ │ ├── column2:90 => th_dts:85 - │ │ │ └── column3:91 => trade_history.th_st_id:86 + │ │ │ ├── column1:93 => trade_history.th_t_id:88 + │ │ │ ├── column2:94 => th_dts:89 + │ │ │ └── column3:96 => trade_history.th_st_id:90 │ │ ├── input binding: &3 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () - │ │ ├── fd: ()-->(84,86) + │ │ ├── fd: ()-->(88,90) │ │ ├── values - │ │ │ ├── columns: column1:89!null column2:90!null column3:91!null + │ │ │ ├── columns: column1:93!null column2:94!null column3:96 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(89-91) - │ │ │ └── (0, '2020-06-15 22:27:42.148484', 'SBMT') + │ │ │ ├── fd: ()-->(93,94,96) + │ │ │ └── (0, '2020-06-15 22:27:42.148484', crdb_internal.assignment_cast('SBMT', NULL::VARCHAR(4))) │ │ └── f-k-checks │ │ ├── f-k-checks-item: trade_history(th_t_id) -> trade(t_id) │ │ │ └── anti-join (lookup trade) - │ │ │ ├── columns: th_t_id:92!null - │ │ │ ├── key columns: [92] = [93] + │ │ │ ├── columns: th_t_id:97!null + │ │ │ ├── key columns: [97] = [98] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(92) + │ │ │ ├── fd: ()-->(97) │ │ │ ├── with-scan &3 - │ │ │ │ ├── columns: th_t_id:92!null + │ │ │ │ ├── columns: th_t_id:97!null │ │ │ │ ├── mapping: - │ │ │ │ │ └── column1:89 => th_t_id:92 + │ │ │ │ │ └── column1:93 => th_t_id:97 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(92) + │ │ │ │ └── fd: ()-->(97) │ │ │ └── filters (true) │ │ └── f-k-checks-item: trade_history(th_st_id) -> status_type(st_id) │ │ └── anti-join (lookup status_type) - │ │ ├── columns: th_st_id:110!null - │ │ ├── key columns: [110] = [111] + │ │ ├── columns: th_st_id:115 + │ │ ├── key columns: [115] = [116] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(110) + │ │ ├── fd: ()-->(115) │ │ ├── with-scan &3 - │ │ │ ├── columns: th_st_id:110!null + │ │ │ ├── columns: th_st_id:115 │ │ │ ├── mapping: - │ │ │ │ └── column3:91 => th_st_id:110 + │ │ │ │ └── column3:96 => th_st_id:115 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(110) + │ │ │ └── fd: ()-->(115) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":115] + │ └── 1 [as="?column?":120] └── values - ├── columns: "?column?":116!null + ├── columns: "?column?":121!null ├── cardinality: [1 - 1] ├── key: () - ├── fd: ()-->(116) + ├── fd: ()-->(121) └── (1,) # Q12 @@ -3202,284 +3218,309 @@ insert_trade_request AS ( SELECT 1; ---- with &2 (insert_trade) - ├── columns: "?column?":187!null + ├── columns: "?column?":195!null ├── cardinality: [1 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(187) + ├── fd: ()-->(195) ├── project - │ ├── columns: "?column?":83!null + │ ├── columns: "?column?":87!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(83) + │ ├── fd: ()-->(87) │ ├── insert trade │ │ ├── columns: t_id:1!null │ │ ├── insert-mapping: │ │ │ ├── column1:18 => t_id:1 │ │ │ ├── column2:19 => t_dts:2 - │ │ │ ├── column3:20 => trade.t_st_id:3 - │ │ │ ├── column4:21 => trade.t_tt_id:4 + │ │ │ ├── column3:33 => trade.t_st_id:3 + │ │ │ ├── column4:34 => trade.t_tt_id:4 │ │ │ ├── column5:22 => t_is_cash:5 - │ │ │ ├── column6:23 => trade.t_s_symb:6 - │ │ │ ├── column7:24 => t_qty:7 - │ │ │ ├── t_bid_price:33 => trade.t_bid_price:8 + │ │ │ ├── column6:35 => trade.t_s_symb:6 + │ │ │ ├── column7:36 => t_qty:7 + │ │ │ ├── column8:37 => t_bid_price:8 │ │ │ ├── column9:26 => trade.t_ca_id:9 - │ │ │ ├── column10:27 => t_exec_name:10 - │ │ │ ├── t_trade_price:34 => trade.t_trade_price:11 - │ │ │ ├── t_chrg:35 => trade.t_chrg:12 - │ │ │ ├── t_comm:36 => trade.t_comm:13 - │ │ │ ├── t_tax:37 => trade.t_tax:14 + │ │ │ ├── column10:38 => t_exec_name:10 + │ │ │ ├── column11:28 => t_trade_price:11 + │ │ │ ├── column12:39 => t_chrg:12 + │ │ │ ├── column13:40 => t_comm:13 + │ │ │ ├── column14:41 => t_tax:14 │ │ │ └── column15:32 => t_lifo:15 - │ │ ├── check columns: check1:38 check2:39 check3:40 check4:41 check5:42 + │ │ ├── check columns: check1:42 check2:43 check3:44 check4:45 check5:46 │ │ ├── input binding: &1 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () │ │ ├── fd: ()-->(1) - │ │ ├── values - │ │ │ ├── columns: column1:18!null column2:19!null column3:20!null column4:21!null column5:22!null column6:23!null column7:24!null column9:26!null column10:27!null column15:32!null t_bid_price:33!null t_trade_price:34 t_chrg:35!null t_comm:36!null t_tax:37!null check1:38!null check2:39!null check3:40!null check4:41!null check5:42!null + │ │ ├── project + │ │ │ ├── columns: check1:42 check2:43 check3:44 check4:45 check5:46 column1:18!null column2:19!null column5:22!null column9:26!null column11:28 column15:32!null column3:33 column4:34 column6:35 column7:36 column8:37 column10:38 column12:39 column13:40 column14:41 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(18-24,26,27,32-42) - │ │ │ └── (0, '2020-06-17 22:27:42.148484', 'SBMT', 'TMB', true, 'SYMB', 10, 0, 'Name', true, 1E+2, NULL, 1, 0, 0, true, true, true, true, true) + │ │ │ ├── fd: ()-->(18,19,22,26,28,32-46) + │ │ │ ├── values + │ │ │ │ ├── columns: column1:18!null column2:19!null column5:22!null column9:26!null column11:28 column15:32!null column3:33 column4:34 column6:35 column7:36 column8:37 column10:38 column12:39 column13:40 column14:41 + │ │ │ │ ├── cardinality: [1 - 1] + │ │ │ │ ├── immutable + │ │ │ │ ├── key: () + │ │ │ │ ├── fd: ()-->(18,19,22,26,28,32-41) + │ │ │ │ └── (0, '2020-06-17 22:27:42.148484', true, 0, CAST(NULL AS DECIMAL(8,2)), true, crdb_internal.assignment_cast('SBMT', NULL::VARCHAR(4)), crdb_internal.assignment_cast('TMB', NULL::VARCHAR(3)), crdb_internal.assignment_cast('SYMB', NULL::VARCHAR(15)), crdb_internal.assignment_cast(10, NULL::INT4), crdb_internal.assignment_cast(1E+2, NULL::DECIMAL(8,2)), crdb_internal.assignment_cast('Name', NULL::VARCHAR(49)), crdb_internal.assignment_cast(1, NULL::DECIMAL(10,2)), crdb_internal.assignment_cast(0, NULL::DECIMAL(10,2)), crdb_internal.assignment_cast(0, NULL::DECIMAL(10,2))) + │ │ │ └── projections + │ │ │ ├── column7:36 > 0 [as=check1:42, outer=(36)] + │ │ │ ├── column8:37 > 0 [as=check2:43, outer=(37), immutable] + │ │ │ ├── column12:39 >= 0 [as=check3:44, outer=(39), immutable] + │ │ │ ├── column13:40 >= 0 [as=check4:45, outer=(40), immutable] + │ │ │ └── column14:41 >= 0 [as=check5:46, outer=(41), immutable] │ │ └── f-k-checks │ │ ├── f-k-checks-item: trade(t_st_id) -> status_type(st_id) │ │ │ └── anti-join (lookup status_type) - │ │ │ ├── columns: t_st_id:43!null - │ │ │ ├── key columns: [43] = [44] + │ │ │ ├── columns: t_st_id:47 + │ │ │ ├── key columns: [47] = [48] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(43) + │ │ │ ├── fd: ()-->(47) │ │ │ ├── with-scan &1 - │ │ │ │ ├── columns: t_st_id:43!null + │ │ │ │ ├── columns: t_st_id:47 │ │ │ │ ├── mapping: - │ │ │ │ │ └── column3:20 => t_st_id:43 + │ │ │ │ │ └── column3:33 => t_st_id:47 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(43) + │ │ │ │ └── fd: ()-->(47) │ │ │ └── filters (true) │ │ ├── f-k-checks-item: trade(t_tt_id) -> trade_type(tt_id) │ │ │ └── anti-join (lookup trade_type) - │ │ │ ├── columns: t_tt_id:48!null - │ │ │ ├── key columns: [48] = [49] + │ │ │ ├── columns: t_tt_id:52 + │ │ │ ├── key columns: [52] = [53] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(48) + │ │ │ ├── fd: ()-->(52) │ │ │ ├── with-scan &1 - │ │ │ │ ├── columns: t_tt_id:48!null + │ │ │ │ ├── columns: t_tt_id:52 │ │ │ │ ├── mapping: - │ │ │ │ │ └── column4:21 => t_tt_id:48 + │ │ │ │ │ └── column4:34 => t_tt_id:52 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(48) + │ │ │ │ └── fd: ()-->(52) │ │ │ └── filters (true) │ │ ├── f-k-checks-item: trade(t_s_symb) -> security(s_symb) │ │ │ └── anti-join (lookup security) - │ │ │ ├── columns: t_s_symb:55!null - │ │ │ ├── key columns: [55] = [56] + │ │ │ ├── columns: t_s_symb:59 + │ │ │ ├── key columns: [59] = [60] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(55) + │ │ │ ├── fd: ()-->(59) │ │ │ ├── with-scan &1 - │ │ │ │ ├── columns: t_s_symb:55!null + │ │ │ │ ├── columns: t_s_symb:59 │ │ │ │ ├── mapping: - │ │ │ │ │ └── column6:23 => t_s_symb:55 + │ │ │ │ │ └── column6:35 => t_s_symb:59 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(55) + │ │ │ │ └── fd: ()-->(59) │ │ │ └── filters (true) │ │ └── f-k-checks-item: trade(t_ca_id) -> customer_account(ca_id) │ │ └── anti-join (lookup customer_account) - │ │ ├── columns: t_ca_id:74!null - │ │ ├── key columns: [74] = [75] + │ │ ├── columns: t_ca_id:78!null + │ │ ├── key columns: [78] = [79] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(74) + │ │ ├── fd: ()-->(78) │ │ ├── with-scan &1 - │ │ │ ├── columns: t_ca_id:74!null + │ │ │ ├── columns: t_ca_id:78!null │ │ │ ├── mapping: - │ │ │ │ └── column9:26 => t_ca_id:74 + │ │ │ │ └── column9:26 => t_ca_id:78 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(74) + │ │ │ └── fd: ()-->(78) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":83] + │ └── 1 [as="?column?":87] └── with &4 (insert_trade_history) - ├── columns: "?column?":187!null + ├── columns: "?column?":195!null ├── cardinality: [1 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(187) + ├── fd: ()-->(195) ├── project - │ ├── columns: "?column?":115!null + │ ├── columns: "?column?":120!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(115) + │ ├── fd: ()-->(120) │ ├── insert trade_history - │ │ ├── columns: trade_history.th_t_id:84!null trade_history.th_st_id:86!null + │ │ ├── columns: trade_history.th_t_id:88!null trade_history.th_st_id:90!null │ │ ├── insert-mapping: - │ │ │ ├── column1:89 => trade_history.th_t_id:84 - │ │ │ ├── column2:90 => th_dts:85 - │ │ │ └── column3:91 => trade_history.th_st_id:86 + │ │ │ ├── column1:93 => trade_history.th_t_id:88 + │ │ │ ├── column2:94 => th_dts:89 + │ │ │ └── column3:96 => trade_history.th_st_id:90 │ │ ├── input binding: &3 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () - │ │ ├── fd: ()-->(84,86) + │ │ ├── fd: ()-->(88,90) │ │ ├── values - │ │ │ ├── columns: column1:89!null column2:90!null column3:91!null + │ │ │ ├── columns: column1:93!null column2:94!null column3:96 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(89-91) - │ │ │ └── (0, '2020-06-15 22:27:42.148484', 'SBMT') + │ │ │ ├── fd: ()-->(93,94,96) + │ │ │ └── (0, '2020-06-15 22:27:42.148484', crdb_internal.assignment_cast('SBMT', NULL::VARCHAR(4))) │ │ └── f-k-checks │ │ ├── f-k-checks-item: trade_history(th_t_id) -> trade(t_id) │ │ │ └── anti-join (lookup trade) - │ │ │ ├── columns: th_t_id:92!null - │ │ │ ├── key columns: [92] = [93] + │ │ │ ├── columns: th_t_id:97!null + │ │ │ ├── key columns: [97] = [98] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(92) + │ │ │ ├── fd: ()-->(97) │ │ │ ├── with-scan &3 - │ │ │ │ ├── columns: th_t_id:92!null + │ │ │ │ ├── columns: th_t_id:97!null │ │ │ │ ├── mapping: - │ │ │ │ │ └── column1:89 => th_t_id:92 + │ │ │ │ │ └── column1:93 => th_t_id:97 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(92) + │ │ │ │ └── fd: ()-->(97) │ │ │ └── filters (true) │ │ └── f-k-checks-item: trade_history(th_st_id) -> status_type(st_id) │ │ └── anti-join (lookup status_type) - │ │ ├── columns: th_st_id:110!null - │ │ ├── key columns: [110] = [111] + │ │ ├── columns: th_st_id:115 + │ │ ├── key columns: [115] = [116] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(110) + │ │ ├── fd: ()-->(115) │ │ ├── with-scan &3 - │ │ │ ├── columns: th_st_id:110!null + │ │ │ ├── columns: th_st_id:115 │ │ │ ├── mapping: - │ │ │ │ └── column3:91 => th_st_id:110 + │ │ │ │ └── column3:96 => th_st_id:115 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(110) + │ │ │ └── fd: ()-->(115) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":115] + │ └── 1 [as="?column?":120] └── with &6 (insert_trade_request) - ├── columns: "?column?":187!null + ├── columns: "?column?":195!null ├── cardinality: [1 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(187) + ├── fd: ()-->(195) ├── project - │ ├── columns: "?column?":186!null + │ ├── columns: "?column?":194!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(186) + │ ├── fd: ()-->(194) │ ├── insert trade_request - │ │ ├── columns: trade_request.tr_t_id:116!null + │ │ ├── columns: trade_request.tr_t_id:121!null │ │ ├── insert-mapping: - │ │ │ ├── column1:124 => trade_request.tr_t_id:116 - │ │ │ ├── column2:125 => trade_request.tr_tt_id:117 - │ │ │ ├── column3:126 => trade_request.tr_s_symb:118 - │ │ │ ├── column4:127 => tr_qty:119 - │ │ │ ├── tr_bid_price:130 => trade_request.tr_bid_price:120 - │ │ │ └── column6:129 => trade_request.tr_b_id:121 - │ │ ├── check columns: check1:131 check2:132 - │ │ ├── partial index put columns: partial_index_put1:133 + │ │ │ ├── column1:129 => trade_request.tr_t_id:121 + │ │ │ ├── column2:135 => trade_request.tr_tt_id:122 + │ │ │ ├── column3:136 => trade_request.tr_s_symb:123 + │ │ │ ├── column4:137 => tr_qty:124 + │ │ │ ├── column5:138 => tr_bid_price:125 + │ │ │ └── column6:134 => trade_request.tr_b_id:126 + │ │ ├── check columns: check1:139 check2:140 + │ │ ├── partial index put columns: partial_index_put1:141 │ │ ├── input binding: &5 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () - │ │ ├── fd: ()-->(116) - │ │ ├── values - │ │ │ ├── columns: column1:124!null column2:125!null column3:126!null column4:127!null column6:129!null tr_bid_price:130!null check1:131!null check2:132!null partial_index_put1:133!null + │ │ ├── fd: ()-->(121) + │ │ ├── project + │ │ │ ├── columns: partial_index_put1:141 check1:139 check2:140 column1:129!null column6:134!null column2:135 column3:136 column4:137 column5:138 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(124-127,129-133) - │ │ │ └── (0, 'TMB', 'SYMB', 10, 0, 1E+2, true, true, false) + │ │ │ ├── fd: ()-->(129,134-141) + │ │ │ ├── values + │ │ │ │ ├── columns: column1:129!null column6:134!null column2:135 column3:136 column4:137 column5:138 + │ │ │ │ ├── cardinality: [1 - 1] + │ │ │ │ ├── immutable + │ │ │ │ ├── key: () + │ │ │ │ ├── fd: ()-->(129,134-138) + │ │ │ │ └── (0, 0, crdb_internal.assignment_cast('TMB', NULL::VARCHAR(3)), crdb_internal.assignment_cast('SYMB', NULL::VARCHAR(15)), crdb_internal.assignment_cast(10, NULL::INT4), crdb_internal.assignment_cast(1E+2, NULL::DECIMAL(8,2))) + │ │ │ └── projections + │ │ │ ├── column2:135 IN ('TLB', 'TLS', 'TSL') [as=partial_index_put1:141, outer=(135)] + │ │ │ ├── column4:137 > 0 [as=check1:139, outer=(137)] + │ │ │ └── column5:138 > 0 [as=check2:140, outer=(138), immutable] │ │ └── f-k-checks │ │ ├── f-k-checks-item: trade_request(tr_t_id) -> trade(t_id) │ │ │ └── anti-join (lookup trade) - │ │ │ ├── columns: tr_t_id:134!null - │ │ │ ├── key columns: [134] = [135] + │ │ │ ├── columns: tr_t_id:142!null + │ │ │ ├── key columns: [142] = [143] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(134) + │ │ │ ├── fd: ()-->(142) │ │ │ ├── with-scan &5 - │ │ │ │ ├── columns: tr_t_id:134!null + │ │ │ │ ├── columns: tr_t_id:142!null │ │ │ │ ├── mapping: - │ │ │ │ │ └── column1:124 => tr_t_id:134 + │ │ │ │ │ └── column1:129 => tr_t_id:142 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(134) + │ │ │ │ └── fd: ()-->(142) │ │ │ └── filters (true) │ │ ├── f-k-checks-item: trade_request(tr_tt_id) -> trade_type(tt_id) │ │ │ └── anti-join (lookup trade_type) - │ │ │ ├── columns: tr_tt_id:152!null - │ │ │ ├── key columns: [152] = [153] + │ │ │ ├── columns: tr_tt_id:160 + │ │ │ ├── key columns: [160] = [161] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(152) + │ │ │ ├── fd: ()-->(160) │ │ │ ├── with-scan &5 - │ │ │ │ ├── columns: tr_tt_id:152!null + │ │ │ │ ├── columns: tr_tt_id:160 │ │ │ │ ├── mapping: - │ │ │ │ │ └── column2:125 => tr_tt_id:152 + │ │ │ │ │ └── column2:135 => tr_tt_id:160 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(152) + │ │ │ │ └── fd: ()-->(160) │ │ │ └── filters (true) │ │ ├── f-k-checks-item: trade_request(tr_s_symb) -> security(s_symb) │ │ │ └── anti-join (lookup security) - │ │ │ ├── columns: tr_s_symb:159!null - │ │ │ ├── key columns: [159] = [160] + │ │ │ ├── columns: tr_s_symb:167 + │ │ │ ├── key columns: [167] = [168] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(159) + │ │ │ ├── fd: ()-->(167) │ │ │ ├── with-scan &5 - │ │ │ │ ├── columns: tr_s_symb:159!null + │ │ │ │ ├── columns: tr_s_symb:167 │ │ │ │ ├── mapping: - │ │ │ │ │ └── column3:126 => tr_s_symb:159 + │ │ │ │ │ └── column3:136 => tr_s_symb:167 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(159) + │ │ │ │ └── fd: ()-->(167) │ │ │ └── filters (true) │ │ └── f-k-checks-item: trade_request(tr_b_id) -> broker(b_id) │ │ └── anti-join (lookup broker) - │ │ ├── columns: tr_b_id:178!null - │ │ ├── key columns: [178] = [179] + │ │ ├── columns: tr_b_id:186!null + │ │ ├── key columns: [186] = [187] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(178) + │ │ ├── fd: ()-->(186) │ │ ├── with-scan &5 - │ │ │ ├── columns: tr_b_id:178!null + │ │ │ ├── columns: tr_b_id:186!null │ │ │ ├── mapping: - │ │ │ │ └── column6:129 => tr_b_id:178 + │ │ │ │ └── column6:134 => tr_b_id:186 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(178) + │ │ │ └── fd: ()-->(186) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":186] + │ └── 1 [as="?column?":194] └── values - ├── columns: "?column?":187!null + ├── columns: "?column?":195!null ├── cardinality: [1 - 1] ├── key: () - ├── fd: ()-->(187) + ├── fd: ()-->(195) └── (1,) # -------------------------------------------------- @@ -3630,49 +3671,50 @@ insert holding_summary ├── columns: ├── insert-mapping: │ ├── column1:6 => holding_summary.hs_ca_id:1 - │ ├── column2:7 => holding_summary.hs_s_symb:2 - │ └── column3:8 => hs_qty:3 + │ ├── column2:9 => holding_summary.hs_s_symb:2 + │ └── column3:10 => hs_qty:3 ├── input binding: &1 ├── cardinality: [0 - 0] ├── volatile, mutations ├── values - │ ├── columns: column1:6!null column2:7!null column3:8!null + │ ├── columns: column1:6!null column2:9 column3:10 │ ├── cardinality: [1 - 1] + │ ├── immutable │ ├── key: () - │ ├── fd: ()-->(6-8) - │ └── (0, 'ROACH', 100) + │ ├── fd: ()-->(6,9,10) + │ └── (0, crdb_internal.assignment_cast('ROACH', NULL::VARCHAR(15)), crdb_internal.assignment_cast(100, NULL::INT4)) └── f-k-checks ├── f-k-checks-item: holding_summary(hs_ca_id) -> customer_account(ca_id) │ └── anti-join (lookup customer_account) - │ ├── columns: hs_ca_id:9!null - │ ├── key columns: [9] = [10] + │ ├── columns: hs_ca_id:11!null + │ ├── key columns: [11] = [12] │ ├── lookup columns are key │ ├── cardinality: [0 - 1] │ ├── key: () - │ ├── fd: ()-->(9) + │ ├── fd: ()-->(11) │ ├── with-scan &1 - │ │ ├── columns: hs_ca_id:9!null + │ │ ├── columns: hs_ca_id:11!null │ │ ├── mapping: - │ │ │ └── column1:6 => hs_ca_id:9 + │ │ │ └── column1:6 => hs_ca_id:11 │ │ ├── cardinality: [1 - 1] │ │ ├── key: () - │ │ └── fd: ()-->(9) + │ │ └── fd: ()-->(11) │ └── filters (true) └── f-k-checks-item: holding_summary(hs_s_symb) -> security(s_symb) └── anti-join (lookup security) - ├── columns: hs_s_symb:18!null - ├── key columns: [18] = [19] + ├── columns: hs_s_symb:20 + ├── key columns: [20] = [21] ├── lookup columns are key ├── cardinality: [0 - 1] ├── key: () - ├── fd: ()-->(18) + ├── fd: ()-->(20) ├── with-scan &1 - │ ├── columns: hs_s_symb:18!null + │ ├── columns: hs_s_symb:20 │ ├── mapping: - │ │ └── column2:7 => hs_s_symb:18 + │ │ └── column2:9 => hs_s_symb:20 │ ├── cardinality: [1 - 1] │ ├── key: () - │ └── fd: ()-->(18) + │ └── fd: ()-->(20) └── filters (true) # Q4 @@ -3868,53 +3910,62 @@ insert holding ├── insert-mapping: │ ├── column1:9 => holding.h_t_id:1 │ ├── column2:10 => holding.h_ca_id:2 - │ ├── column3:11 => holding.h_s_symb:3 + │ ├── column3:15 => holding.h_s_symb:3 │ ├── column4:12 => h_dts:4 - │ ├── h_price:15 => holding.h_price:5 - │ └── column6:14 => h_qty:6 - ├── check columns: check1:16 + │ ├── column5:16 => h_price:5 + │ └── column6:17 => h_qty:6 + ├── check columns: check1:18 ├── input binding: &1 ├── cardinality: [0 - 0] ├── volatile, mutations - ├── values - │ ├── columns: column1:9!null column2:10!null column3:11!null column4:12!null column6:14!null h_price:15!null check1:16!null + ├── project + │ ├── columns: check1:18 column1:9!null column2:10!null column4:12!null column3:15 column5:16 column6:17 │ ├── cardinality: [1 - 1] + │ ├── immutable │ ├── key: () - │ ├── fd: ()-->(9-12,14-16) - │ └── (0, 0, 'ROACH', '2020-06-15 22:27:42.148484', 10, 1E+2, true) + │ ├── fd: ()-->(9,10,12,15-18) + │ ├── values + │ │ ├── columns: column1:9!null column2:10!null column4:12!null column3:15 column5:16 column6:17 + │ │ ├── cardinality: [1 - 1] + │ │ ├── immutable + │ │ ├── key: () + │ │ ├── fd: ()-->(9,10,12,15-17) + │ │ └── (0, 0, '2020-06-15 22:27:42.148484', crdb_internal.assignment_cast('ROACH', NULL::VARCHAR(15)), crdb_internal.assignment_cast(1E+2, NULL::DECIMAL(8,2)), crdb_internal.assignment_cast(10, NULL::INT4)) + │ └── projections + │ └── column5:16 > 0 [as=check1:18, outer=(16), immutable] └── f-k-checks ├── f-k-checks-item: holding(h_t_id) -> trade(t_id) │ └── anti-join (lookup trade) - │ ├── columns: h_t_id:17!null - │ ├── key columns: [17] = [18] + │ ├── columns: h_t_id:19!null + │ ├── key columns: [19] = [20] │ ├── lookup columns are key │ ├── cardinality: [0 - 1] │ ├── key: () - │ ├── fd: ()-->(17) + │ ├── fd: ()-->(19) │ ├── with-scan &1 - │ │ ├── columns: h_t_id:17!null + │ │ ├── columns: h_t_id:19!null │ │ ├── mapping: - │ │ │ └── column1:9 => h_t_id:17 + │ │ │ └── column1:9 => h_t_id:19 │ │ ├── cardinality: [1 - 1] │ │ ├── key: () - │ │ └── fd: ()-->(17) + │ │ └── fd: ()-->(19) │ └── filters (true) └── f-k-checks-item: holding(h_ca_id,h_s_symb) -> holding_summary(hs_ca_id,hs_s_symb) └── anti-join (lookup holding_summary) - ├── columns: h_ca_id:35!null h_s_symb:36!null - ├── key columns: [35 36] = [37 38] + ├── columns: h_ca_id:37!null h_s_symb:38 + ├── key columns: [37 38] = [39 40] ├── lookup columns are key ├── cardinality: [0 - 1] ├── key: () - ├── fd: ()-->(35,36) + ├── fd: ()-->(37,38) ├── with-scan &1 - │ ├── columns: h_ca_id:35!null h_s_symb:36!null + │ ├── columns: h_ca_id:37!null h_s_symb:38 │ ├── mapping: - │ │ ├── column2:10 => h_ca_id:35 - │ │ └── column3:11 => h_s_symb:36 + │ │ ├── column2:10 => h_ca_id:37 + │ │ └── column3:15 => h_s_symb:38 │ ├── cardinality: [1 - 1] │ ├── key: () - │ └── fd: ()-->(35,36) + │ └── fd: ()-->(37,38) └── filters (true) # Q11 @@ -4186,11 +4237,11 @@ insert_trade_history AS ( SELECT 1 ---- with &2 (update_trade_commission) - ├── columns: "?column?":102!null + ├── columns: "?column?":103!null ├── cardinality: [1 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(102) + ├── fd: ()-->(103) ├── project │ ├── columns: "?column?":51!null │ ├── cardinality: [0 - 1] @@ -4248,11 +4299,11 @@ with &2 (update_trade_commission) │ └── projections │ └── 1 [as="?column?":51] └── with &4 (update_broker_commission) - ├── columns: "?column?":102!null + ├── columns: "?column?":103!null ├── cardinality: [1 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(102) + ├── fd: ()-->(103) ├── project │ ├── columns: "?column?":69!null │ ├── cardinality: [0 - 1] @@ -4287,74 +4338,75 @@ with &2 (update_trade_commission) │ └── projections │ └── 1 [as="?column?":69] └── with &6 (insert_trade_history) - ├── columns: "?column?":102!null + ├── columns: "?column?":103!null ├── cardinality: [1 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(102) + ├── fd: ()-->(103) ├── project - │ ├── columns: "?column?":101!null + │ ├── columns: "?column?":102!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(101) + │ ├── fd: ()-->(102) │ ├── insert trade_history │ │ ├── columns: trade_history.th_t_id:70!null trade_history.th_st_id:72!null │ │ ├── insert-mapping: │ │ │ ├── column1:75 => trade_history.th_t_id:70 │ │ │ ├── column2:76 => th_dts:71 - │ │ │ └── column3:77 => trade_history.th_st_id:72 + │ │ │ └── column3:78 => trade_history.th_st_id:72 │ │ ├── input binding: &5 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () │ │ ├── fd: ()-->(70,72) │ │ ├── values - │ │ │ ├── columns: column1:75!null column2:76!null column3:77!null + │ │ │ ├── columns: column1:75!null column2:76!null column3:78 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(75-77) - │ │ │ └── (0, '2020-06-15 22:27:42.148484', 'ACTV') + │ │ │ ├── fd: ()-->(75,76,78) + │ │ │ └── (0, '2020-06-15 22:27:42.148484', crdb_internal.assignment_cast('ACTV', NULL::VARCHAR(4))) │ │ └── f-k-checks │ │ ├── f-k-checks-item: trade_history(th_t_id) -> trade(t_id) │ │ │ └── anti-join (lookup trade) - │ │ │ ├── columns: th_t_id:78!null - │ │ │ ├── key columns: [78] = [79] + │ │ │ ├── columns: th_t_id:79!null + │ │ │ ├── key columns: [79] = [80] │ │ │ ├── lookup columns are key │ │ │ ├── cardinality: [0 - 1] │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(78) + │ │ │ ├── fd: ()-->(79) │ │ │ ├── with-scan &5 - │ │ │ │ ├── columns: th_t_id:78!null + │ │ │ │ ├── columns: th_t_id:79!null │ │ │ │ ├── mapping: - │ │ │ │ │ └── column1:75 => th_t_id:78 + │ │ │ │ │ └── column1:75 => th_t_id:79 │ │ │ │ ├── cardinality: [1 - 1] │ │ │ │ ├── key: () - │ │ │ │ └── fd: ()-->(78) + │ │ │ │ └── fd: ()-->(79) │ │ │ └── filters (true) │ │ └── f-k-checks-item: trade_history(th_st_id) -> status_type(st_id) │ │ └── anti-join (lookup status_type) - │ │ ├── columns: th_st_id:96!null - │ │ ├── key columns: [96] = [97] + │ │ ├── columns: th_st_id:97 + │ │ ├── key columns: [97] = [98] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(96) + │ │ ├── fd: ()-->(97) │ │ ├── with-scan &5 - │ │ │ ├── columns: th_st_id:96!null + │ │ │ ├── columns: th_st_id:97 │ │ │ ├── mapping: - │ │ │ │ └── column3:77 => th_st_id:96 + │ │ │ │ └── column3:78 => th_st_id:97 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(96) + │ │ │ └── fd: ()-->(97) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":101] + │ └── 1 [as="?column?":102] └── values - ├── columns: "?column?":102!null + ├── columns: "?column?":103!null ├── cardinality: [1 - 1] ├── key: () - ├── fd: ()-->(102) + ├── fd: ()-->(103) └── (1,) @@ -4384,134 +4436,136 @@ WHERE ca_id = 0 RETURNING ca_bal::FLOAT8; ---- with &2 (insert_settlement) - ├── columns: ca_bal:80!null + ├── columns: ca_bal:82!null ├── cardinality: [0 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(80) + ├── fd: ()-->(82) ├── project - │ ├── columns: "?column?":30!null + │ ├── columns: "?column?":31!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(30) + │ ├── fd: ()-->(31) │ ├── insert settlement │ │ ├── columns: settlement.se_t_id:1!null │ │ ├── insert-mapping: │ │ │ ├── column1:7 => settlement.se_t_id:1 - │ │ │ ├── column2:8 => se_cash_type:2 + │ │ │ ├── column2:11 => se_cash_type:2 │ │ │ ├── column3:9 => se_cash_due_date:3 - │ │ │ └── se_amt:11 => settlement.se_amt:4 + │ │ │ └── column4:12 => se_amt:4 │ │ ├── input binding: &1 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () │ │ ├── fd: ()-->(1) │ │ ├── values - │ │ │ ├── columns: column1:7!null column2:8!null column3:9!null se_amt:11!null + │ │ │ ├── columns: column1:7!null column3:9!null column2:11 column4:12 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(7-9,11) - │ │ │ └── (0, 'Margin', '2020-06-15', 1E+2) + │ │ │ ├── fd: ()-->(7,9,11,12) + │ │ │ └── (0, '2020-06-15', crdb_internal.assignment_cast('Margin', NULL::VARCHAR(40)), crdb_internal.assignment_cast(1E+2, NULL::DECIMAL(10,2))) │ │ └── f-k-checks │ │ └── f-k-checks-item: settlement(se_t_id) -> trade(t_id) │ │ └── anti-join (lookup trade) - │ │ ├── columns: se_t_id:12!null - │ │ ├── key columns: [12] = [13] + │ │ ├── columns: se_t_id:13!null + │ │ ├── key columns: [13] = [14] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(12) + │ │ ├── fd: ()-->(13) │ │ ├── with-scan &1 - │ │ │ ├── columns: se_t_id:12!null + │ │ │ ├── columns: se_t_id:13!null │ │ │ ├── mapping: - │ │ │ │ └── column1:7 => se_t_id:12 + │ │ │ │ └── column1:7 => se_t_id:13 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(12) + │ │ │ └── fd: ()-->(13) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":30] + │ └── 1 [as="?column?":31] └── with &4 (insert_cash_transaction) - ├── columns: ca_bal:80!null + ├── columns: ca_bal:82!null ├── cardinality: [0 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(80) + ├── fd: ()-->(82) ├── project - │ ├── columns: "?column?":60!null + │ ├── columns: "?column?":62!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(60) + │ ├── fd: ()-->(62) │ ├── insert cash_transaction - │ │ ├── columns: cash_transaction.ct_t_id:31!null + │ │ ├── columns: cash_transaction.ct_t_id:32!null │ │ ├── insert-mapping: - │ │ │ ├── column1:37 => cash_transaction.ct_t_id:31 - │ │ │ ├── column2:38 => ct_dts:32 - │ │ │ ├── ct_amt:41 => cash_transaction.ct_amt:33 - │ │ │ └── column4:40 => ct_name:34 + │ │ │ ├── column1:38 => cash_transaction.ct_t_id:32 + │ │ │ ├── column2:39 => ct_dts:33 + │ │ │ ├── column3:42 => ct_amt:34 + │ │ │ └── column4:43 => ct_name:35 │ │ ├── input binding: &3 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () - │ │ ├── fd: ()-->(31) + │ │ ├── fd: ()-->(32) │ │ ├── values - │ │ │ ├── columns: column1:37!null column2:38!null column4:40!null ct_amt:41!null + │ │ │ ├── columns: column1:38!null column2:39!null column3:42 column4:43 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(37,38,40,41) - │ │ │ └── (0, '2020-06-10 22:27:42.148484', 'Buy 2 shares of ROACH', 1E+2) + │ │ │ ├── fd: ()-->(38,39,42,43) + │ │ │ └── (0, '2020-06-10 22:27:42.148484', crdb_internal.assignment_cast(1E+2, NULL::DECIMAL(10,2)), crdb_internal.assignment_cast('Buy 2 shares of ROACH', NULL::VARCHAR(100))) │ │ └── f-k-checks │ │ └── f-k-checks-item: cash_transaction(ct_t_id) -> trade(t_id) │ │ └── anti-join (lookup trade) - │ │ ├── columns: ct_t_id:42!null - │ │ ├── key columns: [42] = [43] + │ │ ├── columns: ct_t_id:44!null + │ │ ├── key columns: [44] = [45] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(42) + │ │ ├── fd: ()-->(44) │ │ ├── with-scan &3 - │ │ │ ├── columns: ct_t_id:42!null + │ │ │ ├── columns: ct_t_id:44!null │ │ │ ├── mapping: - │ │ │ │ └── column1:37 => ct_t_id:42 + │ │ │ │ └── column1:38 => ct_t_id:44 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(42) + │ │ │ └── fd: ()-->(44) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":60] + │ └── 1 [as="?column?":62] └── project - ├── columns: ca_bal:80!null + ├── columns: ca_bal:82!null ├── cardinality: [0 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(80) + ├── fd: ()-->(82) ├── update customer_account - │ ├── columns: ca_id:61!null customer_account.ca_bal:66!null - │ ├── fetch columns: ca_id:69 ca_b_id:70 ca_c_id:71 ca_name:72 ca_tax_st:73 customer_account.ca_bal:74 + │ ├── columns: ca_id:63!null customer_account.ca_bal:68!null + │ ├── fetch columns: ca_id:71 ca_b_id:72 ca_c_id:73 ca_name:74 ca_tax_st:75 customer_account.ca_bal:76 │ ├── update-mapping: - │ │ └── ca_bal_new:78 => customer_account.ca_bal:66 + │ │ └── ca_bal_new:80 => customer_account.ca_bal:68 │ ├── cardinality: [0 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(61,66) + │ ├── fd: ()-->(63,68) │ └── project - │ ├── columns: ca_bal_new:78 ca_id:69!null ca_b_id:70!null ca_c_id:71!null ca_name:72 ca_tax_st:73!null customer_account.ca_bal:74!null + │ ├── columns: ca_bal_new:80 ca_id:71!null ca_b_id:72!null ca_c_id:73!null ca_name:74 ca_tax_st:75!null customer_account.ca_bal:76!null │ ├── cardinality: [0 - 1] │ ├── immutable │ ├── key: () - │ ├── fd: ()-->(69-74,78) + │ ├── fd: ()-->(71-76,80) │ ├── scan customer_account - │ │ ├── columns: ca_id:69!null ca_b_id:70!null ca_c_id:71!null ca_name:72 ca_tax_st:73!null customer_account.ca_bal:74!null - │ │ ├── constraint: /69: [/0 - /0] + │ │ ├── columns: ca_id:71!null ca_b_id:72!null ca_c_id:73!null ca_name:74 ca_tax_st:75!null customer_account.ca_bal:76!null + │ │ ├── constraint: /71: [/0 - /0] │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ └── fd: ()-->(69-74) + │ │ └── fd: ()-->(71-76) │ └── projections - │ └── crdb_internal.round_decimal_values(customer_account.ca_bal:74::DECIMAL + 1E+2, 2) [as=ca_bal_new:78, outer=(74), immutable] + │ └── crdb_internal.round_decimal_values(customer_account.ca_bal:76::DECIMAL + 1E+2, 2) [as=ca_bal_new:80, outer=(76), immutable] └── projections - └── customer_account.ca_bal:66::FLOAT8 [as=ca_bal:80, outer=(66), immutable] + └── customer_account.ca_bal:68::FLOAT8 [as=ca_bal:82, outer=(68), immutable] # Q16 opt @@ -4525,68 +4579,69 @@ insert_settlement AS ( SELECT ca_bal::FLOAT8 FROM customer_account WHERE ca_id = 0; ---- with &2 (insert_settlement) - ├── columns: ca_bal:39!null + ├── columns: ca_bal:40!null ├── cardinality: [0 - 1] ├── volatile, mutations ├── key: () - ├── fd: ()-->(39) + ├── fd: ()-->(40) ├── project - │ ├── columns: "?column?":30!null + │ ├── columns: "?column?":31!null │ ├── cardinality: [1 - 1] │ ├── volatile, mutations │ ├── key: () - │ ├── fd: ()-->(30) + │ ├── fd: ()-->(31) │ ├── insert settlement │ │ ├── columns: settlement.se_t_id:1!null │ │ ├── insert-mapping: │ │ │ ├── column1:7 => settlement.se_t_id:1 - │ │ │ ├── column2:8 => se_cash_type:2 + │ │ │ ├── column2:11 => se_cash_type:2 │ │ │ ├── column3:9 => se_cash_due_date:3 - │ │ │ └── se_amt:11 => settlement.se_amt:4 + │ │ │ └── column4:12 => se_amt:4 │ │ ├── input binding: &1 │ │ ├── cardinality: [1 - 1] │ │ ├── volatile, mutations │ │ ├── key: () │ │ ├── fd: ()-->(1) │ │ ├── values - │ │ │ ├── columns: column1:7!null column2:8!null column3:9!null se_amt:11!null + │ │ │ ├── columns: column1:7!null column3:9!null column2:11 column4:12 │ │ │ ├── cardinality: [1 - 1] + │ │ │ ├── immutable │ │ │ ├── key: () - │ │ │ ├── fd: ()-->(7-9,11) - │ │ │ └── (0, 'Margin', '2020-06-15', 1E+2) + │ │ │ ├── fd: ()-->(7,9,11,12) + │ │ │ └── (0, '2020-06-15', crdb_internal.assignment_cast('Margin', NULL::VARCHAR(40)), crdb_internal.assignment_cast(1E+2, NULL::DECIMAL(10,2))) │ │ └── f-k-checks │ │ └── f-k-checks-item: settlement(se_t_id) -> trade(t_id) │ │ └── anti-join (lookup trade) - │ │ ├── columns: se_t_id:12!null - │ │ ├── key columns: [12] = [13] + │ │ ├── columns: se_t_id:13!null + │ │ ├── key columns: [13] = [14] │ │ ├── lookup columns are key │ │ ├── cardinality: [0 - 1] │ │ ├── key: () - │ │ ├── fd: ()-->(12) + │ │ ├── fd: ()-->(13) │ │ ├── with-scan &1 - │ │ │ ├── columns: se_t_id:12!null + │ │ │ ├── columns: se_t_id:13!null │ │ │ ├── mapping: - │ │ │ │ └── column1:7 => se_t_id:12 + │ │ │ │ └── column1:7 => se_t_id:13 │ │ │ ├── cardinality: [1 - 1] │ │ │ ├── key: () - │ │ │ └── fd: ()-->(12) + │ │ │ └── fd: ()-->(13) │ │ └── filters (true) │ └── projections - │ └── 1 [as="?column?":30] + │ └── 1 [as="?column?":31] └── project - ├── columns: ca_bal:39!null + ├── columns: ca_bal:40!null ├── cardinality: [0 - 1] ├── immutable ├── key: () - ├── fd: ()-->(39) + ├── fd: ()-->(40) ├── scan customer_account - │ ├── columns: ca_id:31!null customer_account.ca_bal:36!null - │ ├── constraint: /31: [/0 - /0] + │ ├── columns: ca_id:32!null customer_account.ca_bal:37!null + │ ├── constraint: /32: [/0 - /0] │ ├── cardinality: [0 - 1] │ ├── key: () - │ └── fd: ()-->(31,36) + │ └── fd: ()-->(32,37) └── projections - └── customer_account.ca_bal:36::FLOAT8 [as=ca_bal:39, outer=(36), immutable] + └── customer_account.ca_bal:37::FLOAT8 [as=ca_bal:40, outer=(37), immutable] # -------------------------------------------------- # T9 diff --git a/pkg/sql/opt/xform/testdata/external/trading b/pkg/sql/opt/xform/testdata/external/trading index 311e5e4b8d4c..5a5971ae27c0 100644 --- a/pkg/sql/opt/xform/testdata/external/trading +++ b/pkg/sql/opt/xform/testdata/external/trading @@ -1245,19 +1245,19 @@ insert transactions │ ├── column1:10 => dealerid:1 │ ├── column2:11 => isbuy:2 │ ├── column3:12 => date:3 - │ ├── column4:13 => accountname:4 - │ ├── column5:14 => customername:5 + │ ├── column4:16 => accountname:4 + │ ├── column5:17 => customername:5 │ ├── column6:15 => operationid:6 - │ └── version_default:16 => version:7 + │ └── version_default:18 => version:7 ├── cardinality: [0 - 0] ├── volatile, mutations └── values - ├── columns: column1:10!null column2:11!null column3:12!null column4:13!null column5:14!null column6:15!null version_default:16 + ├── columns: column1:10!null column2:11!null column3:12!null column6:15!null column4:16 column5:17 version_default:18 ├── cardinality: [1 - 1] ├── volatile ├── key: () - ├── fd: ()-->(10-16) - └── (1, false, '2020-03-01 00:00:00+00:00', 'the-account', 'the-customer', '70f03eb1-4f58-4c26-b72d-c524a9d537dd', cluster_logical_timestamp()) + ├── fd: ()-->(10-12,15-18) + └── (1, false, '2020-03-01 00:00:00+00:00', '70f03eb1-4f58-4c26-b72d-c524a9d537dd', crdb_internal.assignment_cast('the-account', NULL::VARCHAR(128)), crdb_internal.assignment_cast('the-customer', NULL::VARCHAR(128)), cluster_logical_timestamp()) # Upsert buy or sell transaction. opt diff --git a/pkg/sql/opt/xform/testdata/external/trading-mutation b/pkg/sql/opt/xform/testdata/external/trading-mutation index 29acf18214e5..566a1940bfce 100644 --- a/pkg/sql/opt/xform/testdata/external/trading-mutation +++ b/pkg/sql/opt/xform/testdata/external/trading-mutation @@ -1249,20 +1249,20 @@ insert transactions │ ├── column1:12 => dealerid:1 │ ├── column2:13 => isbuy:2 │ ├── column3:14 => date:3 - │ ├── column4:15 => accountname:4 - │ ├── column5:16 => customername:5 + │ ├── column4:18 => accountname:4 + │ ├── column5:19 => customername:5 │ ├── column6:17 => operationid:6 - │ ├── version_default:18 => version:7 - │ └── olddate_default:19 => olddate:8 + │ ├── version_default:20 => version:7 + │ └── olddate_default:21 => olddate:8 ├── cardinality: [0 - 0] ├── volatile, mutations └── values - ├── columns: column1:12!null column2:13!null column3:14!null column4:15!null column5:16!null column6:17!null version_default:18 olddate_default:19!null + ├── columns: column1:12!null column2:13!null column3:14!null column6:17!null column4:18 column5:19 version_default:20 olddate_default:21!null ├── cardinality: [1 - 1] ├── volatile ├── key: () - ├── fd: ()-->(12-19) - └── (1, false, '2020-03-01 00:00:00+00:00', 'the-account', 'the-customer', '70f03eb1-4f58-4c26-b72d-c524a9d537dd', cluster_logical_timestamp(), '0001-01-01 00:00:00') + ├── fd: ()-->(12-14,17-21) + └── (1, false, '2020-03-01 00:00:00+00:00', '70f03eb1-4f58-4c26-b72d-c524a9d537dd', crdb_internal.assignment_cast('the-account', NULL::VARCHAR(128)), crdb_internal.assignment_cast('the-customer', NULL::VARCHAR(128)), cluster_logical_timestamp(), '0001-01-01 00:00:00') # Upsert buy or sell transaction. opt diff --git a/pkg/sql/opt/xform/testdata/external/ycsb b/pkg/sql/opt/xform/testdata/external/ycsb index 8d458fbbb53e..12751fe261ad 100644 --- a/pkg/sql/opt/xform/testdata/external/ycsb +++ b/pkg/sql/opt/xform/testdata/external/ycsb @@ -93,7 +93,7 @@ INSERT INTO usertable VALUES ( insert usertable ├── columns: ├── insert-mapping: - │ ├── column1:14 => ycsb_key:1 + │ ├── column1:25 => ycsb_key:1 │ ├── column2:15 => field0:2 │ ├── column3:16 => field1:3 │ ├── column4:17 => field2:4 @@ -107,11 +107,12 @@ insert usertable ├── cardinality: [0 - 0] ├── volatile, mutations └── values - ├── columns: column1:14!null column2:15!null column3:16!null column4:17!null column5:18!null column6:19!null column7:20!null column8:21!null column9:22!null column10:23!null column11:24!null + ├── columns: column2:15!null column3:16!null column4:17!null column5:18!null column6:19!null column7:20!null column8:21!null column9:22!null column10:23!null column11:24!null column1:25 ├── cardinality: [1 - 1] + ├── immutable ├── key: () - ├── fd: ()-->(14-24) - └── ('user123', 'field0data', 'field1data', 'field2data', 'field3data', 'field4data', 'field5data', 'field6data', 'field7data', 'field8data', 'field9data') + ├── fd: ()-->(15-25) + └── ('field0data', 'field1data', 'field2data', 'field3data', 'field4data', 'field5data', 'field6data', 'field7data', 'field8data', 'field9data', crdb_internal.assignment_cast('user123', NULL::VARCHAR(255))) # -------------------------------------------------- # Workload E: Short ranges diff --git a/pkg/sql/pgwire/testdata/pgtest/char b/pkg/sql/pgwire/testdata/pgtest/char index d0f0f873f672..70f4ba232855 100644 --- a/pkg/sql/pgwire/testdata/pgtest/char +++ b/pkg/sql/pgwire/testdata/pgtest/char @@ -62,7 +62,7 @@ until ReadyForQuery ---- {"Type":"ParseComplete"} -{"Type":"ParameterDescription","ParameterOIDs":[23,18]} +{"Type":"ParameterDescription","ParameterOIDs":[20,25]} {"Type":"NoData"} {"Type":"BindComplete"} {"Type":"CommandComplete","CommandTag":"INSERT 0 1"} @@ -110,7 +110,7 @@ ReadyForQuery # Use the binary format for the "char" parameter. # ParameterFormatCodes = [1] for binary format send -Bind {"PreparedStatement": "s1", "ParameterFormatCodes": [1,1], "ResultFormatCodes": [0], "Parameters":[{"binary":"00000004"}, {"binary":"46"}]} +Bind {"PreparedStatement": "s1", "ParameterFormatCodes": [1,1], "ResultFormatCodes": [0], "Parameters":[{"binary":"0000000000000004"}, {"binary":"46"}]} Execute Sync ---- @@ -164,7 +164,7 @@ ReadyForQuery # Pass in a null byte. # ParameterFormatCodes = [1] for binary format send -Bind {"PreparedStatement": "s1", "ParameterFormatCodes": [1,1], "ResultFormatCodes": [0], "Parameters":[{"binary":"00000006"}, {"binary":"00"}]} +Bind {"PreparedStatement": "s1", "ParameterFormatCodes": [1,1], "ResultFormatCodes": [0], "Parameters":[{"binary":"0000000000000006"}, {"binary":"00"}]} Execute Sync ---- @@ -184,7 +184,7 @@ until ignore_table_oids ReadyForQuery ---- {"Type":"RowDescription","Fields":[{"Name":"a","TableOID":0,"TableAttributeNumber":1,"DataTypeOID":23,"DataTypeSize":4,"TypeModifier":-1,"Format":0},{"Name":"b","TableOID":0,"TableAttributeNumber":2,"DataTypeOID":18,"DataTypeSize":1,"TypeModifier":-1,"Format":0}]} -{"Type":"DataRow","Values":[{"text":"6"},null]} +{"Type":"DataRow","Values":[{"text":"6"},{"binary":"00"}]} {"Type":"CommandComplete","CommandTag":"SELECT 1"} {"Type":"ReadyForQuery","TxStatus":"I"} diff --git a/pkg/sql/sem/builtins/all_builtins.go b/pkg/sql/sem/builtins/all_builtins.go index 909e61fba065..cd52b180c18f 100644 --- a/pkg/sql/sem/builtins/all_builtins.go +++ b/pkg/sql/sem/builtins/all_builtins.go @@ -60,17 +60,25 @@ func init() { if overload.Fn != nil { fnCount++ } + if overload.FnWithExprs != nil { + fnCount++ + } if overload.Generator != nil { overload.Fn = unsuitableUseOfGeneratorFn + overload.FnWithExprs = unsuitableUseOfGeneratorFnWithExprs fnCount++ } if overload.GeneratorWithExprs != nil { overload.Fn = unsuitableUseOfGeneratorFn + overload.FnWithExprs = unsuitableUseOfGeneratorFnWithExprs fnCount++ } if fnCount > 1 { - panic(fmt.Sprintf("builtin %s: at most 1 of Fn, Generator, and GeneratorWithExprs must be set on overloads; (found %d)", - name, fnCount)) + panic(fmt.Sprintf( + "builtin %s: at most 1 of Fn, FnWithExprs, Generator, and GeneratorWithExprs"+ + "must be set on overloads; (found %d)", + name, fnCount, + )) } } } diff --git a/pkg/sql/sem/builtins/builtins.go b/pkg/sql/sem/builtins/builtins.go index aca446b88b0b..78f2ad261e6c 100644 --- a/pkg/sql/sem/builtins/builtins.go +++ b/pkg/sql/sem/builtins/builtins.go @@ -5276,6 +5276,34 @@ value if you rely on the HLC for accuracy.`, }, ), + "crdb_internal.assignment_cast": makeBuiltin( + tree.FunctionProperties{ + Category: categorySystemInfo, + // The idiomatic usage of this function is to "pass" a target type T + // by passing NULL::T, so we must allow NULL arguments. + NullableArgs: true, + }, + tree.Overload{ + Types: tree.ArgTypes{ + {"val", types.Any}, + {"type", types.Any}, + }, + ReturnType: tree.IdentityReturnType(1), + FnWithExprs: func(evalCtx *tree.EvalContext, args tree.Exprs) (tree.Datum, error) { + targetType := args[1].(tree.TypedExpr).ResolvedType() + val, err := args[0].(tree.TypedExpr).Eval(evalCtx) + if err != nil { + return nil, err + } + return tree.PerformAssignmentCast(evalCtx, val, targetType) + }, + Info: "This function is used internally to perform assignment casts during mutations.", + // The volatility of an assignment cast depends on the argument + // types, so we set it to the maximum volatility of all casts. + Volatility: tree.VolatilityStable, + }, + ), + "crdb_internal.round_decimal_values": makeBuiltin( tree.FunctionProperties{ Category: categorySystemInfo, diff --git a/pkg/sql/sem/builtins/generator_builtins.go b/pkg/sql/sem/builtins/generator_builtins.go index 38310e42fa49..5c253d557cf7 100644 --- a/pkg/sql/sem/builtins/generator_builtins.go +++ b/pkg/sql/sem/builtins/generator_builtins.go @@ -434,6 +434,10 @@ var unsuitableUseOfGeneratorFn = func(_ *tree.EvalContext, _ tree.Datums) (tree. return nil, errors.AssertionFailedf("generator functions cannot be evaluated as scalars") } +var unsuitableUseOfGeneratorFnWithExprs = func(_ *tree.EvalContext, _ tree.Exprs) (tree.Datum, error) { + return nil, errors.AssertionFailedf("generator functions cannot be evaluated as scalars") +} + func makeGeneratorOverloadWithReturnType( in tree.TypeList, retType tree.ReturnTyper, diff --git a/pkg/sql/sem/tree/cast.go b/pkg/sql/sem/tree/cast.go index 7417f9dccb88..aafa04487f22 100644 --- a/pkg/sql/sem/tree/cast.go +++ b/pkg/sql/sem/tree/cast.go @@ -833,6 +833,55 @@ func ForEachCast(fn func(src, tgt oid.Oid)) { } } +// ValidCast returns true if a valid cast exists from src to tgt in the given +// context. +func ValidCast(src, tgt *types.T, ctx CastContext) bool { + srcFamily := src.Family() + tgtFamily := tgt.Family() + + // If src and tgt are array types, check for a valid cast between their + // content types. + if srcFamily == types.ArrayFamily && tgtFamily == types.ArrayFamily { + return ValidCast(src.ArrayContents(), tgt.ArrayContents(), ctx) + } + + // If src and tgt are tuple types, check for a valid cast between each + // corresponding tuple element. + if srcFamily == types.TupleFamily && tgtFamily == types.TupleFamily { + srcTypes := src.TupleContents() + tgtTypes := tgt.TupleContents() + // The tuple types must have the same number of elements. + if len(srcTypes) != len(tgtTypes) { + return false + } + for i := range srcTypes { + if ok := ValidCast(srcTypes[i], tgtTypes[i], ctx); !ok { + return false + } + } + return true + } + + // If src and tgt are not array or tuple types, check castMap for a valid + // cast. + if c, ok := lookupCast(src.Oid(), tgt.Oid()); ok { + return c.maxContext >= ctx + } + + return false +} + +// lookupCast returns a cast that describes the cast from src to tgt if +// it exists. If it does not exist, ok=false is returned. +func lookupCast(src, tgt oid.Oid) (cast, bool) { + if tgts, ok := castMap[src]; ok { + if c, ok := tgts[tgt]; ok { + return c, true + } + } + return cast{}, false +} + type castInfo struct { from types.Family to types.Family @@ -1233,10 +1282,12 @@ func isDateStyleCastAffected(from, to types.Family) bool { return false } -// lookupCast returns the information for a valid cast. +// lookupCastInfo returns the information for a valid cast. // Returns nil if this is not a valid cast. // Does not handle array and tuple casts. -func lookupCast(from, to types.Family, intervalStyleEnabled bool, dateStyleEnabled bool) *castInfo { +func lookupCastInfo( + from, to types.Family, intervalStyleEnabled bool, dateStyleEnabled bool, +) *castInfo { k := castsMapKey{from: from, to: to} if (intervalStyleEnabled && isIntervalStyleCastAffected(from, to)) || (dateStyleEnabled && isDateStyleCastAffected(from, to)) { @@ -1279,7 +1330,7 @@ func LookupCastVolatility(from, to *types.T, sd *sessiondata.SessionData) (_ Vol return maxVolatility, true } - cast := lookupCast( + cast := lookupCastInfo( fromFamily, toFamily, sd != nil && sd.IntervalStyleEnabled, @@ -1294,13 +1345,32 @@ func LookupCastVolatility(from, to *types.T, sd *sessiondata.SessionData) (_ Vol // PerformCast performs a cast from the provided Datum to the specified // types.T. func PerformCast(ctx *EvalContext, d Datum, t *types.T) (Datum, error) { - ret, err := performCastWithoutPrecisionTruncation(ctx, d, t) + ret, err := performCastWithoutPrecisionTruncation(ctx, d, t, true /* truncateWidth */) if err != nil { return nil, err } return AdjustValueToType(t, ret) } +// PerformAssignmentCast performs an assignment cast from the provided Datum to +// the specified type. It is similar to PerformCast, but differs because it +// errors if the datum's width is too wide for the given type rather than +// silently truncating. The one exception is casts to the special "char" type +// which are truncated. +func PerformAssignmentCast(ctx *EvalContext, d Datum, t *types.T) (Datum, error) { + if !ValidCast(d.ResolvedType(), t, CastContextAssignment) { + return nil, pgerror.Newf( + pgcode.CannotCoerce, + "invalid assignment cast: %s -> %s", d.ResolvedType(), t, + ) + } + d, err := performCastWithoutPrecisionTruncation(ctx, d, t, false /* truncateWidth */) + if err != nil { + return nil, err + } + return AdjustValueToType(t, d) +} + // AdjustValueToType checks that the width (for strings, byte arrays, and bit // strings) and scale (decimal). and, shape/srid (for geospatial types) fits the // specified column type. @@ -1318,10 +1388,15 @@ func PerformCast(ctx *EvalContext, d Datum, t *types.T) (Datum, error) { // In the case of geospatial types, it will check whether the SRID and Shape in the // datum matches the type definition. // -// This method is used by casts, parsing, INSERT and UPDATE. It is important to note -// that width must be altered *before* this function, as width truncations should -// only occur during casting and parsing but not update/inserts (see -// enforceLocalColumnConstraints). +// This method is used by casts and parsing. It is important to note that this +// function will error if the given value is too wide for the given type. For +// explicit casts and parsing, inVal should be truncated before this function is +// called so that an error is not returned. For assignment casts, inVal should +// not be truncated before this function is called, so that an error is +// returned. The one exception for assignment casts is for the special "char" +// type. An assignment cast to "char" does not error and truncates a value if +// the width of the value is wider than a single character. For this exception, +// AdjustValueToType performs the truncation itself. func AdjustValueToType(typ *types.T, inVal Datum) (outVal Datum, err error) { switch typ.Family() { case types.StringFamily, types.CollatedStringFamily: @@ -1508,13 +1583,25 @@ func formatBitArrayToType(d *DBitArray, t *types.T) *DBitArray { return &DBitArray{a} } -// performCastWithoutPrecisionTruncation performs the cast, but does not do a -// check on whether the datum fits the type. +// performCastWithoutPrecisionTruncation performs the cast, but does not perform +// precision truncation. For example, if d is of type DECIMAL(6, 2) and t is +// DECIMAL(4, 2), d is not truncated to fit into t. However, if truncateWidth is +// true, widths are truncated to match the target type t for some types, +// including the bit and string types. If truncateWidth is false, the input +// datum is not truncated. +// // In an ideal state, components of AdjustValueToType should be embedded into // this function, but the code base needs a general refactor of parsing // and casting logic before this can happen. // See also: #55094. -func performCastWithoutPrecisionTruncation(ctx *EvalContext, d Datum, t *types.T) (Datum, error) { +func performCastWithoutPrecisionTruncation( + ctx *EvalContext, d Datum, t *types.T, truncateWidth bool, +) (Datum, error) { + // No conversion is needed if d is NULL. + if d == DNull { + return d, nil + } + // If we're casting a DOidWrapper, then we want to cast the wrapped datum. // It is also reasonable to lose the old Oid value too. // Note that we pass in nil as the first argument since we're not interested @@ -1522,28 +1609,33 @@ func performCastWithoutPrecisionTruncation(ctx *EvalContext, d Datum, t *types.T d = UnwrapDatum(nil /* evalCtx */, d) switch t.Family() { case types.BitFamily: + var ba *DBitArray switch v := d.(type) { case *DBitArray: - return formatBitArrayToType(v, t), nil + ba = v case *DInt: - r, err := NewDBitArrayFromInt(int64(*v), uint(t.Width())) + var err error + ba, err = NewDBitArrayFromInt(int64(*v), uint(t.Width())) if err != nil { return nil, err } - return formatBitArrayToType(r, t), nil case *DString: res, err := bitarray.Parse(string(*v)) if err != nil { return nil, err } - return formatBitArrayToType(&DBitArray{res}, t), nil + ba = &DBitArray{res} case *DCollatedString: res, err := bitarray.Parse(v.Contents) if err != nil { return nil, err } - return formatBitArrayToType(&DBitArray{res}, t), nil + ba = &DBitArray{res} } + if truncateWidth { + ba = formatBitArrayToType(ba, t) + } + return ba, nil case types.BoolFamily: switch v := d.(type) { @@ -1771,7 +1863,10 @@ func performCastWithoutPrecisionTruncation(ctx *EvalContext, d Datum, t *types.T dd.Coeff.Abs(&dd.Coeff) } err = LimitDecimalWidth(&dd.Decimal, int(t.Precision()), int(t.Scale())) - return &dd, err + if err != nil { + return nil, errors.Wrapf(err, "type %s", t.SQLString()) + } + return &dd, nil } case types.StringFamily, types.CollatedStringFamily: @@ -1866,7 +1961,7 @@ func performCastWithoutPrecisionTruncation(ctx *EvalContext, d Datum, t *types.T // If the string type specifies a limit we truncate to that limit: // 'hello'::CHAR(2) -> 'he' // This is true of all the string type variants. - if t.Width() > 0 { + if truncateWidth && t.Width() > 0 { s = util.TruncateString(s, int(t.Width())) } return NewDString(s), nil @@ -1876,7 +1971,7 @@ func performCastWithoutPrecisionTruncation(ctx *EvalContext, d Datum, t *types.T s = strings.TrimRight(s, " ") } // Ditto truncation like for TString. - if t.Width() > 0 { + if truncateWidth && t.Width() > 0 { s = util.TruncateString(s, int(t.Width())) } return NewDCollatedString(s, t.Locale(), &ctx.CollationEnv) diff --git a/pkg/sql/sem/tree/cast_test.go b/pkg/sql/sem/tree/cast_test.go index 40426e46f412..c849c6b5e47e 100644 --- a/pkg/sql/sem/tree/cast_test.go +++ b/pkg/sql/sem/tree/cast_test.go @@ -145,7 +145,7 @@ func TestCastsFromUnknown(t *testing.T) { // These type families are exceptions. default: - cast := lookupCast(types.UnknownFamily, fam, false /* intervalStyleEnabled */, false /* dateStyleEnabled */) + cast := lookupCastInfo(types.UnknownFamily, fam, false /* intervalStyleEnabled */, false /* dateStyleEnabled */) if cast == nil { t.Errorf("cast from Unknown to %s does not exist", fam) } diff --git a/pkg/sql/sem/tree/eval.go b/pkg/sql/sem/tree/eval.go index f1bfbcdfa279..ffc116e3aeb7 100644 --- a/pkg/sql/sem/tree/eval.go +++ b/pkg/sql/sem/tree/eval.go @@ -4194,6 +4194,10 @@ func (expr *FuncExpr) MaybeWrapError(err error) error { // Eval implements the TypedExpr interface. func (expr *FuncExpr) Eval(ctx *EvalContext) (Datum, error) { + if expr.fn.FnWithExprs != nil { + return expr.fn.FnWithExprs(ctx, expr.Exprs) + } + nullResult, args, err := expr.evalArgs(ctx) if err != nil { return nil, err @@ -4679,7 +4683,8 @@ func (t *Placeholder) Eval(ctx *EvalContext) (Datum, error) { // checking, since the placeholder's type hint didn't match the desired // type for the placeholder. In this case, we cast the expression to // the desired type. - // TODO(jordan): introduce a restriction on what casts are allowed here. + // TODO(jordan,mgartner): Introduce a restriction on what casts are + // allowed here. Most likely, only implicit casts should be allowed. cast := NewTypedCastExpr(e, typ) return cast.Eval(ctx) } diff --git a/pkg/sql/sem/tree/overload.go b/pkg/sql/sem/tree/overload.go index 3f87420ed352..3e17e4d20f37 100644 --- a/pkg/sql/sem/tree/overload.go +++ b/pkg/sql/sem/tree/overload.go @@ -71,10 +71,14 @@ type Overload struct { // Only one of the following three attributes can be set. // Fn is the normal builtin implementation function. It's for functions that - // take in datums and return a datum. + // take in Datums and return a Datum. Fn func(*EvalContext, Datums) (Datum, error) - // Generator is for SRFs. SRFs take datums and return multiple rows of datums. + // FnWithExprs is for builtins that need access to their arguments as Exprs + // and not pre-evaluated Datums, but is otherwise identical to Fn. + FnWithExprs func(*EvalContext, Exprs) (Datum, error) + + // Generator is for SRFs. SRFs take Datums and return multiple rows of Datums. Generator GeneratorFactory // GeneratorWithExprs is for SRFs that need access to their arguments as Exprs diff --git a/pkg/sql/sem/tree/testdata/eval/cast b/pkg/sql/sem/tree/testdata/eval/cast index f325ea3a8be2..4e293cd97713 100644 --- a/pkg/sql/sem/tree/testdata/eval/cast +++ b/pkg/sql/sem/tree/testdata/eval/cast @@ -382,6 +382,16 @@ eval ---- e'a\U0001F41Bb' +eval +'hello'::varchar(2) +---- +'he' + +eval +'a🐛b🏠c'::varchar(3) +---- +e'a\U0001F41Bb' + eval 'hello'::bytes ---- @@ -1336,3 +1346,33 @@ eval 0::char ---- '0' + +eval +1::BIT +---- +B'1' + +eval +2::BIT +---- +B'0' + +eval +123::BIT +---- +B'1' + +eval +'1'::BIT +---- +B'1' + +eval +'01'::BIT +---- +B'0' + +eval +'2'::BIT +---- +could not parse string as bit array: "2" is not a valid binary digit diff --git a/pkg/sql/sem/tree/type_check.go b/pkg/sql/sem/tree/type_check.go index ea9732eb8fe5..fe85a883197e 100644 --- a/pkg/sql/sem/tree/type_check.go +++ b/pkg/sql/sem/tree/type_check.go @@ -457,7 +457,7 @@ func resolveCast( default: // TODO(mgartner): Use OID cast map. - cast := lookupCast(fromFamily, toFamily, intervalStyleEnabled, dateStyleEnabled) + cast := lookupCastInfo(fromFamily, toFamily, intervalStyleEnabled, dateStyleEnabled) if cast == nil { return pgerror.Newf(pgcode.CannotCoerce, "invalid cast: %s -> %s", castFrom, castTo) } @@ -1551,6 +1551,12 @@ func (expr *ArrayFlatten) TypeCheck( func (expr *Placeholder) TypeCheck( ctx context.Context, semaCtx *SemaContext, desired *types.T, ) (TypedExpr, error) { + // Use the desired type family's canonical type for inference so that no + // assumptions are made about a placeholders width, precision, or other + // details. This is safe because no information can be lost by converting a + // non-canonical type to a canonical type. + canonicalDesired := desired.CanonicalType() + // Perform placeholder typing. This function is only called during Prepare, // when there are no available values for the placeholders yet, because // during Execute all placeholders are replaced from the AST before type @@ -1568,7 +1574,7 @@ func (expr *Placeholder) TypeCheck( // the type system expects. Then, when the value is actually sent to us // later, we cast the input value (whose type is the expected type) to the // desired type here. - typ = desired + typ = canonicalDesired } // We call SetType regardless of the above condition to inform the // placeholder struct that this placeholder is locked to its type and cannot @@ -1582,10 +1588,10 @@ func (expr *Placeholder) TypeCheck( if desired.IsAmbiguous() { return nil, placeholderTypeAmbiguityError(expr.Idx) } - if err := semaCtx.Placeholders.SetType(expr.Idx, desired); err != nil { + if err := semaCtx.Placeholders.SetType(expr.Idx, canonicalDesired); err != nil { return nil, err } - expr.typ = desired + expr.typ = canonicalDesired return expr, nil } diff --git a/pkg/sql/tablewriter_upsert_opt.go b/pkg/sql/tablewriter_upsert_opt.go index e48eb9fcf0e2..c8a5048cd94d 100644 --- a/pkg/sql/tablewriter_upsert_opt.go +++ b/pkg/sql/tablewriter_upsert_opt.go @@ -268,7 +268,11 @@ func (tu *optTableUpserter) updateConflictingRow( // via GenerateInsertRow(). // - for the fetched part, we assume that the data in the table is // correct already. - if err := enforceLocalColumnConstraints(updateValues, tu.updateCols); err != nil { + if err := enforceLocalColumnConstraints( + updateValues, + tu.updateCols, + true, /* isUpdate */ + ); err != nil { return err } diff --git a/pkg/sql/types/types.go b/pkg/sql/types/types.go index 33369a735cce..988034950085 100644 --- a/pkg/sql/types/types.go +++ b/pkg/sql/types/types.go @@ -1305,6 +1305,71 @@ func (f Family) Name() string { return ret } +// CanonicalType returns the canonical type of the given type's family. If the +// family does not have a canonical type, the original type is returned. +func (t *T) CanonicalType() *T { + switch t.Family() { + case BoolFamily: + return Bool + case IntFamily: + return Int + case FloatFamily: + return Float + case DecimalFamily: + return Decimal + case DateFamily: + return Date + case TimestampFamily: + return Timestamp + case IntervalFamily: + return Interval + case StringFamily: + return String + case BytesFamily: + return Bytes + case TimestampTZFamily: + return TimestampTZ + case CollatedStringFamily: + // CollatedStringFamily has no canonical type. + return t + case OidFamily: + return Oid + case UnknownFamily: + return Unknown + case UuidFamily: + return Uuid + case ArrayFamily: + // ArrayFamily has no canonical type. + return t + case INetFamily: + return INet + case TimeFamily: + return Time + case JsonFamily: + return Jsonb + case TimeTZFamily: + return TimeTZ + case TupleFamily: + // TupleFamily has no canonical type. + return t + case BitFamily: + return VarBit + case GeometryFamily: + return Geometry + case GeographyFamily: + return Geography + case EnumFamily: + // EnumFamily has no canonical type. + return t + case Box2DFamily: + return Box2D + case AnyFamily: + return Any + default: + panic(errors.AssertionFailedf("unexpected type family: %v", errors.Safe(t.Family()))) + } +} + // Name returns a single word description of the type that describes it // succinctly, but without all the details, such as width, locale, etc. The name // is sometimes the same as the name returned by SQLStandardName, but is more diff --git a/pkg/sql/update.go b/pkg/sql/update.go index 029c635e2acf..4651ffb73cbd 100644 --- a/pkg/sql/update.go +++ b/pkg/sql/update.go @@ -278,7 +278,11 @@ func (u *updateNode) processSourceRow(params runParams, sourceVals tree.Datums) // Verify the schema constraints. For consistency with INSERT/UPSERT // and compatibility with PostgreSQL, we must do this before // processing the CHECK constraints. - if err := enforceLocalColumnConstraints(u.run.updateValues, u.run.tu.ru.UpdateCols); err != nil { + if err := enforceLocalColumnConstraints( + u.run.updateValues, + u.run.tu.ru.UpdateCols, + true, /* isUpdate */ + ); err != nil { return err } @@ -410,28 +414,23 @@ func (ss scalarSlot) checkColumnTypes(row []tree.TypedExpr) error { return colinfo.CheckDatumTypeFitsColumnType(ss.column, typ) } -// enforceLocalColumnConstraints asserts the column constraints that -// do not require data validation from other sources than the row data -// itself. This includes: -// - rejecting null values in non-nullable columns; -// - checking width constraints from the column type; -// - truncating results to the requested precision (not width). -// Note: the second point is what distinguishes this operation -// from a regular SQL cast -- here widths are checked, not -// used to truncate the value silently. -// -// The row buffer is modified in-place with the result of the -// checks. -func enforceLocalColumnConstraints(row tree.Datums, cols []catalog.Column) error { +// enforceLocalColumnConstraints asserts the column constraints that do not +// require data validation from other sources than the row data itself. This +// currently only includes checking for null values in non-nullable columns. +func enforceLocalColumnConstraints(row tree.Datums, cols []catalog.Column, isUpdate bool) error { for i, col := range cols { if !col.IsNullable() && row[i] == tree.DNull { return sqlerrors.NewNonNullViolationError(col.GetName()) } - outVal, err := tree.AdjustValueToType(col.GetType(), row[i]) - if err != nil { - return err + if isUpdate { + // TODO(mgartner): Remove this once assignment casts are supported + // for UPSERTs and UPDATEs. + outVal, err := tree.AdjustValueToType(col.GetType(), row[i]) + if err != nil { + return err + } + row[i] = outVal } - row[i] = outVal } return nil } diff --git a/pkg/sql/upsert.go b/pkg/sql/upsert.go index c6ca3b5df73b..8a8600adf3ab 100644 --- a/pkg/sql/upsert.go +++ b/pkg/sql/upsert.go @@ -137,7 +137,11 @@ func (n *upsertNode) BatchedNext(params runParams) (bool, error) { // processSourceRow processes one row from the source for upsertion. // The table writer is in charge of accumulating the result rows. func (n *upsertNode) processSourceRow(params runParams, rowVals tree.Datums) error { - if err := enforceLocalColumnConstraints(rowVals, n.run.insertCols); err != nil { + if err := enforceLocalColumnConstraints( + rowVals, + n.run.insertCols, + true, /* isUpdate */ + ); err != nil { return err }