Skip to content

Commit

Permalink
don't push down literal values from projection
Browse files Browse the repository at this point in the history
Signed-off-by: Andres Taylor <[email protected]>
  • Loading branch information
systay committed Aug 8, 2024
1 parent 8dba6cf commit dbd11c7
Show file tree
Hide file tree
Showing 8 changed files with 245 additions and 192 deletions.
99 changes: 9 additions & 90 deletions go/test/endtoend/vtgate/vitess_tester/cte/queries.test
Original file line number Diff line number Diff line change
Expand Up @@ -82,105 +82,24 @@ SELECT *
FROM emp_cte
LIMIT 5;

# Recursive CTE with DISTINCT to avoid duplicates
WITH RECURSIVE distinct_emp_cte AS (SELECT DISTINCT id, name, manager_id
FROM employees
WHERE manager_id IS NULL
UNION ALL
SELECT DISTINCT e.id, e.name, e.manager_id
FROM employees e
INNER JOIN distinct_emp_cte cte ON e.manager_id = cte.id)
SELECT *
FROM distinct_emp_cte;

# Recursive CTE with aggregation outside the CTE
WITH RECURSIVE emp_cte AS (SELECT id, name, manager_id
FROM employees
WHERE manager_id IS NULL
UNION ALL
SELECT e.id, e.name, e.manager_id
FROM employees e
INNER JOIN emp_cte cte ON e.manager_id = cte.id)
SELECT manager_id, COUNT(*) AS employee_count
FROM emp_cte
GROUP BY manager_id;

