From fb507a41ad3cdf667932025b19cf2bba8f0f370e Mon Sep 17 00:00:00 2001 From: Drew Kimball Date: Thu, 16 Apr 2020 18:07:15 -0700 Subject: [PATCH] sql: add a rule to push a distinct modifier into a scalargroupby Previously, the optimizer could not take advantage of an index on a variable with a command like the following: SELECT COUNT(DISTINCT y) FROM xy; To address this, PushAggDistinctIntoScalarGroupBy pushes the distinct operation from the aggregate function and into the input of the ScalarGroupBy. Fixes #46899 Release note: None --- .../opt/exec/execbuilder/testdata/aggregate | 32 +-- .../opt/exec/execbuilder/testdata/distsql_agg | 2 +- pkg/sql/opt/memo/testdata/stats_quality/tpcc | 53 ++-- pkg/sql/opt/norm/custom_funcs.go | 11 + pkg/sql/opt/norm/rules/groupby.opt | 24 ++ pkg/sql/opt/norm/testdata/rules/groupby | 252 ++++++++++++++++++ pkg/sql/opt/xform/testdata/external/tpcc | 33 +-- .../xform/testdata/external/tpcc-later-stats | 33 +-- .../opt/xform/testdata/external/tpcc-no-stats | 33 +-- 9 files changed, 389 insertions(+), 84 deletions(-) diff --git a/pkg/sql/opt/exec/execbuilder/testdata/aggregate b/pkg/sql/opt/exec/execbuilder/testdata/aggregate index 1b0bbf6cfcac..3ac4737192ca 100644 --- a/pkg/sql/opt/exec/execbuilder/testdata/aggregate +++ b/pkg/sql/opt/exec/execbuilder/testdata/aggregate @@ -211,21 +211,23 @@ group · · (count, count, sum, sum, min, min) query TTTTT EXPLAIN (VERBOSE) SELECT count(DISTINCT a.*) FROM kv a, kv b ---- -· distributed false · · -· vectorized false · · -group · · (count) · - │ aggregate 0 count(DISTINCT column9) · · - │ scalar · · · - └── render · · (column9) · - │ render 0 ((k, v, w, s) AS k, v, w, s) · · - └── cross-join · · (k, v, w, s) · - │ type cross · · - ├── scan · · (k, v, w, s) · - │ table kv@primary · · - │ spans FULL SCAN · · - └── scan · · () · -· table kv@primary · · -· spans FULL SCAN · · +· distributed false · · +· vectorized false · · +group · · (count) · + │ aggregate 0 count(column9) · · + │ scalar · · · + └── distinct · · (column9) · + │ distinct on column9 · · + └── render · · (column9) · + │ render 0 ((k, v, w, s) AS k, v, w, s) · · + └── cross-join · · (k, v, w, s) · + │ type cross · · + ├── scan · · (k, v, w, s) · + │ table kv@primary · · + │ spans FULL SCAN · · + └── scan · · () · +· table kv@primary · · +· spans FULL SCAN · · query TTT SELECT tree, field, description FROM [ diff --git a/pkg/sql/opt/exec/execbuilder/testdata/distsql_agg b/pkg/sql/opt/exec/execbuilder/testdata/distsql_agg index 22fa5c798fe7..8a13ad5325ec 100644 --- a/pkg/sql/opt/exec/execbuilder/testdata/distsql_agg +++ b/pkg/sql/opt/exec/execbuilder/testdata/distsql_agg @@ -138,7 +138,7 @@ https://cockroachdb.github.io/distsqlplan/decode.html#eJyslEFvmzAYhu_7FdZ3ajUjMJ query T SELECT url FROM [EXPLAIN (DISTSQL) SELECT SUM (DISTINCT A) FROM data] ---- -https://cockroachdb.github.io/distsqlplan/decode.html#eJyslFGLm04Uxd__n2K4T__ABDNqslmfsuymIGSTbUyhsPgwdS5WMI6dGaEl5LsXtSRNyI4S--g4557z88g9gP6RQwDRcrV83pFK5eTTdvNK3pdf31ZP4Zr8_xJGu-jzakT-XNHVvjkL1887wkftdcENj4FCIQWu-R41BO_AgIILFDyg4AOFKcQUSiUT1Fqq-sqhEYTiJwQTCllRVqY-jikkUiEEBzCZyREC2PFvOW6RC1TOBCgINDzLG5tSZXuufi3qDEAhKnmhAzJ2GOGFIIxI8x0VUNhUJiALBvGRgqzM2UsbniIE7Ej753nJtMmKxDjTyzCW-e6H889jq0IqgQrFxdT4eCPBU5oqTLmRymFXXyT68nquaMFGH0byLiKx_hWwPhU4bOy4g0roSHQqYXZnCW5_YrcXsTt2vEHEHYlOxA93Env9ib1exN7Y8QcRdyQ6Ec_vJPb7E_u9iP2xMx1E3JHoRPz4D1bLjflb1KUsNF6tmNuTJ_XqQZFiu6e0rFSCb0omjU37uGl0zYFAbdq3rH0Ii_ZVHfBvMbOK3Qsxuxa7ducOa8-q9u1if0juqVU8szvPhjg_WMVzu_N8iPOjvatJx29i_8muvePjf78DAAD__wbY234= +https://cockroachdb.github.io/distsqlplan/decode.html#eJyslEFvmzAYhu_7FdZ3ajRHxECahlOqNpMipUkXMmlSxcHDnxgSwcw20qYo_30CpnRUi6EjR4xfnvfhs3wE_SODAMLlevmwJ6XKyKfd9om8LL8-r-9XG3LzuAr34ef1iPzZostDvbbaPOwJHzXbBTc8Agq5FLjhB9QQvAADCi5Q8ICCDxSmEFEolIxRa6mqLcc6sBI_IZhQSPOiNNVyRCGWCiE4gklNhhDAnn_LcIdcoHImQEGg4WlWYwqVHrj6tag6AIWw4LkOyNhhhOeCMCLNd1RAYVuagCwYRCcKsjSvLG14ghCwE-3f5zHVJs1j40zbZRaV9FYJVCisNPci7RUim--8JXyE6GSrxCb_2cl7zx-4TxKFCTdSOYy1geGXp5sFG13k-C0O6z951mfyDhs77qDZdzQ6_-jbq8ze7e_v9vJ3x443yL-j0dl_dhV_r7-_18vfGzv-IP-ORmf_u6v4-_39_V7-_tiZDvLvaHT2n1_97vsHbYe6kLnGFuvSlyfVxYgiweYi1bJUMT4rGdeY5nFb5-oFgdo0b1nzsMqbV1XBv8PMGnZbYfY27FrDnp3s2Wu79rRvTU_t4ekQ6VtreGYnz4aQ76zhuZ08H0JmHWes65C975RFpw-_AwAA___7miUG query T SELECT url FROM [EXPLAIN (DISTSQL) SELECT SUM (DISTINCT A), SUM (DISTINCT B) FROM data] diff --git a/pkg/sql/opt/memo/testdata/stats_quality/tpcc b/pkg/sql/opt/memo/testdata/stats_quality/tpcc index 45e2ff592389..5a16f210f686 100644 --- a/pkg/sql/opt/memo/testdata/stats_quality/tpcc +++ b/pkg/sql/opt/memo/testdata/stats_quality/tpcc @@ -544,30 +544,35 @@ scalar-group-by ├── stats: [rows=1, distinct(28)=1, null(28)=0] ├── key: () ├── fd: ()-->(28) - ├── inner-join (lookup stock) - │ ├── save-table-name: stock_level_02_lookup_join_2 - │ ├── columns: ol_o_id:1(int!null) ol_d_id:2(int!null) ol_w_id:3(int!null) ol_i_id:5(int!null) s_i_id:11(int!null) s_w_id:12(int!null) s_quantity:13(int!null) - │ ├── key columns: [3 5] = [12 11] - │ ├── lookup columns are key - │ ├── stats: [rows=216.137889, distinct(1)=19.9995949, null(1)=0, distinct(2)=1, null(2)=0, distinct(3)=1, null(3)=0, distinct(5)=185.570315, null(5)=0, distinct(11)=185.570315, null(11)=0, distinct(12)=1, null(12)=0, distinct(13)=30.3089364, null(13)=0] - │ ├── fd: ()-->(2,3,12), (11)-->(13), (5)==(11), (11)==(5), (3)==(12), (12)==(3) - │ ├── scan order_line - │ │ ├── save-table-name: stock_level_02_scan_3 - │ │ ├── columns: ol_o_id:1(int!null) ol_d_id:2(int!null) ol_w_id:3(int!null) ol_i_id:5(int!null) - │ │ ├── constraint: /3/2/-1/4: [/1/1/999 - /1/1/980] - │ │ ├── stats: [rows=185.737555, distinct(1)=20, null(1)=0, distinct(2)=1, null(2)=0, distinct(3)=1, null(3)=0, distinct(5)=185.570315, null(5)=0] - │ │ │ histogram(3)= 0 185.74 - │ │ │ <---- 1 -- - │ │ └── fd: ()-->(2,3) - │ └── filters - │ ├── s_w_id:12 = 1 [type=bool, outer=(12), constraints=(/12: [/1 - /1]; tight), fd=()-->(12)] - │ └── s_quantity:13 < 15 [type=bool, outer=(13), constraints=(/13: (/NULL - /14]; tight)] + ├── distinct-on + │ ├── save-table-name: stock_level_02_distinct_on_2 + │ ├── columns: s_i_id:11(int!null) + │ ├── grouping columns: s_i_id:11(int!null) + │ ├── stats: [rows=185.570315, distinct(11)=185.570315, null(11)=0] + │ ├── key: (11) + │ └── inner-join (lookup stock) + │ ├── save-table-name: stock_level_02_lookup_join_3 + │ ├── columns: ol_o_id:1(int!null) ol_d_id:2(int!null) ol_w_id:3(int!null) ol_i_id:5(int!null) s_i_id:11(int!null) s_w_id:12(int!null) s_quantity:13(int!null) + │ ├── key columns: [3 5] = [12 11] + │ ├── lookup columns are key + │ ├── stats: [rows=216.137889, distinct(1)=19.9995949, null(1)=0, distinct(2)=1, null(2)=0, distinct(3)=1, null(3)=0, distinct(5)=185.570315, null(5)=0, distinct(11)=185.570315, null(11)=0, distinct(12)=1, null(12)=0, distinct(13)=30.3089364, null(13)=0] + │ ├── fd: ()-->(2,3,12), (11)-->(13), (5)==(11), (11)==(5), (3)==(12), (12)==(3) + │ ├── scan order_line + │ │ ├── save-table-name: stock_level_02_scan_4 + │ │ ├── columns: ol_o_id:1(int!null) ol_d_id:2(int!null) ol_w_id:3(int!null) ol_i_id:5(int!null) + │ │ ├── constraint: /3/2/-1/4: [/1/1/999 - /1/1/980] + │ │ ├── stats: [rows=185.737555, distinct(1)=20, null(1)=0, distinct(2)=1, null(2)=0, distinct(3)=1, null(3)=0, distinct(5)=185.570315, null(5)=0] + │ │ │ histogram(3)= 0 185.74 + │ │ │ <---- 1 -- + │ │ └── fd: ()-->(2,3) + │ └── filters + │ ├── s_w_id:12 = 1 [type=bool, outer=(12), constraints=(/12: [/1 - /1]; tight), fd=()-->(12)] + │ └── s_quantity:13 < 15 [type=bool, outer=(13), constraints=(/13: (/NULL - /14]; tight)] └── aggregations - └── agg-distinct [as=count:28, type=int, outer=(11)] - └── count [type=int] - └── s_i_id:11 [type=int] + └── count [as=count:28, type=int, outer=(11)] + └── s_i_id:11 [type=int] -stats table=stock_level_02_scan_3 +stats table=stock_level_02_scan_4 ---- column_names row_count distinct_count null_count {ol_d_id} 193 1 0 @@ -581,7 +586,7 @@ column_names row_count_est row_count_err distinct_count_est distinct_count_e {ol_o_id} 186.00 1.04 20.00 1.00 0.00 1.00 {ol_w_id} 186.00 1.04 1.00 1.00 0.00 1.00 -stats table=stock_level_02_lookup_join_2 +stats table=stock_level_02_lookup_join_3 ---- column_names row_count distinct_count null_count {ol_d_id} 15 1 0 @@ -601,6 +606,8 @@ column_names row_count_est row_count_err distinct_count_est distinct_count_e {s_quantity} 216.00 14.40 <== 30.00 6.00 <== 0.00 1.00 {s_w_id} 216.00 14.40 <== 1.00 1.00 0.00 1.00 +TODO(radu): add stock_level_02_distinct_on_2. + stats table=stock_level_02_scalar_group_by_1 ---- column_names row_count distinct_count null_count diff --git a/pkg/sql/opt/norm/custom_funcs.go b/pkg/sql/opt/norm/custom_funcs.go index c646a33ce082..9b98a25bad65 100644 --- a/pkg/sql/opt/norm/custom_funcs.go +++ b/pkg/sql/opt/norm/custom_funcs.go @@ -1289,6 +1289,11 @@ func (c *CustomFuncs) GroupingCols(grouping *memo.GroupingPrivate) opt.ColSet { return grouping.GroupingCols } +// ExtractAggInputColumns returns the set of columns the aggregate depends on. +func (c *CustomFuncs) ExtractAggInputColumns(e opt.ScalarExpr) opt.ColSet { + return memo.ExtractAggInputColumns(e) +} + // IsUnorderedGrouping returns true if the given grouping ordering is not // specified. func (c *CustomFuncs) IsUnorderedGrouping(grouping *memo.GroupingPrivate) bool { @@ -1906,6 +1911,12 @@ func (c *CustomFuncs) MakeOrderedGrouping( return &memo.GroupingPrivate{GroupingCols: groupingCols, Ordering: ordering} } +// MakeUnorderedGrouping constructs a new GroupingPrivate using the given +// grouping columns, but with no ordering on the groups. +func (c CustomFuncs) MakeUnorderedGrouping(groupingCols opt.ColSet) *memo.GroupingPrivate { + return &memo.GroupingPrivate{GroupingCols: groupingCols} +} + // IsLimited indicates whether a limit was pushed under the subquery // already. See e.g. the rule IntroduceExistsLimit. func (c *CustomFuncs) IsLimited(sub *memo.SubqueryPrivate) bool { diff --git a/pkg/sql/opt/norm/rules/groupby.opt b/pkg/sql/opt/norm/rules/groupby.opt index 7de2dadba6f8..6d69e309a67b 100644 --- a/pkg/sql/opt/norm/rules/groupby.opt +++ b/pkg/sql/opt/norm/rules/groupby.opt @@ -199,3 +199,27 @@ (GroupingCols $groupingPrivate) $aggregations ) + +# PushAggDistinctIntoScalarGroupBy pushes an aggregate function DISTINCT +# modifier into the input of the ScalarGroupBy operator. This allows the +# optimizer to take advantage of an index on the column(s) subject to the +# DISTINCT operation. PushAggDistinctIntoScalarGroupBy can match any single +# aggregate function, including those that have multiple input arguments. +[PushAggDistinctIntoScalarGroupBy, Normalize] +(ScalarGroupBy + $input:* + $aggregations:[ + $item:(AggregationsItem (AggDistinct $agg:*) $aggColID:*) + ] + $groupingPrivate:* +) +=> +(ScalarGroupBy + (DistinctOn + $input + [] + (MakeUnorderedGrouping (ExtractAggInputColumns $agg)) + ) + [ (AggregationsItem $agg $aggColID) ] + $groupingPrivate +) diff --git a/pkg/sql/opt/norm/testdata/rules/groupby b/pkg/sql/opt/norm/testdata/rules/groupby index ef59951cd327..3be05fcc14d8 100644 --- a/pkg/sql/opt/norm/testdata/rules/groupby +++ b/pkg/sql/opt/norm/testdata/rules/groupby @@ -58,6 +58,18 @@ CREATE TABLE nullablecols ( ) ---- +exec-ddl +CREATE TABLE xyzbs +( + x INT PRIMARY KEY, + y INT, + z INT NOT NULL, + b BOOL, + s TEXT, + INDEX (y) +) +---- + # -------------------------------------------------- # ConvertGroupByToDistinct # -------------------------------------------------- @@ -1941,3 +1953,243 @@ insert a │ └── column13:13 └── const-agg [as="?column?":11, outer=(11)] └── "?column?":11 + +# -------------------------------------------------- +# PushAggDistinctIntoScalarGroupBy +# -------------------------------------------------- + +# SUM case. +norm expect=PushAggDistinctIntoScalarGroupBy +SELECT sum(DISTINCT y) FROM xyzbs +---- +scalar-group-by + ├── columns: sum:6 + ├── cardinality: [1 - 1] + ├── key: () + ├── fd: ()-->(6) + ├── distinct-on + │ ├── columns: y:2 + │ ├── grouping columns: y:2 + │ ├── key: (2) + │ └── scan xyzbs + │ └── columns: y:2 + └── aggregations + └── sum [as=sum:6, outer=(2)] + └── y:2 + +# COUNT case. Expecting an index scan because opt command is used. +opt expect=PushAggDistinctIntoScalarGroupBy +SELECT count(DISTINCT y) FROM xyzbs +---- +scalar-group-by + ├── columns: count:6!null + ├── cardinality: [1 - 1] + ├── key: () + ├── fd: ()-->(6) + ├── distinct-on + │ ├── columns: y:2 + │ ├── grouping columns: y:2 + │ ├── internal-ordering: +2 + │ ├── key: (2) + │ └── scan xyzbs@secondary + │ ├── columns: y:2 + │ └── ordering: +2 + └── aggregations + └── count [as=count:6, outer=(2)] + └── y:2 + +# AVG case. +norm expect=PushAggDistinctIntoScalarGroupBy +SELECT avg(DISTINCT y) FROM xyzbs +---- +scalar-group-by + ├── columns: avg:6 + ├── cardinality: [1 - 1] + ├── key: () + ├── fd: ()-->(6) + ├── distinct-on + │ ├── columns: y:2 + │ ├── grouping columns: y:2 + │ ├── key: (2) + │ └── scan xyzbs + │ └── columns: y:2 + └── aggregations + └── avg [as=avg:6, outer=(2)] + └── y:2 + +# JSON_AGG case. +norm expect=PushAggDistinctIntoScalarGroupBy +SELECT json_agg(DISTINCT y) FROM xyzbs +---- +scalar-group-by + ├── columns: json_agg:6 + ├── cardinality: [1 - 1] + ├── key: () + ├── fd: ()-->(6) + ├── distinct-on + │ ├── columns: y:2 + │ ├── grouping columns: y:2 + │ ├── key: (2) + │ └── scan xyzbs + │ └── columns: y:2 + └── aggregations + └── json-agg [as=json_agg:6, outer=(2)] + └── y:2 + +# CORR case. +# Multiple input arguments for aggregate function. +norm expect=PushAggDistinctIntoScalarGroupBy +SELECT corr(DISTINCT y, z) FROM xyzbs +---- +scalar-group-by + ├── columns: corr:6 + ├── cardinality: [1 - 1] + ├── key: () + ├── fd: ()-->(6) + ├── distinct-on + │ ├── columns: y:2 z:3!null + │ ├── grouping columns: y:2 z:3!null + │ ├── key: (2,3) + │ └── scan xyzbs + │ └── columns: y:2 z:3!null + └── aggregations + └── corr [as=corr:6, outer=(2,3)] + ├── y:2 + └── z:3 + +# STRING_AGG case. +# Multiple input arguments for aggregate function. +norm expect=PushAggDistinctIntoScalarGroupBy +SELECT string_agg(DISTINCT s, '-') FROM xyzbs +---- +scalar-group-by + ├── columns: string_agg:7 + ├── cardinality: [1 - 1] + ├── key: () + ├── fd: ()-->(7) + ├── distinct-on + │ ├── columns: s:5 column6:6!null + │ ├── grouping columns: s:5 + │ ├── key: (5) + │ ├── fd: ()-->(6) + │ ├── project + │ │ ├── columns: column6:6!null s:5 + │ │ ├── fd: ()-->(6) + │ │ ├── scan xyzbs + │ │ │ └── columns: s:5 + │ │ └── projections + │ │ └── '-' [as=column6:6] + │ └── aggregations + │ └── const-agg [as=column6:6, outer=(6)] + │ └── column6:6 + └── aggregations + └── string-agg [as=string_agg:7, outer=(5,6)] + ├── s:5 + └── column6:6 + +# STRING_AGG case with an ORDER BY. +# Multiple input arguments for aggregate function. +norm expect=PushAggDistinctIntoScalarGroupBy +SELECT string_agg(DISTINCT s, '-') FROM (SELECT s FROM xyzbs ORDER BY s) +---- +scalar-group-by + ├── columns: string_agg:7 + ├── internal-ordering: +5 opt(6) + ├── cardinality: [1 - 1] + ├── key: () + ├── fd: ()-->(7) + ├── sort + │ ├── columns: s:5 column6:6!null + │ ├── key: (5) + │ ├── fd: ()-->(6) + │ ├── ordering: +5 opt(6) [actual: +5] + │ └── distinct-on + │ ├── columns: s:5 column6:6!null + │ ├── grouping columns: s:5 + │ ├── key: (5) + │ ├── fd: ()-->(6) + │ ├── project + │ │ ├── columns: column6:6!null s:5 + │ │ ├── fd: ()-->(6) + │ │ ├── scan xyzbs + │ │ │ └── columns: s:5 + │ │ └── projections + │ │ └── '-' [as=column6:6] + │ └── aggregations + │ └── const-agg [as=column6:6, outer=(6)] + │ └── column6:6 + └── aggregations + └── string-agg [as=string_agg:7, outer=(5,6)] + ├── s:5 + └── column6:6 + +# No-op case where the same aggregate function is called on different +# columns. +norm expect-not=PushAggDistinctIntoScalarGroupBy +SELECT count(DISTINCT y), count(DISTINCT z) FROM xyzbs +---- +scalar-group-by + ├── columns: count:6!null count:7!null + ├── cardinality: [1 - 1] + ├── key: () + ├── fd: ()-->(6,7) + ├── scan xyzbs + │ └── columns: y:2 z:3!null + └── aggregations + ├── agg-distinct [as=count:6, outer=(2)] + │ └── count + │ └── y:2 + └── agg-distinct [as=count:7, outer=(3)] + └── count + └── z:3 + +# No-op case where different aggregate functions are called on the same +# column. +norm expect-not=PushAggDistinctIntoScalarGroupBy +SELECT count(DISTINCT y), sum(DISTINCT y) FROM xyzbs +---- +scalar-group-by + ├── columns: count:6!null sum:7 + ├── cardinality: [1 - 1] + ├── key: () + ├── fd: ()-->(6,7) + ├── scan xyzbs + │ └── columns: y:2 + └── aggregations + ├── agg-distinct [as=count:6, outer=(2)] + │ └── count + │ └── y:2 + └── agg-distinct [as=sum:7, outer=(2)] + └── sum + └── y:2 + +# No-op cases where EliminateAggDistinct removes the AggDistinct before +# PushAggDistinctIntoScalarGroupBy is applied. Applies to MAX, MIN, BOOL_AND, +# and BOOL_OR. +norm expect-not=PushAggDistinctIntoScalarGroupBy +SELECT max(DISTINCT y) FROM xyzbs +---- +scalar-group-by + ├── columns: max:6 + ├── cardinality: [1 - 1] + ├── key: () + ├── fd: ()-->(6) + ├── scan xyzbs + │ └── columns: y:2 + └── aggregations + └── max [as=max:6, outer=(2)] + └── y:2 + +norm expect-not=PushAggDistinctIntoScalarGroupBy +SELECT bool_and(DISTINCT b) FROM xyzbs +---- +scalar-group-by + ├── columns: bool_and:6 + ├── cardinality: [1 - 1] + ├── key: () + ├── fd: ()-->(6) + ├── scan xyzbs + │ └── columns: b:4 + └── aggregations + └── bool-and [as=bool_and:6, outer=(4)] + └── b:4 diff --git a/pkg/sql/opt/xform/testdata/external/tpcc b/pkg/sql/opt/xform/testdata/external/tpcc index dc4bd3d5a47e..408c9299e8d6 100644 --- a/pkg/sql/opt/xform/testdata/external/tpcc +++ b/pkg/sql/opt/xform/testdata/external/tpcc @@ -1026,22 +1026,25 @@ scalar-group-by ├── cardinality: [1 - 1] ├── key: () ├── fd: ()-->(28) - ├── inner-join (lookup stock) - │ ├── columns: ol_o_id:1!null ol_d_id:2!null ol_w_id:3!null ol_i_id:5!null s_i_id:11!null s_w_id:12!null s_quantity:13!null - │ ├── key columns: [3 5] = [12 11] - │ ├── lookup columns are key - │ ├── fd: ()-->(2,3,12), (11)-->(13), (5)==(11), (11)==(5), (3)==(12), (12)==(3) - │ ├── scan order_line - │ │ ├── columns: ol_o_id:1!null ol_d_id:2!null ol_w_id:3!null ol_i_id:5!null - │ │ ├── constraint: /3/2/-1/4: [/10/100/999 - /10/100/980] - │ │ └── fd: ()-->(2,3) - │ └── filters - │ ├── s_w_id:12 = 10 [outer=(12), constraints=(/12: [/10 - /10]; tight), fd=()-->(12)] - │ └── s_quantity:13 < 15 [outer=(13), constraints=(/13: (/NULL - /14]; tight)] + ├── distinct-on + │ ├── columns: s_i_id:11!null + │ ├── grouping columns: s_i_id:11!null + │ ├── key: (11) + │ └── inner-join (lookup stock) + │ ├── columns: ol_o_id:1!null ol_d_id:2!null ol_w_id:3!null ol_i_id:5!null s_i_id:11!null s_w_id:12!null s_quantity:13!null + │ ├── key columns: [3 5] = [12 11] + │ ├── lookup columns are key + │ ├── fd: ()-->(2,3,12), (11)-->(13), (5)==(11), (11)==(5), (3)==(12), (12)==(3) + │ ├── scan order_line + │ │ ├── columns: ol_o_id:1!null ol_d_id:2!null ol_w_id:3!null ol_i_id:5!null + │ │ ├── constraint: /3/2/-1/4: [/10/100/999 - /10/100/980] + │ │ └── fd: ()-->(2,3) + │ └── filters + │ ├── s_w_id:12 = 10 [outer=(12), constraints=(/12: [/10 - /10]; tight), fd=()-->(12)] + │ └── s_quantity:13 < 15 [outer=(13), constraints=(/13: (/NULL - /14]; tight)] └── aggregations - └── agg-distinct [as=count:28, outer=(11)] - └── count - └── s_i_id:11 + └── count [as=count:28, outer=(11)] + └── s_i_id:11 # -------------------------------------------------- # Consistency Queries diff --git a/pkg/sql/opt/xform/testdata/external/tpcc-later-stats b/pkg/sql/opt/xform/testdata/external/tpcc-later-stats index 82124475eed6..b6eac900c13b 100644 --- a/pkg/sql/opt/xform/testdata/external/tpcc-later-stats +++ b/pkg/sql/opt/xform/testdata/external/tpcc-later-stats @@ -1028,22 +1028,25 @@ scalar-group-by ├── cardinality: [1 - 1] ├── key: () ├── fd: ()-->(28) - ├── inner-join (lookup stock) - │ ├── columns: ol_o_id:1!null ol_d_id:2!null ol_w_id:3!null ol_i_id:5!null s_i_id:11!null s_w_id:12!null s_quantity:13!null - │ ├── key columns: [3 5] = [12 11] - │ ├── lookup columns are key - │ ├── fd: ()-->(2,3,12), (11)-->(13), (5)==(11), (11)==(5), (3)==(12), (12)==(3) - │ ├── scan order_line - │ │ ├── columns: ol_o_id:1!null ol_d_id:2!null ol_w_id:3!null ol_i_id:5!null - │ │ ├── constraint: /3/2/-1/4: [/10/100/999 - /10/100/980] - │ │ └── fd: ()-->(2,3) - │ └── filters - │ ├── s_w_id:12 = 10 [outer=(12), constraints=(/12: [/10 - /10]; tight), fd=()-->(12)] - │ └── s_quantity:13 < 15 [outer=(13), constraints=(/13: (/NULL - /14]; tight)] + ├── distinct-on + │ ├── columns: s_i_id:11!null + │ ├── grouping columns: s_i_id:11!null + │ ├── key: (11) + │ └── inner-join (lookup stock) + │ ├── columns: ol_o_id:1!null ol_d_id:2!null ol_w_id:3!null ol_i_id:5!null s_i_id:11!null s_w_id:12!null s_quantity:13!null + │ ├── key columns: [3 5] = [12 11] + │ ├── lookup columns are key + │ ├── fd: ()-->(2,3,12), (11)-->(13), (5)==(11), (11)==(5), (3)==(12), (12)==(3) + │ ├── scan order_line + │ │ ├── columns: ol_o_id:1!null ol_d_id:2!null ol_w_id:3!null ol_i_id:5!null + │ │ ├── constraint: /3/2/-1/4: [/10/100/999 - /10/100/980] + │ │ └── fd: ()-->(2,3) + │ └── filters + │ ├── s_w_id:12 = 10 [outer=(12), constraints=(/12: [/10 - /10]; tight), fd=()-->(12)] + │ └── s_quantity:13 < 15 [outer=(13), constraints=(/13: (/NULL - /14]; tight)] └── aggregations - └── agg-distinct [as=count:28, outer=(11)] - └── count - └── s_i_id:11 + └── count [as=count:28, outer=(11)] + └── s_i_id:11 # -------------------------------------------------- # Consistency Queries diff --git a/pkg/sql/opt/xform/testdata/external/tpcc-no-stats b/pkg/sql/opt/xform/testdata/external/tpcc-no-stats index cbe31958b91d..6152a731aa8b 100644 --- a/pkg/sql/opt/xform/testdata/external/tpcc-no-stats +++ b/pkg/sql/opt/xform/testdata/external/tpcc-no-stats @@ -1022,22 +1022,25 @@ scalar-group-by ├── cardinality: [1 - 1] ├── key: () ├── fd: ()-->(28) - ├── inner-join (lookup stock) - │ ├── columns: ol_o_id:1!null ol_d_id:2!null ol_w_id:3!null ol_i_id:5!null s_i_id:11!null s_w_id:12!null s_quantity:13!null - │ ├── key columns: [3 5] = [12 11] - │ ├── lookup columns are key - │ ├── fd: ()-->(2,3,12), (11)-->(13), (5)==(11), (11)==(5), (3)==(12), (12)==(3) - │ ├── scan order_line - │ │ ├── columns: ol_o_id:1!null ol_d_id:2!null ol_w_id:3!null ol_i_id:5!null - │ │ ├── constraint: /3/2/-1/4: [/10/100/999 - /10/100/980] - │ │ └── fd: ()-->(2,3) - │ └── filters - │ ├── s_w_id:12 = 10 [outer=(12), constraints=(/12: [/10 - /10]; tight), fd=()-->(12)] - │ └── s_quantity:13 < 15 [outer=(13), constraints=(/13: (/NULL - /14]; tight)] + ├── distinct-on + │ ├── columns: s_i_id:11!null + │ ├── grouping columns: s_i_id:11!null + │ ├── key: (11) + │ └── inner-join (lookup stock) + │ ├── columns: ol_o_id:1!null ol_d_id:2!null ol_w_id:3!null ol_i_id:5!null s_i_id:11!null s_w_id:12!null s_quantity:13!null + │ ├── key columns: [3 5] = [12 11] + │ ├── lookup columns are key + │ ├── fd: ()-->(2,3,12), (11)-->(13), (5)==(11), (11)==(5), (3)==(12), (12)==(3) + │ ├── scan order_line + │ │ ├── columns: ol_o_id:1!null ol_d_id:2!null ol_w_id:3!null ol_i_id:5!null + │ │ ├── constraint: /3/2/-1/4: [/10/100/999 - /10/100/980] + │ │ └── fd: ()-->(2,3) + │ └── filters + │ ├── s_w_id:12 = 10 [outer=(12), constraints=(/12: [/10 - /10]; tight), fd=()-->(12)] + │ └── s_quantity:13 < 15 [outer=(13), constraints=(/13: (/NULL - /14]; tight)] └── aggregations - └── agg-distinct [as=count:28, outer=(11)] - └── count - └── s_i_id:11 + └── count [as=count:28, outer=(11)] + └── s_i_id:11 # -------------------------------------------------- # Consistency Queries