Merge pull request #806 from citusdata/fix_805_where_false

Make join queries with where false clauses router plannable
pull/814/head
Murat Tuncer 2016-09-28 18:54:19 +03:00 committed by GitHub
commit 854ed613fb
3 changed files with 384 additions and 10 deletions

View File

@ -1128,7 +1128,9 @@ RouterSelectTask(Query *originalQuery, Query *query,
* in the query and returns list of shards per relation. Shard pruning is done based * in the query and returns list of shards per relation. Shard pruning is done based
* on provided restriction context per relation. The function bails out and returns NULL * on provided restriction context per relation. The function bails out and returns NULL
* if any of the relations pruned down to more than one active shard. It also records * if any of the relations pruned down to more than one active shard. It also records
* pruned shard intervals in relation restriction context to be used later on. * pruned shard intervals in relation restriction context to be used later on. Some
* queries may have contradiction clauses like 'and false' or 'and 1=0', such queries
* are treated as if all of the shards of joining relations are pruned out.
*/ */
static List * static List *
TargetShardIntervalsForSelect(Query *query, TargetShardIntervalsForSelect(Query *query,
@ -1149,13 +1151,26 @@ TargetShardIntervalsForSelect(Query *query,
DistTableCacheEntry *cacheEntry = DistributedTableCacheEntry(relationId); DistTableCacheEntry *cacheEntry = DistributedTableCacheEntry(relationId);
int shardCount = cacheEntry->shardIntervalArrayLength; int shardCount = cacheEntry->shardIntervalArrayLength;
List *baseRestrictionList = relationRestriction->relOptInfo->baserestrictinfo; List *baseRestrictionList = relationRestriction->relOptInfo->baserestrictinfo;
List *restrictClauseList = extract_actual_clauses(baseRestrictionList, false); List *restrictClauseList = get_all_actual_clauses(baseRestrictionList);
List *shardIntervalList = NIL;
List *prunedShardList = NIL; List *prunedShardList = NIL;
int shardIndex = 0; int shardIndex = 0;
List *joinInfoList = relationRestriction->relOptInfo->joininfo;
List *pseudoRestrictionList = extract_actual_clauses(joinInfoList, true);
bool whereFalseQuery = false;
relationRestriction->prunedShardIntervalList = NIL; relationRestriction->prunedShardIntervalList = NIL;
/*
* Queries may have contradiction clauses like 'false', or '1=0' in
* their filters. Such queries would have pseudo constant 'false'
* inside relOptInfo->joininfo list. We treat such cases as if all
* shards of the table are pruned out.
*/
whereFalseQuery = ContainsFalseClause(pseudoRestrictionList);
if (!whereFalseQuery && shardCount > 0)
{
List *shardIntervalList = NIL;
for (shardIndex = 0; shardIndex < shardCount; shardIndex++) for (shardIndex = 0; shardIndex < shardCount; shardIndex++)
{ {
ShardInterval *shardInterval = ShardInterval *shardInterval =
@ -1163,8 +1178,6 @@ TargetShardIntervalsForSelect(Query *query,
shardIntervalList = lappend(shardIntervalList, shardInterval); shardIntervalList = lappend(shardIntervalList, shardInterval);
} }
if (shardCount > 0)
{
prunedShardList = PruneShardList(relationId, tableId, prunedShardList = PruneShardList(relationId, tableId,
restrictClauseList, restrictClauseList,
shardIntervalList); shardIntervalList);

View File

@ -1278,6 +1278,254 @@ SELECT LAG(title, 1) over (ORDER BY word_count) prev, title, word_count
WHERE author_id = 5 or author_id = 2; WHERE author_id = 5 or author_id = 2;
ERROR: cannot perform distributed planning on this query ERROR: cannot perform distributed planning on this query
DETAIL: Window functions are currently unsupported DETAIL: Window functions are currently unsupported
-- where false queries are router plannable
SELECT *
FROM articles_hash
WHERE false;
DEBUG: Creating router plan
DEBUG: Plan is router executable
id | author_id | title | word_count
----+-----------+-------+------------
(0 rows)
SELECT *
FROM articles_hash
WHERE author_id = 1 and false;
DEBUG: Creating router plan
DEBUG: Plan is router executable
id | author_id | title | word_count
----+-----------+-------+------------
(0 rows)
SELECT *
FROM articles_hash
WHERE author_id = 1 and 1=0;
DEBUG: Creating router plan
DEBUG: Plan is router executable
id | author_id | title | word_count
----+-----------+-------+------------
(0 rows)
SELECT a.author_id as first_author, b.word_count as second_word_count
FROM articles_hash a, articles_single_shard_hash b
WHERE a.author_id = 10 and a.author_id = b.author_id and false;
DEBUG: Creating router plan
DEBUG: Plan is router executable
first_author | second_word_count
--------------+-------------------
(0 rows)
SELECT *
FROM articles_hash
WHERE null;
DEBUG: Creating router plan
DEBUG: Plan is router executable
id | author_id | title | word_count
----+-----------+-------+------------
(0 rows)
-- where false with immutable function returning false
SELECT *
FROM articles_hash a
WHERE a.author_id = 10 and int4eq(1, 2);
DEBUG: Creating router plan
DEBUG: Plan is router executable
id | author_id | title | word_count
----+-----------+-------+------------
(0 rows)
SELECT *
FROM articles_hash a
WHERE int4eq(1, 2);
DEBUG: Creating router plan
DEBUG: Plan is router executable
id | author_id | title | word_count
----+-----------+-------+------------
(0 rows)
SELECT a.author_id as first_author, b.word_count as second_word_count
FROM articles_hash a, articles_single_shard_hash b
WHERE a.author_id = 10 and a.author_id = b.author_id and int4eq(1, 1);
DEBUG: predicate pruning for shardId 840001
DEBUG: Creating router plan
DEBUG: Plan is router executable
first_author | second_word_count
--------------+-------------------
10 | 19519
10 | 19519
10 | 19519
10 | 19519
10 | 19519
(5 rows)
SELECT a.author_id as first_author, b.word_count as second_word_count
FROM articles_hash a, articles_single_shard_hash b
WHERE a.author_id = 10 and a.author_id = b.author_id and int4eq(1, 2);
DEBUG: Creating router plan
DEBUG: Plan is router executable
first_author | second_word_count
--------------+-------------------
(0 rows)
-- stable function returning bool
SELECT *
FROM articles_hash a
WHERE date_ne_timestamp('1954-04-11', '1954-04-11'::timestamp);
DEBUG: Creating router plan
DEBUG: Plan is router executable
id | author_id | title | word_count
----+-----------+-------+------------
(0 rows)
SELECT a.author_id as first_author, b.word_count as second_word_count
FROM articles_hash a, articles_single_shard_hash b
WHERE a.author_id = 10 and a.author_id = b.author_id and
date_ne_timestamp('1954-04-11', '1954-04-11'::timestamp);
DEBUG: Creating router plan
DEBUG: Plan is router executable
first_author | second_word_count
--------------+-------------------
(0 rows)
-- union/difference /intersection with where false
-- this query was not originally router plannable, addition of 1=0
-- makes it router plannable
(SELECT * FROM articles_hash WHERE author_id = 1)
UNION
(SELECT * FROM articles_hash WHERE author_id = 2 and 1=0);
DEBUG: predicate pruning for shardId 840001
DEBUG: Creating router plan
DEBUG: Plan is router executable
id | author_id | title | word_count
----+-----------+--------------+------------
11 | 1 | alamo | 1347
41 | 1 | aznavour | 11814
1 | 1 | arsenous | 9572
21 | 1 | arcading | 5890
31 | 1 | athwartships | 7271
(5 rows)
(SELECT * FROM articles_hash WHERE author_id = 1)
EXCEPT
(SELECT * FROM articles_hash WHERE author_id = 2 and 1=0);
DEBUG: predicate pruning for shardId 840001
DEBUG: Creating router plan
DEBUG: Plan is router executable
id | author_id | title | word_count
----+-----------+--------------+------------
1 | 1 | arsenous | 9572
21 | 1 | arcading | 5890
31 | 1 | athwartships | 7271
11 | 1 | alamo | 1347
41 | 1 | aznavour | 11814
(5 rows)
(SELECT * FROM articles_hash WHERE author_id = 1)
INTERSECT
(SELECT * FROM articles_hash WHERE author_id = 2 and 1=0);
DEBUG: predicate pruning for shardId 840001
DEBUG: Creating router plan
DEBUG: Plan is router executable
id | author_id | title | word_count
----+-----------+-------+------------
(0 rows)
-- CTEs with where false
WITH id_author AS ( SELECT id, author_id FROM articles_hash WHERE author_id = 1),
id_title AS (SELECT id, title from articles_hash WHERE author_id = 1 and 1=0)
SELECT * FROM id_author, id_title WHERE id_author.id = id_title.id;
DEBUG: predicate pruning for shardId 840001
DEBUG: Creating router plan
DEBUG: Plan is router executable
id | author_id | id | title
----+-----------+----+-------
(0 rows)
WITH id_author AS ( SELECT id, author_id FROM articles_hash WHERE author_id = 1),
id_title AS (SELECT id, title from articles_hash WHERE author_id = 1)
SELECT * FROM id_author, id_title WHERE id_author.id = id_title.id and 1=0;
DEBUG: predicate pruning for shardId 840001
DEBUG: predicate pruning for shardId 840001
DEBUG: Creating router plan
DEBUG: Plan is router executable
id | author_id | id | title
----+-----------+----+-------
(0 rows)
WITH RECURSIVE hierarchy as (
SELECT *, 1 AS level
FROM company_employees
WHERE company_id = 1 and manager_id = 0
UNION
SELECT ce.*, (h.level+1)
FROM hierarchy h JOIN company_employees ce
ON (h.employee_id = ce.manager_id AND
h.company_id = ce.company_id AND
ce.company_id = 1))
SELECT * FROM hierarchy WHERE LEVEL <= 2 and 1=0;
DEBUG: predicate pruning for shardId 840004
DEBUG: predicate pruning for shardId 840005
DEBUG: predicate pruning for shardId 840006
DEBUG: predicate pruning for shardId 840004
DEBUG: predicate pruning for shardId 840005
DEBUG: predicate pruning for shardId 840006
DEBUG: Creating router plan
DEBUG: Plan is router executable
company_id | employee_id | manager_id | level
------------+-------------+------------+-------
(0 rows)
WITH RECURSIVE hierarchy as (
SELECT *, 1 AS level
FROM company_employees
WHERE company_id = 1 and manager_id = 0
UNION
SELECT ce.*, (h.level+1)
FROM hierarchy h JOIN company_employees ce
ON (h.employee_id = ce.manager_id AND
h.company_id = ce.company_id AND
ce.company_id = 1 AND 1=0))
SELECT * FROM hierarchy WHERE LEVEL <= 2;
DEBUG: predicate pruning for shardId 840004
DEBUG: predicate pruning for shardId 840005
DEBUG: predicate pruning for shardId 840006
DEBUG: Creating router plan
DEBUG: Plan is router executable
company_id | employee_id | manager_id | level
------------+-------------+------------+-------
1 | 1 | 0 | 1
(1 row)
WITH RECURSIVE hierarchy as (
SELECT *, 1 AS level
FROM company_employees
WHERE company_id = 1 and manager_id = 0 AND 1=0
UNION
SELECT ce.*, (h.level+1)
FROM hierarchy h JOIN company_employees ce
ON (h.employee_id = ce.manager_id AND
h.company_id = ce.company_id AND
ce.company_id = 1))
SELECT * FROM hierarchy WHERE LEVEL <= 2;
DEBUG: predicate pruning for shardId 840004
DEBUG: predicate pruning for shardId 840005
DEBUG: predicate pruning for shardId 840006
DEBUG: Creating router plan
DEBUG: Plan is router executable
company_id | employee_id | manager_id | level
------------+-------------+------------+-------
(0 rows)
-- window functions with where false
SELECT word_count, rank() OVER (PARTITION BY author_id ORDER BY word_count)
FROM articles_hash
WHERE author_id = 1 and 1=0;
DEBUG: Creating router plan
DEBUG: Plan is router executable
word_count | rank
------------+------
(0 rows)
-- complex query hitting a single shard -- complex query hitting a single shard
SELECT SELECT
count(DISTINCT CASE count(DISTINCT CASE

View File

@ -531,6 +531,119 @@ SELECT LAG(title, 1) over (ORDER BY word_count) prev, title, word_count
FROM articles_hash FROM articles_hash
WHERE author_id = 5 or author_id = 2; WHERE author_id = 5 or author_id = 2;
-- where false queries are router plannable
SELECT *
FROM articles_hash
WHERE false;
SELECT *
FROM articles_hash
WHERE author_id = 1 and false;
SELECT *
FROM articles_hash
WHERE author_id = 1 and 1=0;
SELECT a.author_id as first_author, b.word_count as second_word_count
FROM articles_hash a, articles_single_shard_hash b
WHERE a.author_id = 10 and a.author_id = b.author_id and false;
SELECT *
FROM articles_hash
WHERE null;
-- where false with immutable function returning false
SELECT *
FROM articles_hash a
WHERE a.author_id = 10 and int4eq(1, 2);
SELECT *
FROM articles_hash a
WHERE int4eq(1, 2);
SELECT a.author_id as first_author, b.word_count as second_word_count
FROM articles_hash a, articles_single_shard_hash b
WHERE a.author_id = 10 and a.author_id = b.author_id and int4eq(1, 1);
SELECT a.author_id as first_author, b.word_count as second_word_count
FROM articles_hash a, articles_single_shard_hash b
WHERE a.author_id = 10 and a.author_id = b.author_id and int4eq(1, 2);
-- stable function returning bool
SELECT *
FROM articles_hash a
WHERE date_ne_timestamp('1954-04-11', '1954-04-11'::timestamp);
SELECT a.author_id as first_author, b.word_count as second_word_count
FROM articles_hash a, articles_single_shard_hash b
WHERE a.author_id = 10 and a.author_id = b.author_id and
date_ne_timestamp('1954-04-11', '1954-04-11'::timestamp);
-- union/difference /intersection with where false
-- this query was not originally router plannable, addition of 1=0
-- makes it router plannable
(SELECT * FROM articles_hash WHERE author_id = 1)
UNION
(SELECT * FROM articles_hash WHERE author_id = 2 and 1=0);
(SELECT * FROM articles_hash WHERE author_id = 1)
EXCEPT
(SELECT * FROM articles_hash WHERE author_id = 2 and 1=0);
(SELECT * FROM articles_hash WHERE author_id = 1)
INTERSECT
(SELECT * FROM articles_hash WHERE author_id = 2 and 1=0);
-- CTEs with where false
WITH id_author AS ( SELECT id, author_id FROM articles_hash WHERE author_id = 1),
id_title AS (SELECT id, title from articles_hash WHERE author_id = 1 and 1=0)
SELECT * FROM id_author, id_title WHERE id_author.id = id_title.id;
WITH id_author AS ( SELECT id, author_id FROM articles_hash WHERE author_id = 1),
id_title AS (SELECT id, title from articles_hash WHERE author_id = 1)
SELECT * FROM id_author, id_title WHERE id_author.id = id_title.id and 1=0;
WITH RECURSIVE hierarchy as (
SELECT *, 1 AS level
FROM company_employees
WHERE company_id = 1 and manager_id = 0
UNION
SELECT ce.*, (h.level+1)
FROM hierarchy h JOIN company_employees ce
ON (h.employee_id = ce.manager_id AND
h.company_id = ce.company_id AND
ce.company_id = 1))
SELECT * FROM hierarchy WHERE LEVEL <= 2 and 1=0;
WITH RECURSIVE hierarchy as (
SELECT *, 1 AS level
FROM company_employees
WHERE company_id = 1 and manager_id = 0
UNION
SELECT ce.*, (h.level+1)
FROM hierarchy h JOIN company_employees ce
ON (h.employee_id = ce.manager_id AND
h.company_id = ce.company_id AND
ce.company_id = 1 AND 1=0))
SELECT * FROM hierarchy WHERE LEVEL <= 2;
WITH RECURSIVE hierarchy as (
SELECT *, 1 AS level
FROM company_employees
WHERE company_id = 1 and manager_id = 0 AND 1=0
UNION
SELECT ce.*, (h.level+1)
FROM hierarchy h JOIN company_employees ce
ON (h.employee_id = ce.manager_id AND
h.company_id = ce.company_id AND
ce.company_id = 1))
SELECT * FROM hierarchy WHERE LEVEL <= 2;
-- window functions with where false
SELECT word_count, rank() OVER (PARTITION BY author_id ORDER BY word_count)
FROM articles_hash
WHERE author_id = 1 and 1=0;
-- complex query hitting a single shard -- complex query hitting a single shard
SELECT SELECT
count(DISTINCT CASE count(DISTINCT CASE