mirror of https://github.com/citusdata/citus.git
Merge pull request #1306 from citusdata/error_on_const_rtes
Disallow subqueries without a relation in the range table listpull/1315/head
commit
897c9852a8
|
@ -2949,6 +2949,12 @@ ErrorIfCannotPushdownSubquery(Query *subqueryTree, bool outerQueryHasLimit)
|
|||
errorDetail = "Subqueries other than from-clause subqueries are unsupported";
|
||||
}
|
||||
|
||||
if (subqueryTree->rtable == NIL)
|
||||
{
|
||||
preconditionsSatisfied = false;
|
||||
errorDetail = "Subqueries without relations are unsupported";
|
||||
}
|
||||
|
||||
if (subqueryTree->hasWindowFuncs)
|
||||
{
|
||||
preconditionsSatisfied = false;
|
||||
|
|
|
@ -871,6 +871,15 @@ MultiTaskRouterSelectQuerySupported(Query *query)
|
|||
|
||||
Assert(subquery->commandType == CMD_SELECT);
|
||||
|
||||
/* pushing down rtes without relations yields (shardCount * expectedRows) */
|
||||
if (subquery->rtable == NIL)
|
||||
{
|
||||
return DeferredError(ERRCODE_FEATURE_NOT_SUPPORTED,
|
||||
"Subqueries without relations are not allowed in "
|
||||
"INSERT ... SELECT queries",
|
||||
NULL, NULL);
|
||||
}
|
||||
|
||||
/* pushing down limit per shard would yield wrong results */
|
||||
if (subquery->limitCount != NULL)
|
||||
{
|
||||
|
|
|
@ -660,3 +660,30 @@ FROM
|
|||
WHERE users_table.value_1 < 50;
|
||||
ERROR: cannot perform distributed planning for the given modification
|
||||
DETAIL: Select query cannot be pushed down to the worker.
|
||||
-- not supported since one of the queries doesn't have a relation
|
||||
INSERT INTO agg_results (user_id, agg_time, value_2_agg)
|
||||
SELECT
|
||||
user_id,
|
||||
user_lastseen,
|
||||
array_length(event_array, 1)
|
||||
FROM (
|
||||
SELECT
|
||||
user_id,
|
||||
max(u.time) as user_lastseen,
|
||||
array_agg(event_type ORDER BY u.time) AS event_array
|
||||
FROM (
|
||||
SELECT user_id, time, value_3 as val_3
|
||||
FROM users_table
|
||||
WHERE
|
||||
user_id >= 10 AND user_id <= 70 AND
|
||||
users_table.value_1 > 10 AND users_table.value_1 < 12
|
||||
) u LEFT JOIN LATERAL (
|
||||
SELECT event_type, time
|
||||
FROM events_table, (SELECT 1 as x) as f
|
||||
WHERE user_id = u.user_id AND
|
||||
events_table.event_type > 10 AND events_table.event_type < 12
|
||||
) t ON true
|
||||
GROUP BY user_id
|
||||
) AS shard_union
|
||||
ORDER BY user_lastseen DESC;
|
||||
ERROR: Subqueries without relations are not allowed in INSERT ... SELECT queries
|
||||
|
|
|
@ -1609,5 +1609,69 @@ ORDER BY 1,2;
|
|||
(2 rows)
|
||||
|
||||
DROP FUNCTION array_index(ANYARRAY, ANYELEMENT);
|
||||
-- a not supported query due to constant range table entry
|
||||
SELECT count(*) as subquery_count
|
||||
FROM (
|
||||
SELECT
|
||||
user_id
|
||||
FROM
|
||||
users_table
|
||||
WHERE
|
||||
(value_1 = '5' OR value_1 = '13')
|
||||
GROUP BY user_id
|
||||
HAVING count(distinct value_1) = 2
|
||||
) as a
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
1 as user_id
|
||||
) AS b
|
||||
ON a.user_id = b.user_id
|
||||
WHERE b.user_id IS NULL
|
||||
GROUP BY a.user_id;
|
||||
ERROR: cannot push down this subquery
|
||||
DETAIL: Subqueries without relations are unsupported
|
||||
-- same with INNER JOIN
|
||||
SELECT count(*) as subquery_count
|
||||
FROM (
|
||||
SELECT
|
||||
user_id
|
||||
FROM
|
||||
users_table
|
||||
WHERE
|
||||
(value_1 = '5' OR value_1 = '13')
|
||||
GROUP BY user_id
|
||||
HAVING count(distinct value_1) = 2
|
||||
) as a
|
||||
INNER JOIN (
|
||||
SELECT
|
||||
1 as user_id
|
||||
) AS b
|
||||
ON a.user_id = b.user_id
|
||||
WHERE b.user_id IS NULL
|
||||
GROUP BY a.user_id;
|
||||
ERROR: cannot push down this subquery
|
||||
DETAIL: Subqueries without relations are unsupported
|
||||
-- this is slightly different, we use RTE_VALUEs here
|
||||
SELECT Count(*) AS subquery_count
|
||||
FROM (SELECT
|
||||
user_id
|
||||
FROM
|
||||
users_table
|
||||
WHERE
|
||||
(value_1 = '5' OR value_1 = '13' )
|
||||
GROUP BY
|
||||
user_id
|
||||
HAVING
|
||||
Count(DISTINCT value_1) = 2) AS a
|
||||
INNER JOIN
|
||||
(SELECT
|
||||
*
|
||||
FROM
|
||||
(VALUES (1, 'one'), (2, 'two'), (3, 'three')) AS t (user_id, letter)) AS b
|
||||
ON a.user_id = b.user_id
|
||||
WHERE b.user_id IS NULL
|
||||
GROUP BY a.user_id;
|
||||
ERROR: cannot push down this subquery
|
||||
DETAIL: Table expressions other than simple relations and subqueries are currently unsupported
|
||||
SET citus.subquery_pushdown TO FALSE;
|
||||
SET citus.enable_router_execution TO TRUE;
|
||||
|
|
|
@ -2027,5 +2027,91 @@ ORDER BY 1,
|
|||
2 limit 10;
|
||||
ERROR: cannot push down this subquery
|
||||
DETAIL: Window functions are currently unsupported
|
||||
-- not supported due to non relation rte
|
||||
SELECT ("final_query"."event_types") as types, count(*) AS sumOfEventType
|
||||
FROM
|
||||
( SELECT *, random()
|
||||
FROM
|
||||
( SELECT "t"."user_id",
|
||||
"t"."time",
|
||||
unnest("t"."collected_events") AS "event_types"
|
||||
FROM
|
||||
( SELECT "t1"."user_id",
|
||||
min("t1"."time") AS "time",
|
||||
array_agg(("t1"."event") ORDER BY time ASC, event DESC) AS collected_events
|
||||
FROM (
|
||||
(SELECT *
|
||||
FROM
|
||||
(SELECT "events"."user_id", "events"."time", 0 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (10, 11, 12, 13, 14, 15) ) events_subquery_1)
|
||||
UNION
|
||||
(SELECT *
|
||||
FROM
|
||||
(SELECT "events"."user_id", "events"."time", 1 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (15, 16, 17, 18, 19) ) events_subquery_2)
|
||||
UNION
|
||||
(SELECT *
|
||||
FROM
|
||||
(SELECT "events"."user_id", "events"."time", 2 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (20, 21, 22, 23, 24, 25) ) events_subquery_3)
|
||||
UNION
|
||||
(SELECT *
|
||||
FROM
|
||||
(SELECT 1, now(), 3 AS event) events_subquery_4)) t1
|
||||
GROUP BY "t1"."user_id") AS t) "q"
|
||||
INNER JOIN
|
||||
(SELECT "users"."user_id"
|
||||
FROM users_table as "users"
|
||||
WHERE value_1 > 50 and value_1 < 70) AS t ON (t.user_id = q.user_id)) as final_query
|
||||
GROUP BY types
|
||||
ORDER BY types;
|
||||
ERROR: cannot push down this subquery
|
||||
DETAIL: Subqueries without relations are unsupported
|
||||
-- similar to the above, but constant rte is on the right side of the query
|
||||
SELECT ("final_query"."event_types") as types, count(*) AS sumOfEventType
|
||||
FROM
|
||||
( SELECT *, random()
|
||||
FROM
|
||||
( SELECT "t"."user_id",
|
||||
"t"."time",
|
||||
unnest("t"."collected_events") AS "event_types"
|
||||
FROM
|
||||
( SELECT "t1"."user_id",
|
||||
min("t1"."time") AS "time",
|
||||
array_agg(("t1"."event") ORDER BY time ASC, event DESC) AS collected_events
|
||||
FROM (
|
||||
(SELECT *
|
||||
FROM
|
||||
(SELECT "events"."user_id", "events"."time", 0 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (10, 11, 12, 13, 14, 15) ) events_subquery_1)
|
||||
UNION ALL
|
||||
(SELECT *
|
||||
FROM
|
||||
(SELECT "events"."user_id", "events"."time", 1 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (15, 16, 17, 18, 19) ) events_subquery_2)
|
||||
UNION ALL
|
||||
(SELECT *
|
||||
FROM
|
||||
(SELECT "events"."user_id", "events"."time", 2 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (20, 21, 22, 23, 24, 25) ) events_subquery_3)
|
||||
UNION ALL
|
||||
(SELECT *
|
||||
FROM
|
||||
(SELECT "events"."user_id", "events"."time", 3 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (26, 27, 28, 29, 30, 13)) events_subquery_4)) t1
|
||||
GROUP BY "t1"."user_id") AS t) "q"
|
||||
INNER JOIN
|
||||
(SELECT random()::int as user_id) AS t ON (t.user_id = q.user_id)) as final_query
|
||||
GROUP BY types
|
||||
ORDER BY types;
|
||||
ERROR: cannot push down this subquery
|
||||
DETAIL: Subqueries without relations are unsupported
|
||||
SET citus.subquery_pushdown TO FALSE;
|
||||
SET citus.enable_router_execution TO TRUE;
|
||||
|
|
|
@ -773,5 +773,77 @@ FROM
|
|||
) b;
|
||||
ERROR: cannot pushdown the subquery since all leaves of the UNION does not include partition key at the same position
|
||||
DETAIL: Each leaf query of the UNION should return partition key at the same position on its target list.
|
||||
-- we don't support subqueries without relations
|
||||
SELECT
|
||||
count(*)
|
||||
FROM
|
||||
(
|
||||
(SELECT user_id FROM users_table)
|
||||
UNION ALL
|
||||
(SELECT 1)
|
||||
) b;
|
||||
ERROR: cannot push down this subquery
|
||||
DETAIL: Subqueries without relations are unsupported
|
||||
-- we don't support subqueries without relations
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
(
|
||||
(SELECT user_id FROM users_table)
|
||||
UNION ALL
|
||||
(SELECT (random() * 100)::int)
|
||||
) b;
|
||||
ERROR: cannot push down this subquery
|
||||
DETAIL: Subqueries without relations are unsupported
|
||||
-- we don't support subqueries without relations
|
||||
SELECT
|
||||
user_id, value_3
|
||||
FROM
|
||||
(
|
||||
(SELECT value_3, user_id FROM events_table where event_type IN (1, 2, 3, 4, 5))
|
||||
UNION ALL
|
||||
(SELECT value_3, user_id FROM events_table where event_type IN (6, 7, 8, 9, 10))
|
||||
UNION ALL
|
||||
(SELECT value_3, user_id FROM events_table where event_type IN (11, 12, 13, 14, 15))
|
||||
UNION ALL
|
||||
(SELECT value_3, user_id FROM events_table where event_type IN (16, 17, 18, 19, 20))
|
||||
UNION ALL
|
||||
(SELECT value_3, user_id FROM events_table where event_type IN (21, 22, 23, 24, 25))
|
||||
UNION ALL
|
||||
(SELECT 1, 2)
|
||||
) b
|
||||
ORDER BY 1 DESC, 2 DESC
|
||||
LIMIT 5;
|
||||
ERROR: cannot push down this subquery
|
||||
DETAIL: Subqueries without relations are unsupported
|
||||
SELECT ("q"."event_types") as types, count(*) AS sumOfEventType
|
||||
FROM
|
||||
( SELECT "t"."user_id",
|
||||
"t"."time",
|
||||
unnest("t"."collected_events") AS "event_types"
|
||||
FROM
|
||||
( SELECT "t1"."user_id",
|
||||
min("t1"."time") AS "time",
|
||||
array_agg(("t1"."event") ORDER BY time ASC, event DESC) AS collected_events
|
||||
FROM (
|
||||
(SELECT "events"."user_id", "events"."time", 0 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (10, 11, 12, 13, 14, 15)
|
||||
)
|
||||
UNION
|
||||
(SELECT "events"."user_id", "events"."time", 1 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (15, 16, 17, 18, 19) )
|
||||
UNION
|
||||
(SELECT "events"."user_id", "events"."time", 2 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (20, 21, 22, 23, 24, 25) )
|
||||
UNION
|
||||
(SELECT 1, now(), 3 AS event)) t1
|
||||
GROUP BY "t1"."user_id") AS t) "q"
|
||||
GROUP BY types
|
||||
ORDER BY types;
|
||||
ERROR: cannot push down this subquery
|
||||
DETAIL: Subqueries without relations are unsupported
|
||||
SET citus.subquery_pushdown TO false;
|
||||
SET citus.enable_router_execution TO true;
|
||||
|
|
|
@ -649,3 +649,30 @@ FROM
|
|||
) temp
|
||||
ON users_table.user_id = temp.user_id
|
||||
WHERE users_table.value_1 < 50;
|
||||
|
||||
-- not supported since one of the queries doesn't have a relation
|
||||
INSERT INTO agg_results (user_id, agg_time, value_2_agg)
|
||||
SELECT
|
||||
user_id,
|
||||
user_lastseen,
|
||||
array_length(event_array, 1)
|
||||
FROM (
|
||||
SELECT
|
||||
user_id,
|
||||
max(u.time) as user_lastseen,
|
||||
array_agg(event_type ORDER BY u.time) AS event_array
|
||||
FROM (
|
||||
SELECT user_id, time, value_3 as val_3
|
||||
FROM users_table
|
||||
WHERE
|
||||
user_id >= 10 AND user_id <= 70 AND
|
||||
users_table.value_1 > 10 AND users_table.value_1 < 12
|
||||
) u LEFT JOIN LATERAL (
|
||||
SELECT event_type, time
|
||||
FROM events_table, (SELECT 1 as x) as f
|
||||
WHERE user_id = u.user_id AND
|
||||
events_table.event_type > 10 AND events_table.event_type < 12
|
||||
) t ON true
|
||||
GROUP BY user_id
|
||||
) AS shard_union
|
||||
ORDER BY user_lastseen DESC;
|
||||
|
|
|
@ -1285,6 +1285,66 @@ SELECT * FROM run_command_on_workers('DROP FUNCTION array_index(ANYARRAY, ANYELE
|
|||
ORDER BY 1,2;
|
||||
DROP FUNCTION array_index(ANYARRAY, ANYELEMENT);
|
||||
|
||||
-- a not supported query due to constant range table entry
|
||||
SELECT count(*) as subquery_count
|
||||
FROM (
|
||||
SELECT
|
||||
user_id
|
||||
FROM
|
||||
users_table
|
||||
WHERE
|
||||
(value_1 = '5' OR value_1 = '13')
|
||||
GROUP BY user_id
|
||||
HAVING count(distinct value_1) = 2
|
||||
) as a
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
1 as user_id
|
||||
) AS b
|
||||
ON a.user_id = b.user_id
|
||||
WHERE b.user_id IS NULL
|
||||
GROUP BY a.user_id;
|
||||
|
||||
-- same with INNER JOIN
|
||||
SELECT count(*) as subquery_count
|
||||
FROM (
|
||||
SELECT
|
||||
user_id
|
||||
FROM
|
||||
users_table
|
||||
WHERE
|
||||
(value_1 = '5' OR value_1 = '13')
|
||||
GROUP BY user_id
|
||||
HAVING count(distinct value_1) = 2
|
||||
) as a
|
||||
INNER JOIN (
|
||||
SELECT
|
||||
1 as user_id
|
||||
) AS b
|
||||
ON a.user_id = b.user_id
|
||||
WHERE b.user_id IS NULL
|
||||
GROUP BY a.user_id;
|
||||
|
||||
-- this is slightly different, we use RTE_VALUEs here
|
||||
SELECT Count(*) AS subquery_count
|
||||
FROM (SELECT
|
||||
user_id
|
||||
FROM
|
||||
users_table
|
||||
WHERE
|
||||
(value_1 = '5' OR value_1 = '13' )
|
||||
GROUP BY
|
||||
user_id
|
||||
HAVING
|
||||
Count(DISTINCT value_1) = 2) AS a
|
||||
INNER JOIN
|
||||
(SELECT
|
||||
*
|
||||
FROM
|
||||
(VALUES (1, 'one'), (2, 'two'), (3, 'three')) AS t (user_id, letter)) AS b
|
||||
ON a.user_id = b.user_id
|
||||
WHERE b.user_id IS NULL
|
||||
GROUP BY a.user_id;
|
||||
|
||||
SET citus.subquery_pushdown TO FALSE;
|
||||
SET citus.enable_router_execution TO TRUE;
|
||||
|
|
|
@ -1786,5 +1786,89 @@ FROM (
|
|||
ORDER BY 1,
|
||||
2 limit 10;
|
||||
|
||||
-- not supported due to non relation rte
|
||||
SELECT ("final_query"."event_types") as types, count(*) AS sumOfEventType
|
||||
FROM
|
||||
( SELECT *, random()
|
||||
FROM
|
||||
( SELECT "t"."user_id",
|
||||
"t"."time",
|
||||
unnest("t"."collected_events") AS "event_types"
|
||||
FROM
|
||||
( SELECT "t1"."user_id",
|
||||
min("t1"."time") AS "time",
|
||||
array_agg(("t1"."event") ORDER BY time ASC, event DESC) AS collected_events
|
||||
FROM (
|
||||
(SELECT *
|
||||
FROM
|
||||
(SELECT "events"."user_id", "events"."time", 0 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (10, 11, 12, 13, 14, 15) ) events_subquery_1)
|
||||
UNION
|
||||
(SELECT *
|
||||
FROM
|
||||
(SELECT "events"."user_id", "events"."time", 1 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (15, 16, 17, 18, 19) ) events_subquery_2)
|
||||
UNION
|
||||
(SELECT *
|
||||
FROM
|
||||
(SELECT "events"."user_id", "events"."time", 2 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (20, 21, 22, 23, 24, 25) ) events_subquery_3)
|
||||
UNION
|
||||
(SELECT *
|
||||
FROM
|
||||
(SELECT 1, now(), 3 AS event) events_subquery_4)) t1
|
||||
GROUP BY "t1"."user_id") AS t) "q"
|
||||
INNER JOIN
|
||||
(SELECT "users"."user_id"
|
||||
FROM users_table as "users"
|
||||
WHERE value_1 > 50 and value_1 < 70) AS t ON (t.user_id = q.user_id)) as final_query
|
||||
GROUP BY types
|
||||
ORDER BY types;
|
||||
|
||||
-- similar to the above, but constant rte is on the right side of the query
|
||||
SELECT ("final_query"."event_types") as types, count(*) AS sumOfEventType
|
||||
FROM
|
||||
( SELECT *, random()
|
||||
FROM
|
||||
( SELECT "t"."user_id",
|
||||
"t"."time",
|
||||
unnest("t"."collected_events") AS "event_types"
|
||||
FROM
|
||||
( SELECT "t1"."user_id",
|
||||
min("t1"."time") AS "time",
|
||||
array_agg(("t1"."event") ORDER BY time ASC, event DESC) AS collected_events
|
||||
FROM (
|
||||
(SELECT *
|
||||
FROM
|
||||
(SELECT "events"."user_id", "events"."time", 0 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (10, 11, 12, 13, 14, 15) ) events_subquery_1)
|
||||
UNION ALL
|
||||
(SELECT *
|
||||
FROM
|
||||
(SELECT "events"."user_id", "events"."time", 1 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (15, 16, 17, 18, 19) ) events_subquery_2)
|
||||
UNION ALL
|
||||
(SELECT *
|
||||
FROM
|
||||
(SELECT "events"."user_id", "events"."time", 2 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (20, 21, 22, 23, 24, 25) ) events_subquery_3)
|
||||
UNION ALL
|
||||
(SELECT *
|
||||
FROM
|
||||
(SELECT "events"."user_id", "events"."time", 3 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (26, 27, 28, 29, 30, 13)) events_subquery_4)) t1
|
||||
GROUP BY "t1"."user_id") AS t) "q"
|
||||
INNER JOIN
|
||||
(SELECT random()::int as user_id) AS t ON (t.user_id = q.user_id)) as final_query
|
||||
GROUP BY types
|
||||
ORDER BY types;
|
||||
|
||||
SET citus.subquery_pushdown TO FALSE;
|
||||
SET citus.enable_router_execution TO TRUE;
|
||||
|
|
|
@ -605,5 +605,73 @@ FROM
|
|||
(SELECT users_table.user_id FROM events_table, users_table WHERE events_table.user_id = users_table.user_id)
|
||||
) b;
|
||||
|
||||
-- we don't support subqueries without relations
|
||||
SELECT
|
||||
count(*)
|
||||
FROM
|
||||
(
|
||||
(SELECT user_id FROM users_table)
|
||||
UNION ALL
|
||||
(SELECT 1)
|
||||
) b;
|
||||
|
||||
-- we don't support subqueries without relations
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
(
|
||||
(SELECT user_id FROM users_table)
|
||||
UNION ALL
|
||||
(SELECT (random() * 100)::int)
|
||||
) b;
|
||||
|
||||
-- we don't support subqueries without relations
|
||||
SELECT
|
||||
user_id, value_3
|
||||
FROM
|
||||
(
|
||||
(SELECT value_3, user_id FROM events_table where event_type IN (1, 2, 3, 4, 5))
|
||||
UNION ALL
|
||||
(SELECT value_3, user_id FROM events_table where event_type IN (6, 7, 8, 9, 10))
|
||||
UNION ALL
|
||||
(SELECT value_3, user_id FROM events_table where event_type IN (11, 12, 13, 14, 15))
|
||||
UNION ALL
|
||||
(SELECT value_3, user_id FROM events_table where event_type IN (16, 17, 18, 19, 20))
|
||||
UNION ALL
|
||||
(SELECT value_3, user_id FROM events_table where event_type IN (21, 22, 23, 24, 25))
|
||||
UNION ALL
|
||||
(SELECT 1, 2)
|
||||
) b
|
||||
ORDER BY 1 DESC, 2 DESC
|
||||
LIMIT 5;
|
||||
|
||||
SELECT ("q"."event_types") as types, count(*) AS sumOfEventType
|
||||
FROM
|
||||
( SELECT "t"."user_id",
|
||||
"t"."time",
|
||||
unnest("t"."collected_events") AS "event_types"
|
||||
FROM
|
||||
( SELECT "t1"."user_id",
|
||||
min("t1"."time") AS "time",
|
||||
array_agg(("t1"."event") ORDER BY time ASC, event DESC) AS collected_events
|
||||
FROM (
|
||||
(SELECT "events"."user_id", "events"."time", 0 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (10, 11, 12, 13, 14, 15)
|
||||
)
|
||||
UNION
|
||||
(SELECT "events"."user_id", "events"."time", 1 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (15, 16, 17, 18, 19) )
|
||||
UNION
|
||||
(SELECT "events"."user_id", "events"."time", 2 AS event
|
||||
FROM events_table as "events"
|
||||
WHERE event_type IN (20, 21, 22, 23, 24, 25) )
|
||||
UNION
|
||||
(SELECT 1, now(), 3 AS event)) t1
|
||||
GROUP BY "t1"."user_id") AS t) "q"
|
||||
GROUP BY types
|
||||
ORDER BY types;
|
||||
|
||||
SET citus.subquery_pushdown TO false;
|
||||
SET citus.enable_router_execution TO true;
|
||||
|
|
Loading…
Reference in New Issue