2025-02-13 20:43:42 +01:00
|
|
|
# title: single table
|
2025-02-13 06:15:54 +01:00
|
|
|
SELECT 1 FROM z;
|
|
|
|
SELECT 1 FROM c.db.z AS z;
|
|
|
|
|
2025-02-13 20:43:42 +01:00
|
|
|
# title: single table with db
|
2025-02-13 06:15:54 +01:00
|
|
|
SELECT 1 FROM y.z;
|
|
|
|
SELECT 1 FROM c.y.z AS z;
|
|
|
|
|
2025-02-13 20:43:42 +01:00
|
|
|
# title: single table with db, catalog
|
2025-02-13 06:15:54 +01:00
|
|
|
SELECT 1 FROM x.y.z;
|
|
|
|
SELECT 1 FROM x.y.z AS z;
|
|
|
|
|
2025-02-13 20:43:42 +01:00
|
|
|
# title: single table with db, catalog, alias
|
2025-02-13 06:15:54 +01:00
|
|
|
SELECT 1 FROM x.y.z AS z;
|
|
|
|
SELECT 1 FROM x.y.z AS z;
|
|
|
|
|
2025-02-13 21:56:11 +01:00
|
|
|
# title: only information schema
|
|
|
|
# dialect: bigquery
|
|
|
|
SELECT * FROM information_schema.tables;
|
|
|
|
SELECT * FROM c.db.`information_schema.tables` AS tables;
|
|
|
|
|
|
|
|
# title: information schema with db
|
|
|
|
# dialect: bigquery
|
|
|
|
SELECT * FROM y.information_schema.tables;
|
|
|
|
SELECT * FROM c.y.`information_schema.tables` AS tables;
|
|
|
|
|
|
|
|
# title: information schema with db, catalog
|
|
|
|
# dialect: bigquery
|
|
|
|
SELECT * FROM x.y.information_schema.tables;
|
|
|
|
SELECT * FROM x.y.`information_schema.tables` AS tables;
|
|
|
|
|
|
|
|
# title: information schema with db, catalog, alias
|
|
|
|
# dialect: bigquery
|
|
|
|
SELECT * FROM x.y.information_schema.tables AS z;
|
|
|
|
SELECT * FROM x.y.`information_schema.tables` AS z;
|
|
|
|
|
2025-02-13 21:18:57 +01:00
|
|
|
# title: redshift unnest syntax, z.a should be a column, not a table
|
|
|
|
# dialect: redshift
|
|
|
|
SELECT 1 FROM y.z AS z, z.a;
|
|
|
|
SELECT 1 FROM c.y.z AS z, z.a;
|
|
|
|
|
2025-02-13 21:29:15 +01:00
|
|
|
# title: bigquery implicit unnest syntax, coordinates.position should be a column, not a table
|
|
|
|
# dialect: bigquery
|
|
|
|
SELECT results FROM Coordinates, coordinates.position AS results;
|
|
|
|
SELECT results FROM c.db.Coordinates AS Coordinates, UNNEST(coordinates.position) AS results;
|
|
|
|
|
|
|
|
# title: bigquery implicit unnest syntax, table is already qualified
|
|
|
|
# dialect: bigquery
|
|
|
|
SELECT results FROM db.coordinates, Coordinates.position AS results;
|
|
|
|
SELECT results FROM c.db.coordinates AS coordinates, UNNEST(Coordinates.position) AS results;
|
|
|
|
|
|
|
|
# title: bigquery schema name clashes with CTE name - this is a join, not an implicit unnest
|
|
|
|
# dialect: bigquery
|
|
|
|
WITH Coordinates AS (SELECT [1, 2] AS position) SELECT results FROM Coordinates, `Coordinates.position` AS results;
|
|
|
|
WITH Coordinates AS (SELECT [1, 2] AS position) SELECT results FROM Coordinates AS Coordinates, `c.Coordinates.position` AS results;
|
|
|
|
|
2025-02-13 21:19:36 +01:00
|
|
|
# title: single cte
|
2025-02-13 06:15:54 +01:00
|
|
|
WITH a AS (SELECT 1 FROM z) SELECT 1 FROM a;
|
2025-02-13 21:19:36 +01:00
|
|
|
WITH a AS (SELECT 1 FROM c.db.z AS z) SELECT 1 FROM a AS a;
|
|
|
|
|
|
|
|
# title: two ctes that are self-joined
|
|
|
|
WITH a AS (SELECT 1 FROM z) SELECT 1 FROM a CROSS JOIN a;
|
|
|
|
WITH a AS (SELECT 1 FROM c.db.z AS z) SELECT 1 FROM a AS a CROSS JOIN a AS a;
|
2025-02-13 06:15:54 +01:00
|
|
|
|
2025-02-13 20:43:42 +01:00
|
|
|
# title: query that yields a single column as projection
|
2025-02-13 06:15:54 +01:00
|
|
|
SELECT (SELECT y.c FROM y AS y) FROM x;
|
|
|
|
SELECT (SELECT y.c FROM c.db.y AS y) FROM c.db.x AS x;
|
2025-02-13 15:52:54 +01:00
|
|
|
|
2025-02-13 20:43:42 +01:00
|
|
|
# title: pivoted table
|
2025-02-13 15:56:32 +01:00
|
|
|
SELECT * FROM x PIVOT (SUM(a) FOR b IN ('a', 'b'));
|
|
|
|
SELECT * FROM c.db.x AS x PIVOT(SUM(a) FOR b IN ('a', 'b')) AS _q_0;
|
|
|
|
|
2025-02-13 21:18:57 +01:00
|
|
|
# title: pivoted table, pivot has alias
|
|
|
|
SELECT * FROM x PIVOT (SUM(a) FOR b IN ('a', 'b')) AS piv;
|
|
|
|
SELECT * FROM c.db.x AS x PIVOT(SUM(a) FOR b IN ('a', 'b')) AS piv;
|
|
|
|
|
2025-02-13 20:43:42 +01:00
|
|
|
# title: wrapped table without alias
|
|
|
|
SELECT * FROM (tbl);
|
2025-02-13 20:44:53 +01:00
|
|
|
SELECT * FROM (c.db.tbl AS tbl);
|
2025-02-13 20:43:42 +01:00
|
|
|
|
|
|
|
# title: wrapped table with alias
|
|
|
|
SELECT * FROM (tbl AS tbl);
|
2025-02-13 20:44:53 +01:00
|
|
|
SELECT * FROM (c.db.tbl AS tbl);
|
2025-02-13 20:43:42 +01:00
|
|
|
|
2025-02-13 20:44:53 +01:00
|
|
|
# title: wrapped table with alias using multiple (redundant) parentheses
|
2025-02-13 20:43:42 +01:00
|
|
|
SELECT * FROM ((((tbl AS tbl))));
|
2025-02-13 20:44:53 +01:00
|
|
|
SELECT * FROM ((((c.db.tbl AS tbl))));
|
|
|
|
|
|
|
|
# title: wrapped join of tables without alias
|
|
|
|
SELECT * FROM (t1 CROSS JOIN t2);
|
|
|
|
SELECT * FROM (c.db.t1 AS t1 CROSS JOIN c.db.t2 AS t2);
|
|
|
|
|
|
|
|
# title: wrapped join of tables with alias, expansion of join construct
|
|
|
|
SELECT * FROM (t1 CROSS JOIN t2) AS t;
|
|
|
|
SELECT * FROM (SELECT * FROM c.db.t1 AS t1 CROSS JOIN c.db.t2 AS t2) AS t;
|
2025-02-13 20:43:42 +01:00
|
|
|
|
|
|
|
# title: chained wrapped joins without aliases (1)
|
|
|
|
SELECT * FROM ((a CROSS JOIN b) CROSS JOIN c);
|
2025-02-13 20:44:53 +01:00
|
|
|
SELECT * FROM ((c.db.a AS a CROSS JOIN c.db.b AS b) CROSS JOIN c.db.c AS c);
|
2025-02-13 20:43:42 +01:00
|
|
|
|
|
|
|
# title: chained wrapped joins without aliases (2)
|
|
|
|
SELECT * FROM (a CROSS JOIN (b CROSS JOIN c));
|
2025-02-13 20:44:53 +01:00
|
|
|
SELECT * FROM (c.db.a AS a CROSS JOIN (c.db.b AS b CROSS JOIN c.db.c AS c));
|
2025-02-13 20:43:42 +01:00
|
|
|
|
|
|
|
# title: chained wrapped joins without aliases (3)
|
|
|
|
SELECT * FROM ((a CROSS JOIN ((b CROSS JOIN c) CROSS JOIN d)));
|
2025-02-13 20:44:53 +01:00
|
|
|
SELECT * FROM ((c.db.a AS a CROSS JOIN ((c.db.b AS b CROSS JOIN c.db.c AS c) CROSS JOIN c.db.d AS d)));
|
2025-02-13 20:43:42 +01:00
|
|
|
|
|
|
|
# title: chained wrapped joins without aliases (4)
|
|
|
|
SELECT * FROM ((a CROSS JOIN ((b CROSS JOIN c) CROSS JOIN (d CROSS JOIN e))));
|
2025-02-13 20:44:53 +01:00
|
|
|
SELECT * FROM ((c.db.a AS a CROSS JOIN ((c.db.b AS b CROSS JOIN c.db.c AS c) CROSS JOIN (c.db.d AS d CROSS JOIN c.db.e AS e))));
|
2025-02-13 20:43:42 +01:00
|
|
|
|
|
|
|
# title: chained wrapped joins with aliases
|
|
|
|
SELECT * FROM ((a AS foo CROSS JOIN b AS bar) CROSS JOIN c AS baz);
|
2025-02-13 20:44:53 +01:00
|
|
|
SELECT * FROM ((c.db.a AS foo CROSS JOIN c.db.b AS bar) CROSS JOIN c.db.c AS baz);
|
2025-02-13 20:43:42 +01:00
|
|
|
|
|
|
|
# title: wrapped join with subquery without alias
|
|
|
|
SELECT * FROM (tbl1 CROSS JOIN (SELECT * FROM tbl2) AS t1);
|
2025-02-13 20:44:53 +01:00
|
|
|
SELECT * FROM (c.db.tbl1 AS tbl1 CROSS JOIN (SELECT * FROM c.db.tbl2 AS tbl2) AS t1);
|
2025-02-13 20:43:42 +01:00
|
|
|
|
2025-02-13 21:29:15 +01:00
|
|
|
# title: wrapped join with subquery with alias, parentheses cant be omitted because of alias
|
2025-02-13 20:43:42 +01:00
|
|
|
SELECT * FROM (tbl1 CROSS JOIN (SELECT * FROM tbl2) AS t1) AS t2;
|
|
|
|
SELECT * FROM (SELECT * FROM c.db.tbl1 AS tbl1 CROSS JOIN (SELECT * FROM c.db.tbl2 AS tbl2) AS t1) AS t2;
|
|
|
|
|
|
|
|
# title: join construct as the right operand of a left join
|
|
|
|
SELECT * FROM a LEFT JOIN (b INNER JOIN c ON c.id = b.id) ON b.id = a.id;
|
2025-02-13 20:44:53 +01:00
|
|
|
SELECT * FROM c.db.a AS a LEFT JOIN (c.db.b AS b INNER JOIN c.db.c AS c ON c.id = b.id) ON b.id = a.id;
|
2025-02-13 20:43:42 +01:00
|
|
|
|
2025-02-13 20:44:53 +01:00
|
|
|
# title: nested joins
|
2025-02-13 20:43:42 +01:00
|
|
|
SELECT * FROM a LEFT JOIN b INNER JOIN c ON c.id = b.id ON b.id = a.id;
|
2025-02-13 20:44:53 +01:00
|
|
|
SELECT * FROM c.db.a AS a LEFT JOIN c.db.b AS b INNER JOIN c.db.c AS c ON c.id = b.id ON b.id = a.id;
|
2025-02-13 20:43:42 +01:00
|
|
|
|
2025-02-13 21:29:15 +01:00
|
|
|
# title: parentheses cant be omitted because alias shadows inner table names
|
2025-02-13 20:43:42 +01:00
|
|
|
SELECT t.a FROM (tbl AS tbl) AS t;
|
|
|
|
SELECT t.a FROM (SELECT * FROM c.db.tbl AS tbl) AS t;
|
2025-02-13 15:52:54 +01:00
|
|
|
|
2025-02-13 20:44:53 +01:00
|
|
|
# title: wrapped aliased table with outer alias
|
2025-02-13 20:43:42 +01:00
|
|
|
SELECT * FROM ((((tbl AS tbl)))) AS _q_0;
|
2025-02-13 15:52:54 +01:00
|
|
|
SELECT * FROM (SELECT * FROM c.db.tbl AS tbl) AS _q_0;
|
|
|
|
|
2025-02-13 20:44:53 +01:00
|
|
|
# title: join construct with three tables
|
2025-02-13 15:52:54 +01:00
|
|
|
SELECT * FROM (tbl1 AS tbl1 JOIN tbl2 AS tbl2 ON id1 = id2 JOIN tbl3 AS tbl3 ON id1 = id3) AS _q_0;
|
|
|
|
SELECT * FROM (SELECT * FROM c.db.tbl1 AS tbl1 JOIN c.db.tbl2 AS tbl2 ON id1 = id2 JOIN c.db.tbl3 AS tbl3 ON id1 = id3) AS _q_0;
|
|
|
|
|
2025-02-13 20:44:53 +01:00
|
|
|
# title: join construct with three tables and redundant set of parentheses
|
2025-02-13 15:52:54 +01:00
|
|
|
SELECT * FROM ((tbl1 AS tbl1 JOIN tbl2 AS tbl2 ON id1 = id2 JOIN tbl3 AS tbl3 ON id1 = id3)) AS _q_0;
|
|
|
|
SELECT * FROM (SELECT * FROM c.db.tbl1 AS tbl1 JOIN c.db.tbl2 AS tbl2 ON id1 = id2 JOIN c.db.tbl3 AS tbl3 ON id1 = id3) AS _q_0;
|
|
|
|
|
2025-02-13 20:44:53 +01:00
|
|
|
# title: join construct within join construct
|
2025-02-13 15:52:54 +01:00
|
|
|
SELECT * FROM (tbl1 AS tbl1 JOIN (tbl2 AS tbl2 JOIN tbl3 AS tbl3 ON id2 = id3) AS _q_0 ON id1 = id3) AS _q_1;
|
|
|
|
SELECT * FROM (SELECT * FROM c.db.tbl1 AS tbl1 JOIN (SELECT * FROM c.db.tbl2 AS tbl2 JOIN c.db.tbl3 AS tbl3 ON id2 = id3) AS _q_0 ON id1 = id3) AS _q_1;
|
2025-02-13 20:46:23 +01:00
|
|
|
|
|
|
|
# title: wrapped subquery without alias
|
|
|
|
SELECT * FROM ((SELECT * FROM t));
|
|
|
|
SELECT * FROM ((SELECT * FROM c.db.t AS t) AS _q_0);
|
|
|
|
|
|
|
|
# title: wrapped subquery without alias joined with a table
|
|
|
|
SELECT * FROM ((SELECT * FROM t1) INNER JOIN t2 ON a = b);
|
|
|
|
SELECT * FROM ((SELECT * FROM c.db.t1 AS t1) AS _q_0 INNER JOIN c.db.t2 AS t2 ON a = b);
|
2025-02-13 21:08:47 +01:00
|
|
|
|
|
|
|
# title: lateral unnest with alias
|
|
|
|
SELECT x FROM t, LATERAL UNNEST(t.xs) AS x;
|
|
|
|
SELECT x FROM c.db.t AS t, LATERAL UNNEST(t.xs) AS x;
|
|
|
|
|
|
|
|
# title: lateral unnest without alias
|
|
|
|
SELECT x FROM t, LATERAL UNNEST(t.xs);
|
|
|
|
SELECT x FROM c.db.t AS t, LATERAL UNNEST(t.xs) AS _q_0;
|
2025-02-13 21:15:38 +01:00
|
|
|
|
|
|
|
# title: table with ordinality
|
|
|
|
SELECT * FROM t CROSS JOIN JSON_ARRAY_ELEMENTS(t.response) WITH ORDINALITY AS kv_json;
|
|
|
|
SELECT * FROM c.db.t AS t CROSS JOIN JSON_ARRAY_ELEMENTS(t.response) WITH ORDINALITY AS kv_json;
|
2025-02-13 21:19:36 +01:00
|
|
|
|
|
|
|
# title: alter table
|
|
|
|
ALTER TABLE t ADD PRIMARY KEY (id) NOT ENFORCED;
|
|
|
|
ALTER TABLE c.db.t ADD PRIMARY KEY (id) NOT ENFORCED;
|
|
|
|
|
|
|
|
# title: create statement with cte
|
|
|
|
CREATE TABLE t1 AS (WITH cte AS (SELECT x FROM t2) SELECT * FROM cte);
|
|
|
|
CREATE TABLE c.db.t1 AS (WITH cte AS (SELECT x FROM c.db.t2 AS t2) SELECT * FROM cte AS cte);
|
|
|
|
|
2025-02-13 21:33:03 +01:00
|
|
|
# title: delete statement
|
|
|
|
DELETE FROM t1 WHERE NOT c IN (SELECT c FROM t2);
|
|
|
|
DELETE FROM c.db.t1 WHERE NOT c IN (SELECT c FROM c.db.t2 AS t2);
|
|
|
|
|
2025-02-13 21:19:36 +01:00
|
|
|
# title: insert statement with cte
|
2025-02-13 21:30:02 +01:00
|
|
|
# dialect: spark
|
2025-02-13 21:19:36 +01:00
|
|
|
WITH cte AS (SELECT b FROM y) INSERT INTO s SELECT * FROM cte;
|
|
|
|
WITH cte AS (SELECT b FROM c.db.y AS y) INSERT INTO c.db.s SELECT * FROM cte AS cte;
|
2025-02-13 21:29:15 +01:00
|
|
|
|
|
|
|
# title: qualify wrapped query
|
|
|
|
(SELECT x FROM t);
|
|
|
|
(SELECT x FROM c.db.t AS t);
|
2025-02-13 21:31:00 +01:00
|
|
|
|
|
|
|
# title: replace columns with db/catalog refs
|
|
|
|
SELECT db1.a.id, db2.a.id FROM db1.a JOIN db2.a ON db1.a.id = db2.a.id;
|
|
|
|
SELECT a.id, a_2.id FROM c.db1.a AS a JOIN c.db2.a AS a_2 ON a.id = a_2.id;
|
|
|
|
|
|
|
|
SELECT cat.db1.a.id, db2.a.id FROM cat.db1.a JOIN db2.a ON cat.db1.a.id = db2.a.id;
|
|
|
|
SELECT a.id, a_2.id FROM cat.db1.a AS a JOIN c.db2.a AS a_2 ON a.id = a_2.id;
|
2025-02-13 21:42:48 +01:00
|
|
|
|
|
|
|
COPY INTO (SELECT * FROM x) TO 'data' WITH (FORMAT 'CSV');
|
|
|
|
COPY INTO (SELECT * FROM c.db.x AS x) TO 'data' WITH (FORMAT 'CSV');
|
2025-02-13 21:52:44 +01:00
|
|
|
|
|
|
|
# title: tablesample
|
|
|
|
SELECT 1 FROM x TABLESAMPLE SYSTEM (10 PERCENT) CROSS JOIN y TABLESAMPLE SYSTEM (10 PERCENT);
|
|
|
|
SELECT 1 FROM c.db.x AS x TABLESAMPLE SYSTEM (10 PERCENT) CROSS JOIN c.db.y AS y TABLESAMPLE SYSTEM (10 PERCENT);
|
2025-02-13 21:55:50 +01:00
|
|
|
|
|
|
|
WITH cte_tbl AS (SELECT 1 AS col2) UPDATE y SET col1 = (SELECT * FROM x) WHERE EXISTS(SELECT 1 FROM cte_tbl);
|
|
|
|
WITH cte_tbl AS (SELECT 1 AS col2) UPDATE c.db.y SET col1 = (SELECT * FROM c.db.x AS x) WHERE EXISTS(SELECT 1 FROM cte_tbl AS cte_tbl);
|