Skip to content

Commit

Permalink
[Array] Support LEFT OUTER / INNER JOIN modes (#26)
Browse files Browse the repository at this point in the history
  • Loading branch information
ohaibbq authored Feb 28, 2024
1 parent 4e2ad69 commit c21c1de
Show file tree
Hide file tree
Showing 2 changed files with 47 additions and 2 deletions.
29 changes: 27 additions & 2 deletions internal/formatter.go
Original file line number Diff line number Diff line change
Expand Up @@ -736,11 +736,36 @@ func (n *ArrayScanNode) FormatSQL(ctx context.Context) (string, error) {
if err != nil {
return "", err
}

array := fmt.Sprintf("json_each(zetasqlite_decode_array(%s))", arrayExpr)
var arrayJoinExpr string
if n.node.JoinExpr() != nil {
arrayJoinExpr, err = newNode(n.node.JoinExpr()).FormatSQL(ctx)
if err != nil {
return "", err
}
// RIGHT JOINs on array expressions are not supported by BigQuery
var joinMode string
if n.node.IsOuter() {
joinMode = "LEFT OUTER JOIN"
} else {
joinMode = "INNER JOIN"
}
arrayJoinExpr = fmt.Sprintf("%s %s ON %s",
joinMode,
array,
arrayJoinExpr,
)
} else {
// If there is no join expression, use a CROSS JOIN
arrayJoinExpr = fmt.Sprintf(", %s", array)
}

return fmt.Sprintf(
"SELECT *, json_each.value AS `%s` %s, json_each(zetasqlite_decode_array(%s))",
"SELECT *, json_each.value AS `%s` %s %s",
colName,
formattedInput,
arrayExpr,
arrayJoinExpr,
), nil
}
return fmt.Sprintf(
Expand Down
20 changes: 20 additions & 0 deletions query_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -2387,6 +2387,26 @@ FROM UNNEST([
{[]interface{}{int64(1), int64(2), int64(3)}},
},
},
// Regression tests for goccy/go-zetasqlite#176
{
name: "array scan left outer join",
query: `WITH produce AS (select 'lettuce' AS item UNION ALL SELECT 'banana')
SELECT item, in_stock_items is not null AS item_in_stock FROM produce
LEFT OUTER JOIN unnest(['lettuce']) in_stock_items ON in_stock_items = item;`,
expectedRows: [][]interface{}{
{"lettuce", true},
{"banana", false},
},
},
{
name: "array scan inner join",
query: `WITH produce AS (select 'lettuce' AS item UNION ALL SELECT 'banana')
SELECT item, in_stock_items is not null AS item_in_stock FROM produce
INNER JOIN unnest(['lettuce']) in_stock_items ON in_stock_items = item;`,
expectedRows: [][]interface{}{
{"lettuce", true},
},
},
{
name: "array function with struct",
query: `SELECT ARRAY (SELECT AS STRUCT 1, 2, 3 UNION ALL SELECT AS STRUCT 4, 5, 6) AS new_array`,
Expand Down

0 comments on commit c21c1de

Please sign in to comment.