-
Notifications
You must be signed in to change notification settings - Fork 769
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Refactor(optimizer): improve handling of DDL optimization (#1972)
* Rebase off gtoonstra's commit * Fixups * Scope fixups, tests for insert * Test fixup * Test fixup
- Loading branch information
1 parent
9ac4550
commit 8a44cc2
Showing
4 changed files
with
83 additions
and
9 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,35 @@ | ||
# title: Create with CTE | ||
WITH cte AS (SELECT b FROM y) CREATE TABLE s AS SELECT * FROM cte; | ||
WITH cte AS (SELECT y.b AS b FROM y AS y) CREATE TABLE s AS SELECT cte.b AS b FROM cte; | ||
|
||
# title: Create without CTE | ||
CREATE TABLE foo AS SELECT a FROM tbl; | ||
CREATE TABLE foo AS SELECT tbl.a AS a FROM tbl AS tbl; | ||
|
||
# title: Create with complex CTE with derived table | ||
WITH cte AS (SELECT a FROM (SELECT a from x)) CREATE TABLE s AS SELECT * FROM cte; | ||
WITH cte AS (SELECT _q_0.a AS a FROM (SELECT x.a AS a FROM x AS x) AS _q_0) CREATE TABLE s AS SELECT cte.a AS a FROM cte; | ||
|
||
# title: Create wtih multiple CTEs | ||
WITH cte1 AS (SELECT b FROM y), cte2 AS (SELECT b FROM cte1) CREATE TABLE s AS SELECT * FROM cte2; | ||
WITH cte1 AS (SELECT y.b AS b FROM y AS y), cte2 AS (SELECT cte1.b AS b FROM cte1) CREATE TABLE s AS SELECT cte2.b AS b FROM cte2; | ||
|
||
# title: Create with multiple CTEs, selecting only from the first CTE (unnecessary code) | ||
WITH cte1 AS (SELECT b FROM y), cte2 AS (SELECT b FROM cte1) CREATE TABLE s AS SELECT * FROM cte1; | ||
WITH cte1 AS (SELECT y.b AS b FROM y AS y), cte2 AS (SELECT cte1.b AS b FROM cte1) CREATE TABLE s AS SELECT cte1.b AS b FROM cte1; | ||
|
||
# title: Create with multiple derived tables | ||
CREATE TABLE s AS SELECT * FROM (SELECT b FROM (SELECT b FROM y)); | ||
CREATE TABLE s AS SELECT _q_1.b AS b FROM (SELECT _q_0.b AS b FROM (SELECT y.b AS b FROM y AS y) AS _q_0) AS _q_1; | ||
|
||
# title: Create with a CTE and a derived table | ||
WITH cte AS (SELECT b FROM y) CREATE TABLE s AS SELECT * FROM (SELECT b FROM (SELECT b FROM cte)); | ||
WITH cte AS (SELECT y.b AS b FROM y AS y) CREATE TABLE s AS SELECT _q_1.b AS b FROM (SELECT _q_0.b AS b FROM (SELECT cte.b AS b FROM cte) AS _q_0) AS _q_1; | ||
|
||
# title: Insert with CTE | ||
WITH cte AS (SELECT b FROM y) INSERT INTO s SELECT * FROM cte; | ||
WITH cte AS (SELECT y.b AS b FROM y AS y) INSERT INTO s SELECT cte.b AS b FROM cte; | ||
|
||
# title: Insert without CTE | ||
INSERT INTO foo SELECT a FROM tbl; | ||
INSERT INTO foo SELECT tbl.a AS a FROM tbl AS tbl; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters