mirror of https://github.com/citusdata/citus.git
Require subquery_pushdown when limit is used in subquery
Using limit in subqueries may cause returning incorrect results. Therefore we allow limits in subqueries only if user explicitly set subquery_pushdown flag.pull/1341/head
parent
6561b9a8b7
commit
a313fdd0a0
|
@ -71,9 +71,11 @@ static DeferredErrorMessage * DeferErrorIfUnsupportedFilters(Query *subquery);
|
|||
static bool EqualOpExpressionLists(List *firstOpExpressionList,
|
||||
List *secondOpExpressionList);
|
||||
static DeferredErrorMessage * DeferErrorIfCannotPushdownSubquery(Query *subqueryTree,
|
||||
bool outerQueryHasLimit);
|
||||
bool
|
||||
outerMostQueryHasLimit);
|
||||
static DeferredErrorMessage * DeferErrorIfUnsupportedUnionQuery(Query *queryTree,
|
||||
bool outerQueryHasLimit);
|
||||
bool
|
||||
outerMostQueryHasLimit);
|
||||
static bool ExtractSetOperationStatmentWalker(Node *node, List **setOperationList);
|
||||
static DeferredErrorMessage * DeferErrorIfUnsupportedTableCombination(Query *queryTree);
|
||||
static bool TargetListOnPartitionColumn(Query *query, List *targetEntryList);
|
||||
|
@ -335,14 +337,14 @@ DeferErrorIfUnsupportedSubqueryPushdown(Query *originalQuery,
|
|||
{
|
||||
ListCell *rangeTableEntryCell = NULL;
|
||||
List *subqueryEntryList = NIL;
|
||||
bool outerQueryHasLimit = false;
|
||||
bool outerMostQueryHasLimit = false;
|
||||
DeferredErrorMessage *error = NULL;
|
||||
RelationRestrictionContext *relationRestrictionContext =
|
||||
plannerRestrictionContext->relationRestrictionContext;
|
||||
|
||||
if (originalQuery->limitCount != NULL)
|
||||
{
|
||||
outerQueryHasLimit = true;
|
||||
outerMostQueryHasLimit = true;
|
||||
}
|
||||
|
||||
/*
|
||||
|
@ -380,7 +382,7 @@ DeferErrorIfUnsupportedSubqueryPushdown(Query *originalQuery,
|
|||
RangeTblEntry *rangeTableEntry = lfirst(rangeTableEntryCell);
|
||||
Query *subquery = rangeTableEntry->subquery;
|
||||
|
||||
error = DeferErrorIfCannotPushdownSubquery(subquery, outerQueryHasLimit);
|
||||
error = DeferErrorIfCannotPushdownSubquery(subquery, outerMostQueryHasLimit);
|
||||
if (error)
|
||||
{
|
||||
return error;
|
||||
|
@ -533,7 +535,7 @@ EqualOpExpressionLists(List *firstOpExpressionList, List *secondOpExpressionList
|
|||
* features of underlying tables.
|
||||
*/
|
||||
static DeferredErrorMessage *
|
||||
DeferErrorIfCannotPushdownSubquery(Query *subqueryTree, bool outerQueryHasLimit)
|
||||
DeferErrorIfCannotPushdownSubquery(Query *subqueryTree, bool outerMostQueryHasLimit)
|
||||
{
|
||||
bool preconditionsSatisfied = true;
|
||||
char *errorDetail = NULL;
|
||||
|
@ -571,16 +573,28 @@ DeferErrorIfCannotPushdownSubquery(Query *subqueryTree, bool outerQueryHasLimit)
|
|||
errorDetail = "Offset clause is currently unsupported";
|
||||
}
|
||||
|
||||
if (subqueryTree->limitCount && !outerQueryHasLimit)
|
||||
/* limit is not supported when SubqueryPushdown is not set */
|
||||
if (subqueryTree->limitCount && !SubqueryPushdown)
|
||||
{
|
||||
preconditionsSatisfied = false;
|
||||
errorDetail = "Limit in subquery without limit in the outer query is unsupported";
|
||||
errorDetail = "Limit in subquery is currently unsupported";
|
||||
}
|
||||
|
||||
/*
|
||||
* Limit is partially supported when SubqueryPushdown is set.
|
||||
* The outermost query must have a limit clause.
|
||||
*/
|
||||
if (subqueryTree->limitCount && SubqueryPushdown && !outerMostQueryHasLimit)
|
||||
{
|
||||
preconditionsSatisfied = false;
|
||||
errorDetail = "Limit in subquery without limit in the outermost query is "
|
||||
"unsupported";
|
||||
}
|
||||
|
||||
if (subqueryTree->setOperations)
|
||||
{
|
||||
deferredError = DeferErrorIfUnsupportedUnionQuery(subqueryTree,
|
||||
outerQueryHasLimit);
|
||||
outerMostQueryHasLimit);
|
||||
if (deferredError)
|
||||
{
|
||||
return deferredError;
|
||||
|
@ -671,7 +685,7 @@ DeferErrorIfCannotPushdownSubquery(Query *subqueryTree, bool outerQueryHasLimit)
|
|||
|
||||
Query *innerSubquery = rangeTableEntry->subquery;
|
||||
deferredError = DeferErrorIfCannotPushdownSubquery(innerSubquery,
|
||||
outerQueryHasLimit);
|
||||
outerMostQueryHasLimit);
|
||||
if (deferredError)
|
||||
{
|
||||
return deferredError;
|
||||
|
@ -690,7 +704,7 @@ DeferErrorIfCannotPushdownSubquery(Query *subqueryTree, bool outerQueryHasLimit)
|
|||
*/
|
||||
static DeferredErrorMessage *
|
||||
DeferErrorIfUnsupportedUnionQuery(Query *subqueryTree,
|
||||
bool outerQueryHasLimit)
|
||||
bool outerMostQueryHasLimit)
|
||||
{
|
||||
List *rangeTableIndexList = NIL;
|
||||
ListCell *rangeTableIndexCell = NULL;
|
||||
|
@ -724,7 +738,7 @@ DeferErrorIfUnsupportedUnionQuery(Query *subqueryTree,
|
|||
Assert(rangeTableEntry->rtekind == RTE_SUBQUERY);
|
||||
|
||||
deferredError = DeferErrorIfCannotPushdownSubquery(rangeTableEntry->subquery,
|
||||
outerQueryHasLimit);
|
||||
outerMostQueryHasLimit);
|
||||
if (deferredError)
|
||||
{
|
||||
return deferredError;
|
||||
|
|
|
@ -830,6 +830,9 @@ GROUP BY
|
|||
1
|
||||
(1 row)
|
||||
|
||||
-- most queries below has limit clause
|
||||
-- therefore setting subquery_pushdown flag for all
|
||||
SET citus.subquery_pushdown to ON;
|
||||
-- multi-subquery-join
|
||||
-- The first query has filters on partion column to make it router plannable
|
||||
-- but it is processed by logical planner since we disabled router execution
|
||||
|
@ -1947,4 +1950,5 @@ FROM (
|
|||
ERROR: unsupported offset clause
|
||||
SET client_min_messages TO DEFAULT;
|
||||
DROP FUNCTION volatile_func_test();
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
SET citus.enable_router_execution TO TRUE;
|
||||
|
|
|
@ -1115,6 +1115,8 @@ LIMIT 10;
|
|||
(10 rows)
|
||||
|
||||
-- Simple LATERAL JOINs with GROUP BYs in each side
|
||||
-- need to set subquery_pushdown due to limit for next 2 queries
|
||||
SET citus.subquery_pushdown to ON;
|
||||
SELECT *
|
||||
FROM
|
||||
(SELECT "some_users_data".user_id, lastseen
|
||||
|
@ -1205,6 +1207,8 @@ limit 50;
|
|||
34 | Tue Jan 21 04:15:03.874341 2014
|
||||
(6 rows)
|
||||
|
||||
-- reset subquery_pushdown
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
-- not supported since JOIN is not on the partition key
|
||||
SELECT "some_users_data".user_id, lastseen
|
||||
FROM
|
||||
|
@ -1277,6 +1281,7 @@ limit 50;
|
|||
ERROR: cannot pushdown the subquery since all relations are not joined using distribution keys
|
||||
DETAIL: Each relation should be joined with at least one another relation using distribution keys and equality operator.
|
||||
-- LATERAL JOINs used with INNER JOINs
|
||||
SET citus.subquery_pushdown to ON;
|
||||
SELECT user_id, lastseen
|
||||
FROM
|
||||
(SELECT
|
||||
|
@ -1405,6 +1410,7 @@ LIMIT 10;
|
|||
14 | Tue Jan 21 05:46:51.286381 2014 | 10
|
||||
(3 rows)
|
||||
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
-- not supported since the inner JOIN is not equi join
|
||||
SELECT user_id, lastseen
|
||||
FROM
|
||||
|
@ -1866,6 +1872,7 @@ ORDER BY cnt, value_3 DESC LIMIT 10;
|
|||
ERROR: cannot pushdown the subquery since all relations are not joined using distribution keys
|
||||
DETAIL: Each relation should be joined with at least one another relation using distribution keys and equality operator.
|
||||
-- nested LATERAL JOINs
|
||||
SET citus.subquery_pushdown to ON;
|
||||
SELECT *
|
||||
FROM
|
||||
(SELECT "some_users_data".user_id, "some_recent_users".value_3
|
||||
|
@ -2070,6 +2077,7 @@ LIMIT 10;
|
|||
21 | 985
|
||||
(6 rows)
|
||||
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
-- LEFT JOINs used with INNER JOINs
|
||||
SELECT
|
||||
count(*) AS cnt, "generated_group_field"
|
||||
|
@ -2154,6 +2162,7 @@ LIMIT 10;
|
|||
(10 rows)
|
||||
|
||||
-- lateral joins in the nested manner
|
||||
SET citus.subquery_pushdown to ON;
|
||||
SELECT *
|
||||
FROM
|
||||
(SELECT
|
||||
|
@ -2204,6 +2213,7 @@ LIMIT 10;
|
|||
19 | 966
|
||||
(9 rows)
|
||||
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
-- not supported since join is not on the partition key
|
||||
SELECT *
|
||||
FROM
|
||||
|
|
|
@ -193,7 +193,7 @@ SELECT count(*) FROM
|
|||
(SELECT l_orderkey FROM lineitem_subquery) UNION
|
||||
(SELECT l_orderkey FROM lineitem_subquery)
|
||||
) b;
|
||||
-- Check that we error out if inner query has limit but outer quers has not.
|
||||
-- Check that we error out if inner query has Limit but subquery_pushdown is not set
|
||||
SELECT
|
||||
avg(o_totalprice/l_quantity)
|
||||
FROM
|
||||
|
@ -214,6 +214,32 @@ FROM
|
|||
WHERE
|
||||
lineitem_quantities.l_orderkey = o_orderkey) orders_price ON true;
|
||||
|
||||
-- Limit is only supported when subquery_pushdown is set
|
||||
-- Check that we error out if inner query has limit but outer query has not.
|
||||
SET citus.subquery_pushdown to ON;
|
||||
SELECT
|
||||
avg(o_totalprice/l_quantity)
|
||||
FROM
|
||||
(SELECT
|
||||
l_orderkey,
|
||||
l_quantity
|
||||
FROM
|
||||
lineitem_subquery
|
||||
ORDER BY
|
||||
l_quantity
|
||||
LIMIT 10
|
||||
) lineitem_quantities
|
||||
JOIN LATERAL
|
||||
(SELECT
|
||||
o_totalprice
|
||||
FROM
|
||||
orders_subquery
|
||||
WHERE
|
||||
lineitem_quantities.l_orderkey = o_orderkey) orders_price ON true;
|
||||
|
||||
-- reset the flag for next query
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
|
||||
-- Check that we error out if the outermost query is a distinct clause.
|
||||
|
||||
SELECT
|
||||
|
@ -1083,6 +1109,8 @@ ORDER BY
|
|||
count_pay;
|
||||
|
||||
-- Lateral join subquery pushdown
|
||||
-- set subquery_pushdown since there is limit in the query
|
||||
SET citus.subquery_pushdown to ON;
|
||||
SELECT
|
||||
tenant_id,
|
||||
user_id,
|
||||
|
@ -1132,7 +1160,8 @@ ORDER BY
|
|||
user_lastseen DESC
|
||||
LIMIT
|
||||
10;
|
||||
|
||||
-- reset the flag for next query
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
|
||||
-- Same queries above with explain
|
||||
-- Simple join subquery pushdown
|
||||
|
@ -1297,6 +1326,8 @@ ORDER BY
|
|||
count_pay;
|
||||
|
||||
-- Lateral join subquery pushdown
|
||||
-- set subquery_pushdown due to limit in the query
|
||||
SET citus.subquery_pushdown to ON;
|
||||
EXPLAIN SELECT
|
||||
tenant_id,
|
||||
user_id,
|
||||
|
@ -1346,5 +1377,5 @@ ORDER BY
|
|||
user_lastseen DESC
|
||||
LIMIT
|
||||
10;
|
||||
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
SET citus.enable_router_execution TO 'true';
|
||||
|
|
|
@ -201,7 +201,7 @@ SELECT count(*) FROM
|
|||
2985
|
||||
(1 row)
|
||||
|
||||
-- Check that we error out if inner query has limit but outer quers has not.
|
||||
-- Check that we error out if inner query has Limit but subquery_pushdown is not set
|
||||
SELECT
|
||||
avg(o_totalprice/l_quantity)
|
||||
FROM
|
||||
|
@ -222,7 +222,33 @@ FROM
|
|||
WHERE
|
||||
lineitem_quantities.l_orderkey = o_orderkey) orders_price ON true;
|
||||
ERROR: cannot push down this subquery
|
||||
DETAIL: Limit in subquery without limit in the outer query is unsupported
|
||||
DETAIL: Limit in subquery is currently unsupported
|
||||
-- Limit is only supported when subquery_pushdown is set
|
||||
-- Check that we error out if inner query has limit but outer query has not.
|
||||
SET citus.subquery_pushdown to ON;
|
||||
SELECT
|
||||
avg(o_totalprice/l_quantity)
|
||||
FROM
|
||||
(SELECT
|
||||
l_orderkey,
|
||||
l_quantity
|
||||
FROM
|
||||
lineitem_subquery
|
||||
ORDER BY
|
||||
l_quantity
|
||||
LIMIT 10
|
||||
) lineitem_quantities
|
||||
JOIN LATERAL
|
||||
(SELECT
|
||||
o_totalprice
|
||||
FROM
|
||||
orders_subquery
|
||||
WHERE
|
||||
lineitem_quantities.l_orderkey = o_orderkey) orders_price ON true;
|
||||
ERROR: cannot push down this subquery
|
||||
DETAIL: Limit in subquery without limit in the outermost query is unsupported
|
||||
-- reset the flag for next query
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
-- Check that we error out if the outermost query is a distinct clause.
|
||||
SELECT
|
||||
count(DISTINCT a)
|
||||
|
@ -1084,6 +1110,8 @@ ORDER BY
|
|||
|
||||
|
||||
-- Lateral join subquery pushdown
|
||||
-- set subquery_pushdown since there is limit in the query
|
||||
SET citus.subquery_pushdown to ON;
|
||||
SELECT
|
||||
tenant_id,
|
||||
user_id,
|
||||
|
@ -1140,6 +1168,8 @@ LIMIT
|
|||
1 | 1001 | 1472807115 | {click,submit,pay}
|
||||
(3 rows)
|
||||
|
||||
-- reset the flag for next query
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
-- Same queries above with explain
|
||||
-- Simple join subquery pushdown
|
||||
EXPLAIN SELECT
|
||||
|
@ -1367,6 +1397,8 @@ ORDER BY
|
|||
count_pay;
|
||||
ERROR: bogus varattno for OUTER_VAR var: 3
|
||||
-- Lateral join subquery pushdown
|
||||
-- set subquery_pushdown due to limit in the query
|
||||
SET citus.subquery_pushdown to ON;
|
||||
EXPLAIN SELECT
|
||||
tenant_id,
|
||||
user_id,
|
||||
|
@ -1447,5 +1479,5 @@ LIMIT
|
|||
Filter: (composite_id = users.composite_id)
|
||||
(27 rows)
|
||||
|
||||
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
SET citus.enable_router_execution TO 'true';
|
||||
|
|
|
@ -201,7 +201,7 @@ SELECT count(*) FROM
|
|||
2985
|
||||
(1 row)
|
||||
|
||||
-- Check that we error out if inner query has limit but outer quers has not.
|
||||
-- Check that we error out if inner query has Limit but subquery_pushdown is not set
|
||||
SELECT
|
||||
avg(o_totalprice/l_quantity)
|
||||
FROM
|
||||
|
@ -222,7 +222,33 @@ FROM
|
|||
WHERE
|
||||
lineitem_quantities.l_orderkey = o_orderkey) orders_price ON true;
|
||||
ERROR: cannot push down this subquery
|
||||
DETAIL: Limit in subquery without limit in the outer query is unsupported
|
||||
DETAIL: Limit in subquery is currently unsupported
|
||||
-- Limit is only supported when subquery_pushdown is set
|
||||
-- Check that we error out if inner query has limit but outer query has not.
|
||||
SET citus.subquery_pushdown to ON;
|
||||
SELECT
|
||||
avg(o_totalprice/l_quantity)
|
||||
FROM
|
||||
(SELECT
|
||||
l_orderkey,
|
||||
l_quantity
|
||||
FROM
|
||||
lineitem_subquery
|
||||
ORDER BY
|
||||
l_quantity
|
||||
LIMIT 10
|
||||
) lineitem_quantities
|
||||
JOIN LATERAL
|
||||
(SELECT
|
||||
o_totalprice
|
||||
FROM
|
||||
orders_subquery
|
||||
WHERE
|
||||
lineitem_quantities.l_orderkey = o_orderkey) orders_price ON true;
|
||||
ERROR: cannot push down this subquery
|
||||
DETAIL: Limit in subquery without limit in the outermost query is unsupported
|
||||
-- reset the flag for next query
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
-- Check that we error out if the outermost query is a distinct clause.
|
||||
SELECT
|
||||
count(DISTINCT a)
|
||||
|
@ -1084,6 +1110,8 @@ ORDER BY
|
|||
|
||||
|
||||
-- Lateral join subquery pushdown
|
||||
-- set subquery_pushdown since there is limit in the query
|
||||
SET citus.subquery_pushdown to ON;
|
||||
SELECT
|
||||
tenant_id,
|
||||
user_id,
|
||||
|
@ -1140,6 +1168,8 @@ LIMIT
|
|||
1 | 1001 | 1472807115 | {click,submit,pay}
|
||||
(3 rows)
|
||||
|
||||
-- reset the flag for next query
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
-- Same queries above with explain
|
||||
-- Simple join subquery pushdown
|
||||
EXPLAIN SELECT
|
||||
|
@ -1351,6 +1381,8 @@ ORDER BY
|
|||
count_pay;
|
||||
ERROR: bogus varattno for OUTER_VAR var: 3
|
||||
-- Lateral join subquery pushdown
|
||||
-- set subquery_pushdown due to limit in the query
|
||||
SET citus.subquery_pushdown to ON;
|
||||
EXPLAIN SELECT
|
||||
tenant_id,
|
||||
user_id,
|
||||
|
@ -1430,5 +1462,5 @@ LIMIT
|
|||
Filter: (composite_id = composite_id)
|
||||
(26 rows)
|
||||
|
||||
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
SET citus.enable_router_execution TO 'true';
|
||||
|
|
|
@ -697,6 +697,10 @@ WHERE
|
|||
GROUP BY
|
||||
a.user_id;
|
||||
|
||||
-- most queries below has limit clause
|
||||
-- therefore setting subquery_pushdown flag for all
|
||||
SET citus.subquery_pushdown to ON;
|
||||
|
||||
-- multi-subquery-join
|
||||
-- The first query has filters on partion column to make it router plannable
|
||||
-- but it is processed by logical planner since we disabled router execution
|
||||
|
@ -1596,4 +1600,5 @@ FROM (
|
|||
SET client_min_messages TO DEFAULT;
|
||||
DROP FUNCTION volatile_func_test();
|
||||
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
SET citus.enable_router_execution TO TRUE;
|
||||
|
|
|
@ -1043,6 +1043,8 @@ GROUP BY
|
|||
LIMIT 10;
|
||||
|
||||
-- Simple LATERAL JOINs with GROUP BYs in each side
|
||||
-- need to set subquery_pushdown due to limit for next 2 queries
|
||||
SET citus.subquery_pushdown to ON;
|
||||
SELECT *
|
||||
FROM
|
||||
(SELECT "some_users_data".user_id, lastseen
|
||||
|
@ -1115,6 +1117,9 @@ ORDER BY
|
|||
user_id
|
||||
limit 50;
|
||||
|
||||
-- reset subquery_pushdown
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
|
||||
-- not supported since JOIN is not on the partition key
|
||||
SELECT "some_users_data".user_id, lastseen
|
||||
FROM
|
||||
|
@ -1185,6 +1190,7 @@ ORDER BY
|
|||
limit 50;
|
||||
|
||||
-- LATERAL JOINs used with INNER JOINs
|
||||
SET citus.subquery_pushdown to ON;
|
||||
SELECT user_id, lastseen
|
||||
FROM
|
||||
(SELECT
|
||||
|
@ -1294,6 +1300,8 @@ GROUP BY 1
|
|||
ORDER BY 2, 1 DESC
|
||||
LIMIT 10;
|
||||
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
|
||||
-- not supported since the inner JOIN is not equi join
|
||||
SELECT user_id, lastseen
|
||||
FROM
|
||||
|
@ -1718,6 +1726,7 @@ GROUP BY "value_3"
|
|||
ORDER BY cnt, value_3 DESC LIMIT 10;
|
||||
|
||||
-- nested LATERAL JOINs
|
||||
SET citus.subquery_pushdown to ON;
|
||||
SELECT *
|
||||
FROM
|
||||
(SELECT "some_users_data".user_id, "some_recent_users".value_3
|
||||
|
@ -1886,6 +1895,8 @@ FROM
|
|||
ORDER BY value_3 DESC
|
||||
LIMIT 10;
|
||||
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
|
||||
-- LEFT JOINs used with INNER JOINs
|
||||
SELECT
|
||||
count(*) AS cnt, "generated_group_field"
|
||||
|
@ -1944,6 +1955,7 @@ ORDER BY
|
|||
LIMIT 10;
|
||||
|
||||
-- lateral joins in the nested manner
|
||||
SET citus.subquery_pushdown to ON;
|
||||
SELECT *
|
||||
FROM
|
||||
(SELECT
|
||||
|
@ -1981,6 +1993,7 @@ FROM
|
|||
ORDER BY
|
||||
value_2 DESC, user_id DESC
|
||||
LIMIT 10;
|
||||
SET citus.subquery_pushdown to OFF;
|
||||
|
||||
-- not supported since join is not on the partition key
|
||||
SELECT *
|
||||
|
|
Loading…
Reference in New Issue