planner: fix expand operator shouldn't keep child keys && fix grouping function forget to encode their func meta (#62558)
close pingcap/tidb#62551
This commit is contained in:
@ -91,7 +91,8 @@ func (b *BuiltinGroupingImplSig) setMetaGroupingMarks(groupingMarks []map[uint64
|
||||
b.groupingMarks = groupingMarks
|
||||
}
|
||||
|
||||
func (b *BuiltinGroupingImplSig) getGroupingMode() tipb.GroupingMode {
|
||||
// GetGroupingMode returns the grouping mode of the grouping function.
|
||||
func (b *BuiltinGroupingImplSig) GetGroupingMode() tipb.GroupingMode {
|
||||
return b.mode
|
||||
}
|
||||
|
||||
@ -128,7 +129,8 @@ func (b *BuiltinGroupingImplSig) Clone() builtinFunc {
|
||||
return newSig
|
||||
}
|
||||
|
||||
func (b *BuiltinGroupingImplSig) getMetaGroupingMarks() []map[uint64]struct{} {
|
||||
// GetMetaGroupingMarks returns the grouping marks of the grouping function.
|
||||
func (b *BuiltinGroupingImplSig) GetMetaGroupingMarks() []map[uint64]struct{} {
|
||||
return b.groupingMarks
|
||||
}
|
||||
|
||||
@ -136,8 +138,8 @@ func (b *BuiltinGroupingImplSig) checkMetadata() error {
|
||||
if !b.isMetaInited {
|
||||
return errors.Errorf("Meta data hasn't been initialized")
|
||||
}
|
||||
mode := b.getGroupingMode()
|
||||
groupingMarks := b.getMetaGroupingMarks()
|
||||
mode := b.GetGroupingMode()
|
||||
groupingMarks := b.GetMetaGroupingMarks()
|
||||
if mode != tipb.GroupingMode_ModeBitAnd && mode != tipb.GroupingMode_ModeNumericCmp && mode != tipb.GroupingMode_ModeNumericSet {
|
||||
return errors.Errorf("Mode of meta data in grouping function is invalid. input mode: %d", mode)
|
||||
} else if mode == tipb.GroupingMode_ModeBitAnd || mode == tipb.GroupingMode_ModeNumericCmp {
|
||||
@ -151,7 +153,7 @@ func (b *BuiltinGroupingImplSig) checkMetadata() error {
|
||||
}
|
||||
|
||||
func (b *BuiltinGroupingImplSig) groupingImplBitAnd(groupingID uint64) int64 {
|
||||
groupingMarks := b.getMetaGroupingMarks()
|
||||
groupingMarks := b.GetMetaGroupingMarks()
|
||||
res := uint64(0)
|
||||
for _, groupingMark := range groupingMarks {
|
||||
// for Bit-And mode, there is only one element in groupingMark.
|
||||
@ -168,7 +170,7 @@ func (b *BuiltinGroupingImplSig) groupingImplBitAnd(groupingID uint64) int64 {
|
||||
}
|
||||
|
||||
func (b *BuiltinGroupingImplSig) groupingImplNumericCmp(groupingID uint64) int64 {
|
||||
groupingMarks := b.getMetaGroupingMarks()
|
||||
groupingMarks := b.GetMetaGroupingMarks()
|
||||
res := uint64(0)
|
||||
for _, groupingMark := range groupingMarks {
|
||||
// for Num-Cmp mode, there is only one element in groupingMark.
|
||||
@ -185,7 +187,7 @@ func (b *BuiltinGroupingImplSig) groupingImplNumericCmp(groupingID uint64) int64
|
||||
}
|
||||
|
||||
func (b *BuiltinGroupingImplSig) groupingImplNumericSet(groupingID uint64) int64 {
|
||||
groupingMarks := b.getMetaGroupingMarks()
|
||||
groupingMarks := b.GetMetaGroupingMarks()
|
||||
res := uint64(0)
|
||||
for _, groupingMark := range groupingMarks {
|
||||
res <<= 1
|
||||
|
||||
@ -741,6 +741,23 @@ func ReHashCode(sf *ScalarFunction) {
|
||||
evalTp := sf.RetType.EvalType()
|
||||
sf.hashcode = append(sf.hashcode, byte(evalTp))
|
||||
}
|
||||
if sf.FuncName.L == ast.Grouping {
|
||||
sf.hashcode = codec.EncodeInt(sf.hashcode, int64(sf.Function.(*BuiltinGroupingImplSig).GetGroupingMode()))
|
||||
marks := sf.Function.(*BuiltinGroupingImplSig).GetMetaGroupingMarks()
|
||||
sf.hashcode = codec.EncodeInt(sf.hashcode, int64(len(marks)))
|
||||
for _, mark := range marks {
|
||||
sf.hashcode = codec.EncodeInt(sf.hashcode, int64(len(mark)))
|
||||
// we need to sort map keys to ensure the hashcode is deterministic.
|
||||
keys := make([]uint64, 0, len(mark))
|
||||
for k := range mark {
|
||||
keys = append(keys, k)
|
||||
}
|
||||
slices.Sort(keys)
|
||||
for _, k := range keys {
|
||||
sf.hashcode = codec.EncodeInt(sf.hashcode, int64(k))
|
||||
}
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
// ResolveIndices implements Expression interface.
|
||||
|
||||
@ -448,9 +448,11 @@ func (p *PhysicalExpand) ExplainInfo() string {
|
||||
var str strings.Builder
|
||||
str.WriteString("group set num:")
|
||||
str.WriteString(strconv.FormatInt(int64(len(p.GroupingSets)), 10))
|
||||
str.WriteString(", groupingID:")
|
||||
str.WriteString(p.GroupingIDCol.StringWithCtx(ectx, perrors.RedactLogDisable))
|
||||
str.WriteString(", ")
|
||||
if p.GroupingIDCol != nil {
|
||||
str.WriteString(", groupingID:")
|
||||
str.WriteString(p.GroupingIDCol.StringWithCtx(ectx, perrors.RedactLogDisable))
|
||||
str.WriteString(", ")
|
||||
}
|
||||
str.WriteString(p.GroupingSets.StringWithCtx(ectx, perrors.RedactLogDisable))
|
||||
return str.String()
|
||||
}
|
||||
|
||||
@ -396,3 +396,10 @@ func (p *LogicalExpand) GenerateGroupingIDIncrementModeNumericSet(oneSetOffset i
|
||||
// {0,1,2}. This grouping id set is returned back as this grouping function's specified meta when rewriting the grouping function,
|
||||
// and the evaluating logic is quite simple as IN compare.
|
||||
}
|
||||
|
||||
// BuildKeyInfo implements base.LogicalPlan interface.
|
||||
func (*LogicalExpand) BuildKeyInfo(selfSchema *expression.Schema, _ []*expression.Schema) {
|
||||
// since LogicalExpand is a logical operator which will split the rows out, duplicated rows may exist in the output.
|
||||
selfSchema.SetKeys(nil)
|
||||
selfSchema.SetUniqueKeys(nil)
|
||||
}
|
||||
|
||||
@ -7,10 +7,12 @@ go_test(
|
||||
"hash64_equals_test.go",
|
||||
"logical_mem_table_predicate_extractor_test.go",
|
||||
"logical_operator_test.go",
|
||||
"main_test.go",
|
||||
"plan_execute_test.go",
|
||||
],
|
||||
data = glob(["testdata/**"]),
|
||||
flaky = True,
|
||||
shard_count = 37,
|
||||
shard_count = 38,
|
||||
deps = [
|
||||
"//pkg/domain",
|
||||
"//pkg/expression",
|
||||
@ -31,11 +33,15 @@ go_test(
|
||||
"//pkg/session",
|
||||
"//pkg/session/sessionapi",
|
||||
"//pkg/testkit",
|
||||
"//pkg/testkit/testdata",
|
||||
"//pkg/testkit/testmain",
|
||||
"//pkg/testkit/testsetup",
|
||||
"//pkg/types",
|
||||
"//pkg/util/chunk",
|
||||
"//pkg/util/hint",
|
||||
"//pkg/util/mock",
|
||||
"//pkg/util/set",
|
||||
"@com_github_stretchr_testify//require",
|
||||
"@org_uber_go_goleak//:goleak",
|
||||
],
|
||||
)
|
||||
|
||||
@ -21,6 +21,7 @@ import (
|
||||
"github.com/pingcap/tidb/pkg/parser/ast"
|
||||
"github.com/pingcap/tidb/pkg/planner/core/operator/logicalop"
|
||||
"github.com/pingcap/tidb/pkg/testkit"
|
||||
"github.com/pingcap/tidb/pkg/testkit/testdata"
|
||||
"github.com/pingcap/tidb/pkg/types"
|
||||
"github.com/pingcap/tidb/pkg/util/mock"
|
||||
"github.com/stretchr/testify/require"
|
||||
@ -113,19 +114,19 @@ func TestLogicalProjectionPushDownTopN(t *testing.T) {
|
||||
col16 json DEFAULT NULL,
|
||||
col17 json DEFAULT NULL
|
||||
);`)
|
||||
sql := `explain format='brief' SELECT
|
||||
sql := `explain format='brief' SELECT
|
||||
s.column16 AS column16,
|
||||
s.column17 AS column17
|
||||
FROM
|
||||
(SELECT
|
||||
(SELECT
|
||||
col16 -> '$[].optUid' AS column16,
|
||||
JSON_UNQUOTE(JSON_EXTRACT(col17, '$[0].value')) AS column17
|
||||
FROM
|
||||
(SELECT
|
||||
(SELECT
|
||||
col16,
|
||||
col17
|
||||
FROM table_test) ta24e
|
||||
) AS s
|
||||
) AS s
|
||||
ORDER BY CONVERT(column16 USING GBK) ASC,column17 ASC
|
||||
LIMIT 0,
|
||||
20;`
|
||||
@ -147,3 +148,76 @@ LIMIT 0,
|
||||
" └─Projection 10000.00 cop[tikv] json_extract(test.table_test.col16, $[].optUid)->Column#4, json_unquote(cast(json_extract(test.table_test.col17, $[0].value), var_string(16777216)))->Column#5",
|
||||
" └─TableFullScan 10000.00 cop[tikv] table:table_test keep order:false, stats:pseudo"))
|
||||
}
|
||||
|
||||
func TestLogicalExpandBuildKeyInfo(t *testing.T) {
|
||||
testkit.RunTestUnderCascades(t, func(t *testing.T, testKit *testkit.TestKit, cascades, caller string) {
|
||||
store := testkit.CreateMockStore(t)
|
||||
tk := testkit.NewTestKit(t, store)
|
||||
tk.MustExec("use test;")
|
||||
tk.MustExec("CREATE TABLE `testorg` (\n `org_id` decimal(19,0) NOT NULL,\n `org_code` varchar(100) DEFAULT NULL,\n `org_name` varchar(100) DEFAULT NULL,\n `org_type` varchar(100) DEFAULT NULL,\n PRIMARY KEY (`org_id`) /*T![clustered_index] CLUSTERED */\n) ")
|
||||
tk.MustExec("CREATE TABLE `testpay` (\n `bill_code` varchar(100) NOT NULL,\n `org_id` decimal(19,0) DEFAULT NULL,\n `amt` decimal(15,2) DEFAULT NULL,\n `pay_date` varchar(10) DEFAULT NULL,\n PRIMARY KEY (`bill_code`) /*T![clustered_index] CLUSTERED */\n)")
|
||||
tk.MustExec("CREATE TABLE `testreturn` (\n `bill_code` varchar(100) NOT NULL,\n `org_id` decimal(19,0) DEFAULT NULL,\n `amt` decimal(15,2) DEFAULT NULL,\n `ret_date` varchar(10) DEFAULT NULL,\n PRIMARY KEY (`bill_code`) /*T![clustered_index] CLUSTERED */\n)")
|
||||
tk.MustExec("insert into testorg (org_id,org_code,org_name,org_type) values(1,'ORG0001','部门1','DEPT');" +
|
||||
"insert into testorg (org_id,org_code,org_name,org_type) values(2,'ORG0002','部门2','DEPT');" +
|
||||
"insert into testorg (org_id,org_code,org_name,org_type) values(3,'ORG0003','部门3','DEPT');" +
|
||||
"insert into testorg (org_id,org_code,org_name,org_type) values(4,'ORG0004','部门4','DEPT');" +
|
||||
"insert into testorg (org_id,org_code,org_name,org_type) values(5,'ORG0005','公司1','ORG');" +
|
||||
"insert into testorg (org_id,org_code,org_name,org_type) values(6,'ORG0006','公司2','ORG');" +
|
||||
"insert into testorg (org_id,org_code,org_name,org_type) values(7,'ORG0007','公司3','ORG');")
|
||||
tk.MustExec("insert into testpay (bill_code,org_id,amt,pay_date) values('PAY0001',1,100,'2024-06-01');" +
|
||||
"insert into testpay (bill_code,org_id,amt,pay_date) values('PAY0002',2,200,'2024-06-02');" +
|
||||
"insert into testpay (bill_code,org_id,amt,pay_date) values('PAY0003',3,300,'2024-06-03');" +
|
||||
"insert into testpay (bill_code,org_id,amt,pay_date) values('PAY0004',4,400,'2024-07-01');" +
|
||||
"insert into testpay (bill_code,org_id,amt,pay_date) values('PAY0005',5,500,'2024-07-02');" +
|
||||
"insert into testpay (bill_code,org_id,amt,pay_date) values('PAY0006',6,600,'2024-07-03');")
|
||||
tk.MustExec("insert into testreturn (bill_code,org_id,amt,ret_date) values('RET0001',1,100,'2024-06-01');" +
|
||||
"insert into testreturn (bill_code,org_id,amt,ret_date) values('RET0002',2,200,'2024-06-02');" +
|
||||
"insert into testreturn (bill_code,org_id,amt,ret_date) values('RET0003',3,300,'2024-06-03');" +
|
||||
"insert into testreturn (bill_code,org_id,amt,ret_date) values('RET0004',4,400,'2024-07-01'); ")
|
||||
res := tk.MustQuery("SELECT\n SUM(IFNULL(pay.payamt, 0)) AS payamt," +
|
||||
" SUM(IFNULL(ret.retamt, 0)) AS retamt," +
|
||||
" org.org_type," +
|
||||
" org.org_id," +
|
||||
" org.org_name" +
|
||||
" FROM testorg org" +
|
||||
" LEFT JOIN (" +
|
||||
" SELECT" +
|
||||
" SUM(IFNULL(amt, 0)) AS payamt," +
|
||||
" org_id" +
|
||||
" FROM testpay tp" +
|
||||
" WHERE tp.pay_date BETWEEN '2024-06-01' AND '2024-07-31'" +
|
||||
" GROUP BY org_id" +
|
||||
") pay ON pay.org_id = org.org_id" +
|
||||
" LEFT JOIN (" +
|
||||
" SELECT" +
|
||||
" SUM(IFNULL(amt, 0)) AS retamt," +
|
||||
" org_id" +
|
||||
" FROM testreturn tr" +
|
||||
" WHERE tr.ret_date BETWEEN '2024-06-01' AND '2024-07-31'" +
|
||||
" GROUP BY org_id" +
|
||||
") ret ON ret.org_id = org.org_id" +
|
||||
" GROUP BY org.org_type, org.org_id WITH ROLLUP;")
|
||||
require.Equal(t, len(res.Rows()), 10)
|
||||
res = tk.MustQuery("SELECT * FROM ( SELECT SUM(IFNULL(pay.payamt, 0)) AS payamt, SUM(IFNULL(ret.retamt, 0)) AS retamt, GROUPING(org.org_type) AS grouptype, org.org_type, GROUPING(org.org_id) AS groupid, org.org_id, org.org_name FROM testorg org LEFT JOIN ( SELECT SUM(IFNULL(amt, 0)) AS payamt, org_id FROM testpay tp WHERE tp.pay_date BETWEEN '2024-06-01' AND '2024-07-31' GROUP BY org_id ) pay ON pay.org_id = org.org_id LEFT JOIN ( SELECT SUM(IFNULL(amt, 0)) AS retamt, org_id FROM testreturn tr WHERE tr.ret_date BETWEEN '2024-06-01' AND '2024-07-31' GROUP BY org_id ) ret ON ret.org_id = org.org_id GROUP BY org.org_type, org.org_id WITH ROLLUP ) t WHERE groupid = 1 AND grouptype = 1;\n")
|
||||
require.Equal(t, len(res.Rows()), 1)
|
||||
res = tk.MustQuery("SELECT SUM(IFNULL(pay.payamt, 0)) AS payamt, SUM(IFNULL(ret.retamt, 0)) AS retamt, GROUPING(org.org_type) AS grouptype, org.org_type, GROUPING(org.org_id) AS groupid, org.org_id, org.org_name FROM testorg org LEFT JOIN ( SELECT SUM(IFNULL(amt, 0)) AS payamt, org_id FROM testpay tp WHERE tp.pay_date BETWEEN '2024-06-01' AND '2024-07-31' GROUP BY org_id ) pay ON pay.org_id = org.org_id LEFT JOIN ( SELECT SUM(IFNULL(amt, 0)) AS retamt, org_id FROM testreturn tr WHERE tr.ret_date BETWEEN '2024-06-01' AND '2024-07-31' GROUP BY org_id ) ret ON ret.org_id = org.org_id GROUP BY org.org_type, org.org_id WITH ROLLUP having groupid = 1 AND grouptype = 1;")
|
||||
require.Equal(t, len(res.Rows()), 1)
|
||||
|
||||
// since the plan may differ under different planner mode, recommend to record explain result to json accordingly.
|
||||
var input []string
|
||||
var output []struct {
|
||||
SQL string
|
||||
Plan []string
|
||||
}
|
||||
cascadesData := GetCascadesSuiteData()
|
||||
cascadesData.LoadTestCases(t, &input, &output, cascades, caller)
|
||||
for i, tt := range input {
|
||||
testdata.OnRecord(func() {
|
||||
output[i].SQL = tt
|
||||
output[i].Plan = testdata.ConvertRowsToStrings(tk.MustQuery("explain format=brief " + tt).Rows())
|
||||
})
|
||||
res := tk.MustQuery("explain format=brief " + tt)
|
||||
res.Check(testkit.Rows(output[i].Plan...))
|
||||
}
|
||||
})
|
||||
}
|
||||
|
||||
@ -0,0 +1,53 @@
|
||||
// Copyright 2025 PingCAP, Inc.
|
||||
//
|
||||
// Licensed under the Apache License, Version 2.0 (the "License");
|
||||
// you may not use this file except in compliance with the License.
|
||||
// You may obtain a copy of the License at
|
||||
//
|
||||
// http://www.apache.org/licenses/LICENSE-2.0
|
||||
//
|
||||
// Unless required by applicable law or agreed to in writing, software
|
||||
// distributed under the License is distributed on an "AS IS" BASIS,
|
||||
// WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
|
||||
// See the License for the specific language governing permissions and
|
||||
// limitations under the License.
|
||||
|
||||
package logicalop
|
||||
|
||||
import (
|
||||
"flag"
|
||||
"testing"
|
||||
|
||||
"github.com/pingcap/tidb/pkg/testkit/testdata"
|
||||
"github.com/pingcap/tidb/pkg/testkit/testmain"
|
||||
"github.com/pingcap/tidb/pkg/testkit/testsetup"
|
||||
"go.uber.org/goleak"
|
||||
)
|
||||
|
||||
var testDataMap = make(testdata.BookKeeper)
|
||||
|
||||
func TestMain(m *testing.M) {
|
||||
testsetup.SetupForCommonTest()
|
||||
flag.Parse()
|
||||
testDataMap.LoadTestSuiteData("testdata", "cascades_suite", true)
|
||||
opts := []goleak.Option{
|
||||
goleak.IgnoreTopFunction("github.com/golang/glog.(*fileSink).flushDaemon"),
|
||||
goleak.IgnoreTopFunction("github.com/bazelbuild/rules_go/go/tools/bzltestutil.RegisterTimeoutHandler.func1"),
|
||||
goleak.IgnoreTopFunction("github.com/lestrrat-go/httprc.runFetchWorker"),
|
||||
goleak.IgnoreTopFunction("go.etcd.io/etcd/client/pkg/v3/logutil.(*MergeLogger).outputLoop"),
|
||||
goleak.IgnoreTopFunction("gopkg.in/natefinch/lumberjack%2ev2.(*Logger).millRun"),
|
||||
goleak.IgnoreTopFunction("github.com/tikv/client-go/v2/txnkv/transaction.keepAlive"),
|
||||
goleak.IgnoreTopFunction("go.opencensus.io/stats/view.(*worker).start"),
|
||||
}
|
||||
|
||||
callback := func(i int) int {
|
||||
testDataMap.GenerateOutputIfNeeded()
|
||||
return i
|
||||
}
|
||||
|
||||
goleak.VerifyTestMain(testmain.WrapTestingM(m, callback), opts...)
|
||||
}
|
||||
|
||||
func GetCascadesSuiteData() testdata.TestData {
|
||||
return testDataMap["cascades_suite"]
|
||||
}
|
||||
9
pkg/planner/core/operator/logicalop/logicalop_test/testdata/cascades_suite_in.json
vendored
Normal file
9
pkg/planner/core/operator/logicalop/logicalop_test/testdata/cascades_suite_in.json
vendored
Normal file
@ -0,0 +1,9 @@
|
||||
[
|
||||
{
|
||||
"name": "TestLogicalExpandBuildKeyInfo",
|
||||
"cases": [
|
||||
"SELECT * FROM ( SELECT SUM(IFNULL(pay.payamt, 0)) AS payamt, SUM(IFNULL(ret.retamt, 0)) AS retamt, GROUPING(org.org_type) AS grouptype, org.org_type, GROUPING(org.org_id) AS groupid, org.org_id, org.org_name FROM testorg org LEFT JOIN ( SELECT SUM(IFNULL(amt, 0)) AS payamt, org_id FROM testpay tp WHERE tp.pay_date BETWEEN '2024-06-01' AND '2024-07-31' GROUP BY org_id ) pay ON pay.org_id = org.org_id LEFT JOIN ( SELECT SUM(IFNULL(amt, 0)) AS retamt, org_id FROM testreturn tr WHERE tr.ret_date BETWEEN '2024-06-01' AND '2024-07-31' GROUP BY org_id ) ret ON ret.org_id = org.org_id GROUP BY org.org_type, org.org_id WITH ROLLUP ) t WHERE groupid = 1 AND grouptype = 1;",
|
||||
"SELECT SUM(IFNULL(pay.payamt, 0)) AS payamt, SUM(IFNULL(ret.retamt, 0)) AS retamt, GROUPING(org.org_type) AS grouptype, org.org_type, GROUPING(org.org_id) AS groupid, org.org_id, org.org_name FROM testorg org LEFT JOIN ( SELECT SUM(IFNULL(amt, 0)) AS payamt, org_id FROM testpay tp WHERE tp.pay_date BETWEEN '2024-06-01' AND '2024-07-31' GROUP BY org_id ) pay ON pay.org_id = org.org_id LEFT JOIN ( SELECT SUM(IFNULL(amt, 0)) AS retamt, org_id FROM testreturn tr WHERE tr.ret_date BETWEEN '2024-06-01' AND '2024-07-31' GROUP BY org_id ) ret ON ret.org_id = org.org_id GROUP BY org.org_type, org.org_id WITH ROLLUP having groupid = 1 AND grouptype = 1;"
|
||||
]
|
||||
}
|
||||
]
|
||||
57
pkg/planner/core/operator/logicalop/logicalop_test/testdata/cascades_suite_out.json
vendored
Normal file
57
pkg/planner/core/operator/logicalop/logicalop_test/testdata/cascades_suite_out.json
vendored
Normal file
@ -0,0 +1,57 @@
|
||||
[
|
||||
{
|
||||
"Name": "TestLogicalExpandBuildKeyInfo",
|
||||
"Cases": [
|
||||
{
|
||||
"SQL": "SELECT * FROM ( SELECT SUM(IFNULL(pay.payamt, 0)) AS payamt, SUM(IFNULL(ret.retamt, 0)) AS retamt, GROUPING(org.org_type) AS grouptype, org.org_type, GROUPING(org.org_id) AS groupid, org.org_id, org.org_name FROM testorg org LEFT JOIN ( SELECT SUM(IFNULL(amt, 0)) AS payamt, org_id FROM testpay tp WHERE tp.pay_date BETWEEN '2024-06-01' AND '2024-07-31' GROUP BY org_id ) pay ON pay.org_id = org.org_id LEFT JOIN ( SELECT SUM(IFNULL(amt, 0)) AS retamt, org_id FROM testreturn tr WHERE tr.ret_date BETWEEN '2024-06-01' AND '2024-07-31' GROUP BY org_id ) ret ON ret.org_id = org.org_id GROUP BY org.org_type, org.org_id WITH ROLLUP ) t WHERE groupid = 1 AND grouptype = 1;",
|
||||
"Plan": [
|
||||
"Projection 6400.00 root Column#18->Column#22, Column#19->Column#23, grouping(gid)->Column#24, Column#15->Column#25, grouping(gid)->Column#26, Column#16->Column#27, test.testorg.org_name",
|
||||
"└─HashAgg 6400.00 root group by:Column#45, Column#46, Column#47, funcs:sum(Column#42)->Column#18, funcs:sum(Column#43)->Column#19, funcs:firstrow(Column#44)->test.testorg.org_name, funcs:firstrow(Column#45)->Column#15, funcs:firstrow(Column#46)->Column#16, funcs:firstrow(Column#47)->gid",
|
||||
" └─Projection 8000.00 root ifnull(Column#9, 0.00)->Column#42, ifnull(Column#14, 0.00)->Column#43, test.testorg.org_name->Column#44, Column#15->Column#45, Column#16->Column#46, gid->Column#47",
|
||||
" └─Selection 8000.00 root eq(grouping(gid), 1), eq(grouping(gid), 1)",
|
||||
" └─Expand 10000.00 root level-projection:[test.testorg.org_name, Column#9, Column#14, <nil>->Column#15, <nil>->Column#16, 0->gid],[test.testorg.org_name, Column#9, Column#14, Column#15, <nil>->Column#16, 1->gid],[test.testorg.org_name, Column#9, Column#14, Column#15, Column#16, 3->gid]; schema: [test.testorg.org_name,Column#9,Column#14,Column#15,Column#16,gid]",
|
||||
" └─Projection 10000.00 root test.testorg.org_name, Column#9, Column#14, test.testorg.org_type->Column#15, test.testorg.org_id->Column#16",
|
||||
" └─HashJoin 10000.00 root left outer join, left side:HashJoin, equal:[eq(test.testorg.org_id, test.testreturn.org_id)]",
|
||||
" ├─HashAgg(Build) 199.80 root group by:test.testreturn.org_id, funcs:sum(Column#40)->Column#14, funcs:firstrow(test.testreturn.org_id)->test.testreturn.org_id",
|
||||
" │ └─TableReader 199.80 root data:HashAgg",
|
||||
" │ └─HashAgg 199.80 cop[tikv] group by:test.testreturn.org_id, funcs:sum(ifnull(test.testreturn.amt, 0.00))->Column#40",
|
||||
" │ └─Selection 249.75 cop[tikv] ge(test.testreturn.ret_date, \"2024-06-01\"), le(test.testreturn.ret_date, \"2024-07-31\"), not(isnull(test.testreturn.org_id))",
|
||||
" │ └─TableFullScan 10000.00 cop[tikv] table:tr keep order:false, stats:pseudo",
|
||||
" └─HashJoin(Probe) 10000.00 root left outer join, left side:TableReader, equal:[eq(test.testorg.org_id, test.testpay.org_id)]",
|
||||
" ├─HashAgg(Build) 199.80 root group by:test.testpay.org_id, funcs:sum(Column#38)->Column#9, funcs:firstrow(test.testpay.org_id)->test.testpay.org_id",
|
||||
" │ └─TableReader 199.80 root data:HashAgg",
|
||||
" │ └─HashAgg 199.80 cop[tikv] group by:test.testpay.org_id, funcs:sum(ifnull(test.testpay.amt, 0.00))->Column#38",
|
||||
" │ └─Selection 249.75 cop[tikv] ge(test.testpay.pay_date, \"2024-06-01\"), le(test.testpay.pay_date, \"2024-07-31\"), not(isnull(test.testpay.org_id))",
|
||||
" │ └─TableFullScan 10000.00 cop[tikv] table:tp keep order:false, stats:pseudo",
|
||||
" └─TableReader(Probe) 10000.00 root data:TableFullScan",
|
||||
" └─TableFullScan 10000.00 cop[tikv] table:org keep order:false, stats:pseudo"
|
||||
]
|
||||
},
|
||||
{
|
||||
"SQL": "SELECT SUM(IFNULL(pay.payamt, 0)) AS payamt, SUM(IFNULL(ret.retamt, 0)) AS retamt, GROUPING(org.org_type) AS grouptype, org.org_type, GROUPING(org.org_id) AS groupid, org.org_id, org.org_name FROM testorg org LEFT JOIN ( SELECT SUM(IFNULL(amt, 0)) AS payamt, org_id FROM testpay tp WHERE tp.pay_date BETWEEN '2024-06-01' AND '2024-07-31' GROUP BY org_id ) pay ON pay.org_id = org.org_id LEFT JOIN ( SELECT SUM(IFNULL(amt, 0)) AS retamt, org_id FROM testreturn tr WHERE tr.ret_date BETWEEN '2024-06-01' AND '2024-07-31' GROUP BY org_id ) ret ON ret.org_id = org.org_id GROUP BY org.org_type, org.org_id WITH ROLLUP having groupid = 1 AND grouptype = 1;",
|
||||
"Plan": [
|
||||
"Projection 6400.00 root Column#18->Column#22, Column#19->Column#23, grouping(gid)->Column#24, Column#15->Column#25, grouping(gid)->Column#26, Column#16->Column#27, test.testorg.org_name",
|
||||
"└─HashAgg 6400.00 root group by:Column#38, Column#39, Column#40, funcs:sum(Column#35)->Column#18, funcs:sum(Column#36)->Column#19, funcs:firstrow(Column#37)->test.testorg.org_name, funcs:firstrow(Column#38)->Column#15, funcs:firstrow(Column#39)->Column#16, funcs:firstrow(Column#40)->gid",
|
||||
" └─Projection 8000.00 root ifnull(Column#9, 0.00)->Column#35, ifnull(Column#14, 0.00)->Column#36, test.testorg.org_name->Column#37, Column#15->Column#38, Column#16->Column#39, gid->Column#40",
|
||||
" └─Selection 8000.00 root eq(grouping(gid), 1), eq(grouping(gid), 1)",
|
||||
" └─Expand 10000.00 root level-projection:[test.testorg.org_name, Column#9, Column#14, <nil>->Column#15, <nil>->Column#16, 0->gid],[test.testorg.org_name, Column#9, Column#14, Column#15, <nil>->Column#16, 1->gid],[test.testorg.org_name, Column#9, Column#14, Column#15, Column#16, 3->gid]; schema: [test.testorg.org_name,Column#9,Column#14,Column#15,Column#16,gid]",
|
||||
" └─Projection 10000.00 root test.testorg.org_name, Column#9, Column#14, test.testorg.org_type->Column#15, test.testorg.org_id->Column#16",
|
||||
" └─HashJoin 10000.00 root left outer join, left side:HashJoin, equal:[eq(test.testorg.org_id, test.testreturn.org_id)]",
|
||||
" ├─HashAgg(Build) 199.80 root group by:test.testreturn.org_id, funcs:sum(Column#33)->Column#14, funcs:firstrow(test.testreturn.org_id)->test.testreturn.org_id",
|
||||
" │ └─TableReader 199.80 root data:HashAgg",
|
||||
" │ └─HashAgg 199.80 cop[tikv] group by:test.testreturn.org_id, funcs:sum(ifnull(test.testreturn.amt, 0.00))->Column#33",
|
||||
" │ └─Selection 249.75 cop[tikv] ge(test.testreturn.ret_date, \"2024-06-01\"), le(test.testreturn.ret_date, \"2024-07-31\"), not(isnull(test.testreturn.org_id))",
|
||||
" │ └─TableFullScan 10000.00 cop[tikv] table:tr keep order:false, stats:pseudo",
|
||||
" └─HashJoin(Probe) 10000.00 root left outer join, left side:TableReader, equal:[eq(test.testorg.org_id, test.testpay.org_id)]",
|
||||
" ├─HashAgg(Build) 199.80 root group by:test.testpay.org_id, funcs:sum(Column#31)->Column#9, funcs:firstrow(test.testpay.org_id)->test.testpay.org_id",
|
||||
" │ └─TableReader 199.80 root data:HashAgg",
|
||||
" │ └─HashAgg 199.80 cop[tikv] group by:test.testpay.org_id, funcs:sum(ifnull(test.testpay.amt, 0.00))->Column#31",
|
||||
" │ └─Selection 249.75 cop[tikv] ge(test.testpay.pay_date, \"2024-06-01\"), le(test.testpay.pay_date, \"2024-07-31\"), not(isnull(test.testpay.org_id))",
|
||||
" │ └─TableFullScan 10000.00 cop[tikv] table:tp keep order:false, stats:pseudo",
|
||||
" └─TableReader(Probe) 10000.00 root data:TableFullScan",
|
||||
" └─TableFullScan 10000.00 cop[tikv] table:org keep order:false, stats:pseudo"
|
||||
]
|
||||
}
|
||||
]
|
||||
}
|
||||
]
|
||||
57
pkg/planner/core/operator/logicalop/logicalop_test/testdata/cascades_suite_xut.json
vendored
Normal file
57
pkg/planner/core/operator/logicalop/logicalop_test/testdata/cascades_suite_xut.json
vendored
Normal file
@ -0,0 +1,57 @@
|
||||
[
|
||||
{
|
||||
"Name": "TestLogicalExpandBuildKeyInfo",
|
||||
"Cases": [
|
||||
{
|
||||
"SQL": "SELECT * FROM ( SELECT SUM(IFNULL(pay.payamt, 0)) AS payamt, SUM(IFNULL(ret.retamt, 0)) AS retamt, GROUPING(org.org_type) AS grouptype, org.org_type, GROUPING(org.org_id) AS groupid, org.org_id, org.org_name FROM testorg org LEFT JOIN ( SELECT SUM(IFNULL(amt, 0)) AS payamt, org_id FROM testpay tp WHERE tp.pay_date BETWEEN '2024-06-01' AND '2024-07-31' GROUP BY org_id ) pay ON pay.org_id = org.org_id LEFT JOIN ( SELECT SUM(IFNULL(amt, 0)) AS retamt, org_id FROM testreturn tr WHERE tr.ret_date BETWEEN '2024-06-01' AND '2024-07-31' GROUP BY org_id ) ret ON ret.org_id = org.org_id GROUP BY org.org_type, org.org_id WITH ROLLUP ) t WHERE groupid = 1 AND grouptype = 1;",
|
||||
"Plan": [
|
||||
"Projection 6400.00 root Column#18->Column#22, Column#19->Column#23, grouping(gid)->Column#24, Column#15->Column#25, grouping(gid)->Column#26, Column#16->Column#27, test.testorg.org_name",
|
||||
"└─HashAgg 6400.00 root group by:Column#45, Column#46, Column#47, funcs:sum(Column#42)->Column#18, funcs:sum(Column#43)->Column#19, funcs:firstrow(Column#44)->test.testorg.org_name, funcs:firstrow(Column#45)->Column#15, funcs:firstrow(Column#46)->Column#16, funcs:firstrow(Column#47)->gid",
|
||||
" └─Projection 8000.00 root ifnull(Column#9, 0.00)->Column#42, ifnull(Column#14, 0.00)->Column#43, test.testorg.org_name->Column#44, Column#15->Column#45, Column#16->Column#46, gid->Column#47",
|
||||
" └─Selection 8000.00 root eq(grouping(gid), 1), eq(grouping(gid), 1)",
|
||||
" └─Expand 10000.00 root level-projection:[test.testorg.org_name, Column#9, Column#14, <nil>->Column#15, <nil>->Column#16, 0->gid],[test.testorg.org_name, Column#9, Column#14, Column#15, <nil>->Column#16, 1->gid],[test.testorg.org_name, Column#9, Column#14, Column#15, Column#16, 3->gid]; schema: [test.testorg.org_name,Column#9,Column#14,Column#15,Column#16,gid]",
|
||||
" └─Projection 10000.00 root test.testorg.org_name, Column#9, Column#14, test.testorg.org_type->Column#15, test.testorg.org_id->Column#16",
|
||||
" └─HashJoin 10000.00 root left outer join, left side:HashJoin, equal:[eq(test.testorg.org_id, test.testreturn.org_id)]",
|
||||
" ├─HashAgg(Build) 199.80 root group by:test.testreturn.org_id, funcs:sum(Column#40)->Column#14, funcs:firstrow(test.testreturn.org_id)->test.testreturn.org_id",
|
||||
" │ └─TableReader 199.80 root data:HashAgg",
|
||||
" │ └─HashAgg 199.80 cop[tikv] group by:test.testreturn.org_id, funcs:sum(ifnull(test.testreturn.amt, 0.00))->Column#40",
|
||||
" │ └─Selection 249.75 cop[tikv] ge(test.testreturn.ret_date, \"2024-06-01\"), le(test.testreturn.ret_date, \"2024-07-31\"), not(isnull(test.testreturn.org_id))",
|
||||
" │ └─TableFullScan 10000.00 cop[tikv] table:tr keep order:false, stats:pseudo",
|
||||
" └─HashJoin(Probe) 10000.00 root left outer join, left side:TableReader, equal:[eq(test.testorg.org_id, test.testpay.org_id)]",
|
||||
" ├─HashAgg(Build) 199.80 root group by:test.testpay.org_id, funcs:sum(Column#38)->Column#9, funcs:firstrow(test.testpay.org_id)->test.testpay.org_id",
|
||||
" │ └─TableReader 199.80 root data:HashAgg",
|
||||
" │ └─HashAgg 199.80 cop[tikv] group by:test.testpay.org_id, funcs:sum(ifnull(test.testpay.amt, 0.00))->Column#38",
|
||||
" │ └─Selection 249.75 cop[tikv] ge(test.testpay.pay_date, \"2024-06-01\"), le(test.testpay.pay_date, \"2024-07-31\"), not(isnull(test.testpay.org_id))",
|
||||
" │ └─TableFullScan 10000.00 cop[tikv] table:tp keep order:false, stats:pseudo",
|
||||
" └─TableReader(Probe) 10000.00 root data:TableFullScan",
|
||||
" └─TableFullScan 10000.00 cop[tikv] table:org keep order:false, stats:pseudo"
|
||||
]
|
||||
},
|
||||
{
|
||||
"SQL": "SELECT SUM(IFNULL(pay.payamt, 0)) AS payamt, SUM(IFNULL(ret.retamt, 0)) AS retamt, GROUPING(org.org_type) AS grouptype, org.org_type, GROUPING(org.org_id) AS groupid, org.org_id, org.org_name FROM testorg org LEFT JOIN ( SELECT SUM(IFNULL(amt, 0)) AS payamt, org_id FROM testpay tp WHERE tp.pay_date BETWEEN '2024-06-01' AND '2024-07-31' GROUP BY org_id ) pay ON pay.org_id = org.org_id LEFT JOIN ( SELECT SUM(IFNULL(amt, 0)) AS retamt, org_id FROM testreturn tr WHERE tr.ret_date BETWEEN '2024-06-01' AND '2024-07-31' GROUP BY org_id ) ret ON ret.org_id = org.org_id GROUP BY org.org_type, org.org_id WITH ROLLUP having groupid = 1 AND grouptype = 1;",
|
||||
"Plan": [
|
||||
"Projection 6400.00 root Column#18->Column#22, Column#19->Column#23, grouping(gid)->Column#24, Column#15->Column#25, grouping(gid)->Column#26, Column#16->Column#27, test.testorg.org_name",
|
||||
"└─HashAgg 6400.00 root group by:Column#38, Column#39, Column#40, funcs:sum(Column#35)->Column#18, funcs:sum(Column#36)->Column#19, funcs:firstrow(Column#37)->test.testorg.org_name, funcs:firstrow(Column#38)->Column#15, funcs:firstrow(Column#39)->Column#16, funcs:firstrow(Column#40)->gid",
|
||||
" └─Projection 8000.00 root ifnull(Column#9, 0.00)->Column#35, ifnull(Column#14, 0.00)->Column#36, test.testorg.org_name->Column#37, Column#15->Column#38, Column#16->Column#39, gid->Column#40",
|
||||
" └─Selection 8000.00 root eq(grouping(gid), 1), eq(grouping(gid), 1)",
|
||||
" └─Expand 10000.00 root level-projection:[test.testorg.org_name, Column#9, Column#14, <nil>->Column#15, <nil>->Column#16, 0->gid],[test.testorg.org_name, Column#9, Column#14, Column#15, <nil>->Column#16, 1->gid],[test.testorg.org_name, Column#9, Column#14, Column#15, Column#16, 3->gid]; schema: [test.testorg.org_name,Column#9,Column#14,Column#15,Column#16,gid]",
|
||||
" └─Projection 10000.00 root test.testorg.org_name, Column#9, Column#14, test.testorg.org_type->Column#15, test.testorg.org_id->Column#16",
|
||||
" └─HashJoin 10000.00 root left outer join, left side:HashJoin, equal:[eq(test.testorg.org_id, test.testreturn.org_id)]",
|
||||
" ├─HashAgg(Build) 199.80 root group by:test.testreturn.org_id, funcs:sum(Column#33)->Column#14, funcs:firstrow(test.testreturn.org_id)->test.testreturn.org_id",
|
||||
" │ └─TableReader 199.80 root data:HashAgg",
|
||||
" │ └─HashAgg 199.80 cop[tikv] group by:test.testreturn.org_id, funcs:sum(ifnull(test.testreturn.amt, 0.00))->Column#33",
|
||||
" │ └─Selection 249.75 cop[tikv] ge(test.testreturn.ret_date, \"2024-06-01\"), le(test.testreturn.ret_date, \"2024-07-31\"), not(isnull(test.testreturn.org_id))",
|
||||
" │ └─TableFullScan 10000.00 cop[tikv] table:tr keep order:false, stats:pseudo",
|
||||
" └─HashJoin(Probe) 10000.00 root left outer join, left side:TableReader, equal:[eq(test.testorg.org_id, test.testpay.org_id)]",
|
||||
" ├─HashAgg(Build) 199.80 root group by:test.testpay.org_id, funcs:sum(Column#31)->Column#9, funcs:firstrow(test.testpay.org_id)->test.testpay.org_id",
|
||||
" │ └─TableReader 199.80 root data:HashAgg",
|
||||
" │ └─HashAgg 199.80 cop[tikv] group by:test.testpay.org_id, funcs:sum(ifnull(test.testpay.amt, 0.00))->Column#31",
|
||||
" │ └─Selection 249.75 cop[tikv] ge(test.testpay.pay_date, \"2024-06-01\"), le(test.testpay.pay_date, \"2024-07-31\"), not(isnull(test.testpay.org_id))",
|
||||
" │ └─TableFullScan 10000.00 cop[tikv] table:tp keep order:false, stats:pseudo",
|
||||
" └─TableReader(Probe) 10000.00 root data:TableFullScan",
|
||||
" └─TableFullScan 10000.00 cop[tikv] table:org keep order:false, stats:pseudo"
|
||||
]
|
||||
}
|
||||
]
|
||||
}
|
||||
]
|
||||
Reference in New Issue
Block a user