Skip to content
Merged
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
123 changes: 118 additions & 5 deletions union.go
Original file line number Diff line number Diff line change
Expand Up @@ -3,6 +3,10 @@

package sqlbuilder

import (
"fmt"
)

const (
unionDistinct = " UNION " // Default union type is DISTINCT.
unionAll = " UNION ALL "
Expand Down Expand Up @@ -140,9 +144,16 @@ func (ub *UnionBuilder) BuildWithFlavor(flavor Flavor, initialArg ...interface{}
buf := newStringBuilder()
ub.injection.WriteTo(buf, unionMarkerInit)

nestedSelect := (flavor == Oracle && (len(ub.limitVar) > 0 || len(ub.offsetVar) > 0)) ||
(flavor == Informix && len(ub.limitVar) > 0)

if len(ub.builderVars) > 0 {
needParen := flavor != SQLite

if nestedSelect {
buf.WriteLeadingString("SELECT * FROM (")
}

if needParen {
buf.WriteLeadingString("(")
buf.WriteString(ub.builderVars[0])
Expand All @@ -164,6 +175,10 @@ func (ub *UnionBuilder) BuildWithFlavor(flavor Flavor, initialArg ...interface{}
buf.WriteRune(')')
}
}

if nestedSelect {
buf.WriteLeadingString(")")
}
}

ub.injection.WriteTo(buf, unionMarkerAfterUnion)
Expand All @@ -180,16 +195,114 @@ func (ub *UnionBuilder) BuildWithFlavor(flavor Flavor, initialArg ...interface{}
ub.injection.WriteTo(buf, unionMarkerAfterOrderBy)
}

if len(ub.limitVar) > 0 {
buf.WriteLeadingString("LIMIT ")
buf.WriteString(ub.limitVar)
switch flavor {
case MySQL, SQLite, ClickHouse:
if len(ub.limitVar) > 0 {
buf.WriteLeadingString("LIMIT ")
buf.WriteString(ub.limitVar)

}
if len(ub.offsetVar) > 0 {
buf.WriteLeadingString("OFFSET ")
buf.WriteString(ub.offsetVar)
}
}

case CQL:
if len(ub.limitVar) > 0 {
buf.WriteLeadingString("LIMIT ")
buf.WriteString(ub.limitVar)
}

case PostgreSQL:
if len(ub.limitVar) > 0 {
buf.WriteLeadingString("LIMIT ")
buf.WriteString(ub.limitVar)
}

if len(ub.offsetVar) > 0 {
buf.WriteLeadingString("OFFSET ")
buf.WriteString(ub.offsetVar)
}

case Presto:
// There might be a hidden constraint in Presto requiring offset to be set before limit.
// The select statement documentation (https://prestodb.io/docs/current/sql/select.html)
// puts offset before limit, and Trino, which is based on Presto, seems
// to require this specific order.
if len(ub.offsetVar) > 0 {
buf.WriteLeadingString("OFFSET ")
buf.WriteString(ub.offsetVar)
}

if ((MySQL == flavor || Informix == flavor) && len(ub.limitVar) > 0) || PostgreSQL == flavor {
if len(ub.limitVar) > 0 {
buf.WriteLeadingString("LIMIT ")
buf.WriteString(ub.limitVar)
}

case SQLServer:
// If ORDER BY is not set, sort column #1 by default.
// It's required to make OFFSET...FETCH work.
if len(ub.orderByCols) == 0 && (len(ub.limitVar) > 0 || len(ub.offsetVar) > 0) {
buf.WriteLeadingString("ORDER BY 1")
}

if len(ub.offsetVar) > 0 {
buf.WriteLeadingString("OFFSET ")
buf.WriteString(ub.offsetVar)
buf.WriteString(" ROWS")
}

if len(ub.limitVar) > 0 {
if len(ub.offsetVar) == 0 {
buf.WriteLeadingString("OFFSET 0 ROWS")
}

buf.WriteLeadingString("FETCH NEXT ")
buf.WriteString(ub.limitVar)
buf.WriteString(" ROWS ONLY")
}

case Oracle:
// It's required to make OFFSET...FETCH work.
if len(ub.offsetVar) > 0 {
buf.WriteLeadingString("OFFSET ")
buf.WriteString(ub.offsetVar)
buf.WriteString(" ROWS")
}

if len(ub.limitVar) > 0 {
if len(ub.offsetVar) == 0 {
buf.WriteLeadingString("OFFSET 0 ROWS")
}

buf.WriteLeadingString("FETCH NEXT ")
buf.WriteString(ub.limitVar)
buf.WriteString(" ROWS ONLY")
}

case Informix:
// [SKIP N] FIRST M
// M must be greater than 0
if len(ub.limitVar) > 0 {
if len(ub.offsetVar) > 0 {
buf.WriteLeadingString("SKIP ")
buf.WriteString(ub.offsetVar)
}

buf.WriteLeadingString("FIRST ")
buf.WriteString(ub.limitVar)
}

case Doris:
// #192: Doris doesn't support ? in OFFSET and LIMIT.
if len(ub.limitVar) > 0 {
buf.WriteLeadingString("LIMIT ")
buf.WriteString(fmt.Sprint(ub.args.Value(ub.limitVar)))

if len(ub.offsetVar) > 0 {
buf.WriteLeadingString("OFFSET ")
buf.WriteString(fmt.Sprint(ub.args.Value(ub.offsetVar)))
}
}
}

Expand Down
145 changes: 143 additions & 2 deletions union_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -87,9 +87,9 @@ func TestUnionForSQLite(t *testing.T) {
a := assert.New(t)
sb1 := Select("id", "name").From("users").Where("created_at > DATE('now', '-15 days')")
sb2 := Select("id", "nick_name").From("user_extras").Where("status IN (1, 2, 3)")
sql, _ := UnionAll(sb1, sb2).OrderBy("id").BuildWithFlavor(SQLite)
sql, _ := UnionAll(sb1, sb2).OrderBy("id").Limit(100).Offset(5).BuildWithFlavor(SQLite)

a.Equal(sql, "SELECT id, name FROM users WHERE created_at > DATE('now', '-15 days') UNION ALL SELECT id, nick_name FROM user_extras WHERE status IN (1, 2, 3) ORDER BY id")
a.Equal(sql, "SELECT id, name FROM users WHERE created_at > DATE('now', '-15 days') UNION ALL SELECT id, nick_name FROM user_extras WHERE status IN (1, 2, 3) ORDER BY id LIMIT ? OFFSET ?")
}

func TestUnionBuilderGetFlavor(t *testing.T) {
Expand All @@ -104,3 +104,144 @@ func TestUnionBuilderGetFlavor(t *testing.T) {
flavor = ubClick.Flavor()
a.Equal(ClickHouse, flavor)
}

func ExampleUnionBuilder_limit_offset() {
flavors := []Flavor{MySQL, PostgreSQL, SQLite, SQLServer, CQL, ClickHouse, Presto, Oracle, Informix, Doris}
results := make([][]string, len(flavors))

ub := NewUnionBuilder()
saveResults := func() {
sb1 := NewSelectBuilder()
sb1.Select("*").From("user1")
sb2 := NewSelectBuilder()
sb2.Select("*").From("user2")
ub.Union(sb1, sb2)
for i, f := range flavors {
s, _ := ub.BuildWithFlavor(f)
results[i] = append(results[i], s)
}
}

// Case #1: limit < 0 and offset < 0
//
// All: No limit or offset in query.
ub.Limit(-1)
ub.Offset(-1)
saveResults()

// Case #2: limit < 0 and offset >= 0
//
// MySQL and SQLite: Ignore offset if the limit is not set.
// PostgreSQL: Offset can be set without limit.
// SQLServer: Offset can be set without limit.
// CQL: Ignore offset.
// Oracle: Offset can be set without limit.
ub.Limit(-1)
ub.Offset(0)
saveResults()

// Case #3: limit >= 0 and offset >= 0
//
// CQL: Ignore offset.
// All others: Set both limit and offset.
ub.Limit(1)
ub.Offset(0)
saveResults()

// Case #4: limit >= 0 and offset < 0
//
// All: Set limit in query.
ub.Limit(1)
ub.Offset(-1)
saveResults()

// Case #5: limit >= 0 and offset >= 0 order by id
//
// CQL: Ignore offset.
// All others: Set both limit and offset.
ub.Limit(1)
ub.Offset(1)
ub.OrderBy("id")
saveResults()

for i, result := range results {
fmt.Println()
fmt.Println(flavors[i])

for n, s := range result {
fmt.Printf("#%d: %s\n", n+1, s)
}
}

// Output:
//
// MySQL
// #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
// #2: (SELECT * FROM user1) UNION (SELECT * FROM user2)
// #3: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT ? OFFSET ?
// #4: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT ?
// #5: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY id LIMIT ? OFFSET ?
//
// PostgreSQL
// #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
// #2: (SELECT * FROM user1) UNION (SELECT * FROM user2) OFFSET $1
// #3: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT $1 OFFSET $2
// #4: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT $1
// #5: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY id LIMIT $1 OFFSET $2
//
// SQLite
// #1: SELECT * FROM user1 UNION SELECT * FROM user2
// #2: SELECT * FROM user1 UNION SELECT * FROM user2
// #3: SELECT * FROM user1 UNION SELECT * FROM user2 LIMIT ? OFFSET ?
// #4: SELECT * FROM user1 UNION SELECT * FROM user2 LIMIT ?
// #5: SELECT * FROM user1 UNION SELECT * FROM user2 ORDER BY id LIMIT ? OFFSET ?
//
// SQLServer
// #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
// #2: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY 1 OFFSET @p1 ROWS
// #3: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY 1 OFFSET @p1 ROWS FETCH NEXT @p2 ROWS ONLY
// #4: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY 1 OFFSET 0 ROWS FETCH NEXT @p1 ROWS ONLY
// #5: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY id OFFSET @p1 ROWS FETCH NEXT @p2 ROWS ONLY
//
// CQL
// #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
// #2: (SELECT * FROM user1) UNION (SELECT * FROM user2)
// #3: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT ?
// #4: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT ?
// #5: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY id LIMIT ?
//
// ClickHouse
// #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
// #2: (SELECT * FROM user1) UNION (SELECT * FROM user2)
// #3: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT ? OFFSET ?
// #4: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT ?
// #5: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY id LIMIT ? OFFSET ?
//
// Presto
// #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
// #2: (SELECT * FROM user1) UNION (SELECT * FROM user2) OFFSET ?
// #3: (SELECT * FROM user1) UNION (SELECT * FROM user2) OFFSET ? LIMIT ?
// #4: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT ?
// #5: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY id OFFSET ? LIMIT ?
//
// Oracle
// #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
// #2: SELECT * FROM ( (SELECT * FROM user1) UNION (SELECT * FROM user2) ) OFFSET :1 ROWS
// #3: SELECT * FROM ( (SELECT * FROM user1) UNION (SELECT * FROM user2) ) OFFSET :1 ROWS FETCH NEXT :2 ROWS ONLY
// #4: SELECT * FROM ( (SELECT * FROM user1) UNION (SELECT * FROM user2) ) OFFSET 0 ROWS FETCH NEXT :1 ROWS ONLY
// #5: SELECT * FROM ( (SELECT * FROM user1) UNION (SELECT * FROM user2) ) ORDER BY id OFFSET :1 ROWS FETCH NEXT :2 ROWS ONLY
//
// Informix
// #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
// #2: (SELECT * FROM user1) UNION (SELECT * FROM user2)
// #3: SELECT * FROM ( (SELECT * FROM user1) UNION (SELECT * FROM user2) ) SKIP ? FIRST ?
// #4: SELECT * FROM ( (SELECT * FROM user1) UNION (SELECT * FROM user2) ) FIRST ?
// #5: SELECT * FROM ( (SELECT * FROM user1) UNION (SELECT * FROM user2) ) ORDER BY id SKIP ? FIRST ?
//
// Doris
// #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
// #2: (SELECT * FROM user1) UNION (SELECT * FROM user2)
// #3: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT 1 OFFSET 0
// #4: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT 1
// #5: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY id LIMIT 1 OFFSET 1
}