# Recursive CTE using literal values and joined with a real table on the outside
WITH RECURSIVE literal_cte AS (SELECT 1 AS id, 'Root' AS name, NULL AS manager_id
WITH RECURSIVE literal_cte AS (SELECT 1 AS id, 100 AS value, NULL AS manager_id
UNION ALL
SELECT id + 1, CONCAT('Node', id + 1), id
SELECT id + 1, value * 2, id
FROM literal_cte
WHERE id < 5)
SELECT l.id, l.name, l.manager_id, e.name AS employee_name
SELECT l.id, l.value, l.manager_id, e.name AS employee_name
FROM literal_cte l
LEFT JOIN employees e ON l.id = e.id;

# Recursive CTE for generating a series of numbers
WITH RECURSIVE
number_series AS (SELECT 1 AS n
UNION ALL
SELECT n + 1
FROM number_series
WHERE n < 5),

# Recursive CTE that uses the number series
number_names AS (SELECT n, CONCAT('Number', n) AS name
FROM number_series)
SELECT *
FROM number_names;

# Recursive CTE for generating a series of numbers
WITH RECURSIVE
number_series AS (SELECT 1 AS n
UNION ALL
SELECT n + 1
FROM number_series
WHERE n < 5),

# Independent recursive CTE for employees hierarchy
employee_hierarchy AS (SELECT id, name, manager_id
FROM employees
WHERE manager_id IS NULL
UNION ALL
SELECT e.id, e.name, e.manager_id
FROM employees e
INNER JOIN employee_hierarchy eh ON e.manager_id = eh.id)

# Joining results from both CTEs
SELECT ns.n, ns.n AS number, eh.id, eh.name, eh.manager_id
FROM number_series ns
JOIN employee_hierarchy eh ON ns.n = eh.id;

# Recursive CTE for generating a series of numbers
WITH RECURSIVE
number_series AS (SELECT 1 AS n
UNION ALL
SELECT n + 1
FROM number_series
WHERE n < 5),

# Independent recursive CTE for employees hierarchy
employee_hierarchy AS (SELECT id, name, manager_id
# Recursive CTE with aggregation outside the CTE
WITH RECURSIVE emp_cte AS (SELECT id, name, manager_id
FROM employees
WHERE manager_id IS NULL
UNION ALL
SELECT e.id, e.name, e.manager_id
FROM employees e
INNER JOIN employee_hierarchy eh ON e.manager_id = eh.id)

# Union results from both CTEs
SELECT n AS id, CONCAT('Number', n) AS name, NULL AS manager_id
FROM number_series
UNION
SELECT id, name, manager_id
FROM employee_hierarchy;

WITH RECURSIVE emp_cte AS (SELECT id, 1 AS level
FROM employees
WHERE manager_id IS NULL
UNION ALL
SELECT e.id, cte.level + 1
FROM employees e
JOIN emp_cte cte ON e.manager_id = cte.id)
SELECT *
FROM emp_cte;
INNER JOIN emp_cte cte ON e.manager_id = cte.id)
SELECT manager_id, COUNT(*) AS employee_count
FROM emp_cte
GROUP BY manager_id;
12 changes: 12 additions & 0 deletions go/vt/vtgate/planbuilder/operators/expressions.go
Original file line number Diff line number Diff line change
Expand Up @@ -59,3 +59,15 @@ func breakExpressionInLHSandRHS(
col.Original = expr
return
}

// nothingNeedsFetching will return true if all the nodes in the expression are constant
func nothingNeedsFetching(ctx *plancontext.PlanningContext, expr sqlparser.Expr) (constant bool) {
constant = true
_ = sqlparser.Walk(func(node sqlparser.SQLNode) (kontinue bool, err error) {
if mustFetchFromInput(ctx, node) {
constant = false
}
return true, nil
}, expr)
return
}
2 changes: 1 addition & 1 deletion go/vt/vtgate/planbuilder/operators/phases.go
Original file line number Diff line number Diff line change
Expand Up @@ -290,7 +290,7 @@ func addLiteralGroupingToRHS(in *ApplyJoin) (Operator, *ApplyResult) {
return nil
}
if len(aggr.Grouping) == 0 {
gb := sqlparser.NewIntLiteral(".0")
gb := sqlparser.NewFloatLiteral(".0")
aggr.Grouping = append(aggr.Grouping, NewGroupBy(gb))
}
return nil
Expand Down
14 changes: 12 additions & 2 deletions go/vt/vtgate/planbuilder/operators/projection.go
Original file line number Diff line number Diff line change
Expand Up @@ -383,8 +383,18 @@ func (p *Projection) addColumn(
return p.addProjExpr(pe)
}

// we need to push down this column to our input
inputOffset := p.Source.AddColumn(ctx, true, addToGroupBy, ae)
var inputOffset int
if nothingNeedsFetching(ctx, expr) {
// if we don't need to fetch anything, we could just evaluate it in the projection
// we still check if it's there - if it is, we can, we should use it
inputOffset = p.Source.FindCol(ctx, expr, false)
if inputOffset < 0 {
return p.addProjExpr(pe)
}
} else {
// we need to push down this column to our input
inputOffset = p.Source.AddColumn(ctx, true, addToGroupBy, ae)
}

pe.Info = Offset(inputOffset) // since we already know the offset, let's save the information
return p.addProjExpr(pe)
Expand Down
66 changes: 41 additions & 25 deletions go/vt/vtgate/planbuilder/testdata/aggr_cases.json
Original file line number Diff line number Diff line change
Expand Up @@ -3621,8 +3621,10 @@
"Aggregates": "count_star(0) AS count(*)",
"Inputs": [
{
"OperatorType": "SimpleProjection",
"Columns": "3",
"OperatorType": "Projection",
"Expressions": [
"1 as 1"
],
"Inputs": [
{
"OperatorType": "Limit",
Expand All @@ -3635,8 +3637,8 @@
"Name": "user",
"Sharded": true
},
"FieldQuery": "select x.phone, x.id, x.city, 1 from (select phone, id, city from `user` where 1 != 1) as x where 1 != 1",
"Query": "select x.phone, x.id, x.city, 1 from (select phone, id, city from `user` where id > 12) as x limit 10",
"FieldQuery": "select 1 from (select phone, id, city from `user` where 1 != 1) as x where 1 != 1",
"Query": "select 1 from (select phone, id, city from `user` where id > 12) as x limit 10",
"Table": "`user`"
}
]
Expand Down Expand Up @@ -3734,8 +3736,12 @@
"ResultColumns": 2,
"Inputs": [
{
"OperatorType": "SimpleProjection",
"Columns": "1,2,3",
"OperatorType": "Projection",
"Expressions": [
":1 as val1",
"1 as 1",
":2 as weight_string(x.val1)"
],
"Inputs": [
{
"OperatorType": "Limit",
Expand All @@ -3748,9 +3754,9 @@
"Name": "user",
"Sharded": true
},
"FieldQuery": "select x.id, x.val1, 1, weight_string(x.val1) from (select id, val1 from `user` where 1 != 1) as x where 1 != 1",
"OrderBy": "(1|3) ASC",
"Query": "select x.id, x.val1, 1, weight_string(x.val1) from (select id, val1 from `user` where val2 < 4) as x order by x.val1 asc limit 2",
"FieldQuery": "select x.id, x.val1, weight_string(x.val1) from (select id, val1 from `user` where 1 != 1) as x where 1 != 1",
"OrderBy": "(1|2) ASC",
"Query": "select x.id, x.val1, weight_string(x.val1) from (select id, val1 from `user` where val2 < 4) as x order by x.val1 asc limit 2",
"Table": "`user`"
}
]
Expand Down Expand Up @@ -6107,15 +6113,18 @@
"ResultColumns": 1,
"Inputs": [
{
"OperatorType": "SimpleProjection",
"Columns": "2,1",
"OperatorType": "Projection",
"Expressions": [
"1 as 1",
"0 as .0"
],
"Inputs": [
{
"OperatorType": "Aggregate",
"Variant": "Ordered",
"Aggregates": "sum_count_star(0) AS count(*), any_value(2)",
"Aggregates": "sum_count_star(0) AS count(*)",
"GroupBy": "1",
"ResultColumns": 3,
"ResultColumns": 1,
"Inputs": [
{
"OperatorType": "Route",
Expand All @@ -6124,8 +6133,8 @@
"Name": "user",
"Sharded": true
},
"FieldQuery": "select count(*), .0, 1 from `user` where 1 != 1 group by .0",
"Query": "select count(*), .0, 1 from `user` group by .0",
"FieldQuery": "select count(*), .0 from `user` where 1 != 1 group by .0",
"Query": "select count(*), .0 from `user` group by .0",
"Table": "`user`"
}
]
Expand Down Expand Up @@ -6703,13 +6712,18 @@
"ResultColumns": 3,
"Inputs": [
{
"OperatorType": "SimpleProjection",
"Columns": "2,0,1,3",
"OperatorType": "Projection",
"Expressions": [
"1 as 1",
":0 as col",
":1 as bar",
":2 as weight_string(ue.bar)"
],
"Inputs": [
{
"OperatorType": "Sort",
"Variant": "Memory",
"OrderBy": "0 ASC, (1|3) ASC",
"OrderBy": "0 ASC, (1|2) ASC",
"Inputs": [
{
"OperatorType": "Limit",
Expand All @@ -6722,8 +6736,8 @@
"Name": "user",
"Sharded": true
},
"FieldQuery": "select ue.col, ue.bar, 1, weight_string(ue.bar) from (select col, bar from user_extra where 1 != 1) as ue where 1 != 1",
"Query": "select ue.col, ue.bar, 1, weight_string(ue.bar) from (select col, bar from user_extra) as ue limit 10",
"FieldQuery": "select ue.col, ue.bar, weight_string(ue.bar) from (select col, bar from user_extra where 1 != 1) as ue where 1 != 1",
"Query": "select ue.col, ue.bar, weight_string(ue.bar) from (select col, bar from user_extra) as ue limit 10",
"Table": "user_extra"
}
]
Expand Down Expand Up @@ -7271,8 +7285,10 @@
"Aggregates": "count_star(0) AS count(*)",
"Inputs": [
{
"OperatorType": "SimpleProjection",
"Columns": "2",
"OperatorType": "Projection",
"Expressions": [
"1 as 1"
],
"Inputs": [
{
"OperatorType": "Limit",
Expand All @@ -7286,9 +7302,9 @@
"Name": "user",
"Sharded": true
},
"FieldQuery": "select subquery_for_count.one, subquery_for_count.id, 1, weight_string(subquery_for_count.id) from (select 1 as one, id from `user` where 1 != 1) as subquery_for_count where 1 != 1",
"OrderBy": "(1|3) DESC",
"Query": "select subquery_for_count.one, subquery_for_count.id, 1, weight_string(subquery_for_count.id) from (select 1 as one, id from `user` where `user`.is_not_deleted = true) as subquery_for_count order by subquery_for_count.id desc limit 25",
"FieldQuery": "select subquery_for_count.one, subquery_for_count.id, weight_string(subquery_for_count.id) from (select 1 as one, id from `user` where 1 != 1) as subquery_for_count where 1 != 1",
"OrderBy": "(1|2) DESC",
"Query": "select subquery_for_count.one, subquery_for_count.id, weight_string(subquery_for_count.id) from (select 1 as one, id from `user` where `user`.is_not_deleted = true) as subquery_for_count order by subquery_for_count.id desc limit 25",
"Table": "`user`"
}
]
Expand Down
Loading

0 comments on commit dbd11c7

Please sign in to comment.