Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Making MERGE more robust in handling edge-cases #222

Open
wants to merge 2 commits into
base: main
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
5 changes: 3 additions & 2 deletions internal/analyzer.go
Original file line number Diff line number Diff line change
Expand Up @@ -76,6 +76,7 @@ func newAnalyzerOptions() (*zetasql.AnalyzerOptions, error) {
zetasql.FeatureV13Pivot,
zetasql.FeatureV13Unpivot,
zetasql.FeatureCreateTableAsSelectColumnList,
zetasql.FeatureV13OmitInsertColumnList,
})
langOpt.SetSupportedStatementKinds([]ast.Kind{
ast.BeginStmt,
Expand Down Expand Up @@ -583,7 +584,7 @@ func (a *Analyzer) newMergeStmtAction(ctx context.Context, _ string, args []driv
sourceColumn *ast.Column
targetColumn *ast.Column
)
if strings.Contains(sourceTable, colA.Column().TableName()) {
if strings.Contains(sourceTable, colA.Column().TableName()) && !strings.Contains(sourceTable, colB.Column().TableName()) {
sourceColumn = colA.Column()
targetColumn = colB.Column()
} else {
Expand All @@ -598,7 +599,7 @@ func (a *Analyzer) newMergeStmtAction(ctx context.Context, _ string, args []driv
}
var stmts []string
stmts = append(stmts, fmt.Sprintf(
"CREATE TABLE zetasqlite_merged_table AS SELECT DISTINCT * FROM (SELECT * FROM %[1]s LEFT JOIN %[2]s ON %[3]s UNION ALL SELECT * FROM %[2]s LEFT JOIN %[1]s ON %[3]s)",
"CREATE TABLE zetasqlite_merged_table AS SELECT DISTINCT * FROM (SELECT * FROM (%[1]s) LEFT JOIN (%[2]s) ON %[3]s UNION ALL SELECT * FROM (%[2]s) LEFT JOIN (%[1]s) ON %[3]s)",
sourceTable, targetTable, expr,
))

Expand Down
78 changes: 78 additions & 0 deletions query_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -5898,6 +5898,84 @@ SELECT * FROM table2;
`,
expectedRows: [][]interface{}{{"test"}},
},
{
name: "merge two tables with empty source",
query: `
CREATE TEMP TABLE target(id INT64, name STRING);
CREATE TEMP TABLE source(id INT64, name STRING);
MERGE target T USING source S ON T.id = S.id
WHEN MATCHED THEN UPDATE SET id = S.id, name = S.name
WHEN NOT MATCHED THEN INSERT (id, name) VALUES (id, name);
SELECT * FROM target;
`,
expectedRows: [][]interface{}{},
},
{
name: "merge two tables with non-empty source",
query: `
CREATE TEMP TABLE target(id INT64, name STRING);
CREATE TEMP TABLE source(id INT64, name STRING);
INSERT INTO source(id, name) VALUES (1, "test");
MERGE target T USING source S ON T.id = S.id
WHEN MATCHED THEN UPDATE SET id = S.id, name = S.name
WHEN NOT MATCHED THEN INSERT (id, name) VALUES (id, name);
SELECT * FROM target;
`,
expectedRows: [][]interface{}{{int64(1), "test"}},
},
{
name: "merge two tables where target table name is substring of source table name",
query: `
CREATE TEMP TABLE target(id INT64, name STRING);
CREATE TEMP TABLE tmp_target_123(id INT64, name STRING);
INSERT INTO tmp_target_123(id, name) VALUES (1, "test");
MERGE target T USING tmp_target_123 S ON T.id = S.id
WHEN MATCHED THEN UPDATE SET id = S.id, name = S.name
WHEN NOT MATCHED THEN INSERT (id, name) VALUES (id, name);
SELECT * FROM target;
`,
expectedRows: [][]interface{}{{int64(1), "test"}},
},
{
name: "merge two tables where source table is evaluated using a SELECT expression",
query: `
CREATE TEMP TABLE target(id INT64, name STRING);
CREATE TEMP TABLE source(id INT64, name STRING);
INSERT INTO source(id, name) VALUES (1, "test");
INSERT INTO source(id, name) VALUES (2, "test2");
MERGE target T USING (SELECT * FROM source) S ON T.id = S.id
WHEN MATCHED THEN UPDATE SET id = S.id, name = S.name
WHEN NOT MATCHED THEN INSERT (id, name) VALUES (id, name);
SELECT * FROM target;
`,
expectedRows: [][]interface{}{{int64(1), "test"}, {int64(2), "test2"}},
},
{
name: "merge two tables deleting matched rows",
query: `
CREATE TEMP TABLE target(id INT64, name STRING);
CREATE TEMP TABLE source(id INT64, name STRING);
INSERT INTO target(id, name) VALUES (1, "test");
INSERT INTO target(id, name) VALUES (2, "test2");
INSERT INTO source(id, name) VALUES (1, "test");
MERGE target T USING (SELECT * FROM source) S ON T.id = S.id
WHEN MATCHED THEN DELETE;
SELECT * FROM target;
`,
expectedRows: [][]interface{}{{int64(2), "test2"}},
},
{
name: "merge two tables omitting INSERT column list and using ROW",
query: `
CREATE TEMP TABLE target(id INT64, name STRING);
CREATE TEMP TABLE source(id INT64, name STRING);
INSERT INTO source(id, name) VALUES (1, "test");
MERGE target T USING (SELECT * FROM source) S ON T.id = S.id
WHEN NOT MATCHED THEN INSERT ROW;
SELECT * FROM target;
`,
expectedRows: [][]interface{}{{int64(1), "test"}},
},
} {
test := test
t.Run(test.name, func(t *testing.T) {
Expand Down
Loading