Skip to content

Commit 3282717

Browse files
authored
Merge pull request #157 from huandu/feature/cte
Support CTE (Common Table Expression)
2 parents 9fc30d9 + a0af5e4 commit 3282717

File tree

8 files changed

+330
-10
lines changed

8 files changed

+330
-10
lines changed

README.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -81,6 +81,7 @@ This package includes following pre-defined builders so far. API document and ex
8181
- [UpdateBuilder](https://pkg.go.dev/github.com/huandu/go-sqlbuilder#UpdateBuilder): Builder for UPDATE.
8282
- [DeleteBuilder](https://pkg.go.dev/github.com/huandu/go-sqlbuilder#DeleteBuilder): Builder for DELETE.
8383
- [UnionBuilder](https://pkg.go.dev/github.com/huandu/go-sqlbuilder#UnionBuilder): Builder for UNION and UNION ALL.
84+
- [CTEBuilder](https://pkg.go.dev/github.com/huandu/go-sqlbuilder#CTEBuilder): Builder for Common Table Expression (CTE), e.g. `WITH name (col1, col2) AS (SELECT ...)`.
8485
- [Buildf](https://pkg.go.dev/github.com/huandu/go-sqlbuilder#Buildf): Freestyle builder using `fmt.Sprintf`-like syntax.
8586
- [Build](https://pkg.go.dev/github.com/huandu/go-sqlbuilder#Build): Advanced freestyle builder using special syntax defined in [Args#Compile](https://pkg.go.dev/github.com/huandu/go-sqlbuilder#Args.Compile).
8687
- [BuildNamed](https://pkg.go.dev/github.com/huandu/go-sqlbuilder#BuildNamed): Advanced freestyle builder using `${key}` to refer the value of a map by key.

cte.go

Lines changed: 99 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,99 @@
1+
// Copyright 2024 Huan Du. All rights reserved.
2+
// Licensed under the MIT license that can be found in the LICENSE file.
3+
4+
package sqlbuilder
5+
6+
const (
7+
cteMarkerInit injectionMarker = iota
8+
cteMarkerAfterWith
9+
)
10+
11+
// With creates a new CTE builder with default flavor.
12+
func With(tables ...*CTETableBuilder) *CTEBuilder {
13+
return DefaultFlavor.NewCTEBuilder().With(tables...)
14+
}
15+
16+
func newCTEBuilder() *CTEBuilder {
17+
return &CTEBuilder{
18+
args: &Args{},
19+
injection: newInjection(),
20+
}
21+
}
22+
23+
// CTEBuilder is a CTE (Common Table Expression) builder.
24+
type CTEBuilder struct {
25+
tableNames []string
26+
tableBuilderVars []string
27+
28+
args *Args
29+
30+
injection *injection
31+
marker injectionMarker
32+
}
33+
34+
var _ Builder = new(CTEBuilder)
35+
36+
// With sets the CTE name and columns.
37+
func (cteb *CTEBuilder) With(tables ...*CTETableBuilder) *CTEBuilder {
38+
tableNames := make([]string, 0, len(tables))
39+
tableBuilderVars := make([]string, 0, len(tables))
40+
41+
for _, table := range tables {
42+
tableNames = append(tableNames, table.TableName())
43+
tableBuilderVars = append(tableBuilderVars, cteb.args.Add(table))
44+
}
45+
46+
cteb.tableNames = tableNames
47+
cteb.tableBuilderVars = tableBuilderVars
48+
cteb.marker = cteMarkerAfterWith
49+
return cteb
50+
}
51+
52+
// Select creates a new SelectBuilder to build a SELECT statement using this CTE.
53+
func (cteb *CTEBuilder) Select(col ...string) *SelectBuilder {
54+
sb := cteb.args.Flavor.NewSelectBuilder()
55+
return sb.With(cteb).Select(col...)
56+
}
57+
58+
// String returns the compiled CTE string.
59+
func (cteb *CTEBuilder) String() string {
60+
sql, _ := cteb.Build()
61+
return sql
62+
}
63+
64+
// Build returns compiled CTE string and args.
65+
func (cteb *CTEBuilder) Build() (sql string, args []interface{}) {
66+
return cteb.BuildWithFlavor(cteb.args.Flavor)
67+
}
68+
69+
// BuildWithFlavor builds a CTE with the specified flavor and initial arguments.
70+
func (cteb *CTEBuilder) BuildWithFlavor(flavor Flavor, initialArg ...interface{}) (sql string, args []interface{}) {
71+
buf := newStringBuilder()
72+
cteb.injection.WriteTo(buf, cteMarkerInit)
73+
74+
if len(cteb.tableBuilderVars) > 0 {
75+
buf.WriteLeadingString("WITH ")
76+
buf.WriteStrings(cteb.tableBuilderVars, ", ")
77+
}
78+
79+
cteb.injection.WriteTo(buf, cteMarkerAfterWith)
80+
return cteb.args.CompileWithFlavor(buf.String(), flavor, initialArg...)
81+
}
82+
83+
// SetFlavor sets the flavor of compiled sql.
84+
func (cteb *CTEBuilder) SetFlavor(flavor Flavor) (old Flavor) {
85+
old = cteb.args.Flavor
86+
cteb.args.Flavor = flavor
87+
return
88+
}
89+
90+
// SQL adds an arbitrary sql to current position.
91+
func (cteb *CTEBuilder) SQL(sql string) *CTEBuilder {
92+
cteb.injection.SQL(cteb.marker, sql)
93+
return cteb
94+
}
95+
96+
// TableNames returns all table names in a CTE.
97+
func (cteb *CTEBuilder) TableNames() []string {
98+
return cteb.tableNames
99+
}

cte_test.go

Lines changed: 81 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,81 @@
1+
// Copyright 2024 Huan Du. All rights reserved.
2+
// Licensed under the MIT license that can be found in the LICENSE file.
3+
4+
package sqlbuilder
5+
6+
import (
7+
"fmt"
8+
"testing"
9+
10+
"github.com/huandu/go-assert"
11+
)
12+
13+
func ExampleWith() {
14+
sb := With(
15+
CTETable("users", "id", "name").As(
16+
Select("id", "name").From("users").Where("name IS NOT NULL"),
17+
),
18+
CTETable("devices").As(
19+
Select("device_id").From("devices"),
20+
),
21+
).Select("users.id", "orders.id", "devices.device_id").Join(
22+
"orders",
23+
"users.id = orders.user_id",
24+
"devices.device_id = orders.device_id",
25+
)
26+
27+
fmt.Println(sb)
28+
29+
// Output:
30+
// WITH users (id, name) AS (SELECT id, name FROM users WHERE name IS NOT NULL), devices AS (SELECT device_id FROM devices) SELECT users.id, orders.id, devices.device_id FROM users, devices JOIN orders ON users.id = orders.user_id AND devices.device_id = orders.device_id
31+
}
32+
33+
func ExampleCTEBuilder() {
34+
usersBuilder := Select("id", "name", "level").From("users")
35+
usersBuilder.Where(
36+
usersBuilder.GreaterEqualThan("level", 10),
37+
)
38+
cteb := With(
39+
CTETable("valid_users").As(usersBuilder),
40+
)
41+
fmt.Println(cteb)
42+
43+
sb := Select("valid_users.id", "valid_users.name", "orders.id").With(cteb)
44+
sb.Join("orders", "valid_users.id = orders.user_id")
45+
sb.Where(
46+
sb.LessEqualThan("orders.price", 200),
47+
"valid_users.level < orders.min_level",
48+
).OrderBy("orders.price").Desc()
49+
50+
sql, args := sb.Build()
51+
fmt.Println(sql)
52+
fmt.Println(args)
53+
54+
// Output:
55+
// WITH valid_users AS (SELECT id, name, level FROM users WHERE level >= ?)
56+
// WITH valid_users AS (SELECT id, name, level FROM users WHERE level >= ?) SELECT valid_users.id, valid_users.name, orders.id FROM valid_users JOIN orders ON valid_users.id = orders.user_id WHERE orders.price <= ? AND valid_users.level < orders.min_level ORDER BY orders.price DESC
57+
// [10 200]
58+
}
59+
60+
func TestCTEBuilder(t *testing.T) {
61+
a := assert.New(t)
62+
cteb := newCTEBuilder()
63+
ctetb := newCTETableBuilder()
64+
cteb.SQL("/* init */")
65+
cteb.With(ctetb)
66+
cteb.SQL("/* after with */")
67+
68+
ctetb.SQL("/* table init */")
69+
ctetb.Table("t", "a", "b")
70+
ctetb.SQL("/* after table */")
71+
72+
ctetb.As(Select("a", "b").From("t"))
73+
ctetb.SQL("/* after table as */")
74+
75+
sql, args := cteb.Build()
76+
a.Equal(sql, "/* init */ WITH /* table init */ t (a, b) /* after table */ AS (SELECT a, b FROM t) /* after table as */ /* after with */")
77+
a.Assert(args == nil)
78+
79+
sql = ctetb.String()
80+
a.Equal(sql, "/* table init */ t (a, b) /* after table */ AS (SELECT a, b FROM t) /* after table as */")
81+
}

ctetable.go

Lines changed: 106 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,106 @@
1+
// Copyright 2024 Huan Du. All rights reserved.
2+
// Licensed under the MIT license that can be found in the LICENSE file.
3+
4+
package sqlbuilder
5+
6+
const (
7+
cteTableMarkerInit injectionMarker = iota
8+
cteTableMarkerAfterTable
9+
cteTableMarkerAfterAs
10+
)
11+
12+
// CTETable creates a new CTE table builder with default flavor.
13+
func CTETable(name string, cols ...string) *CTETableBuilder {
14+
return DefaultFlavor.NewCTETableBuilder().Table(name, cols...)
15+
}
16+
17+
func newCTETableBuilder() *CTETableBuilder {
18+
return &CTETableBuilder{
19+
args: &Args{},
20+
injection: newInjection(),
21+
}
22+
}
23+
24+
// CTETableBuilder is a builder to build one table in CTE (Common Table Expression).
25+
type CTETableBuilder struct {
26+
name string
27+
cols []string
28+
builderVar string
29+
30+
args *Args
31+
32+
injection *injection
33+
marker injectionMarker
34+
}
35+
36+
// Table sets the table name and columns in a CTE table.
37+
func (ctetb *CTETableBuilder) Table(name string, cols ...string) *CTETableBuilder {
38+
ctetb.name = name
39+
ctetb.cols = cols
40+
ctetb.marker = cteTableMarkerAfterTable
41+
return ctetb
42+
}
43+
44+
// As sets the builder to select data.
45+
func (ctetb *CTETableBuilder) As(builder Builder) *CTETableBuilder {
46+
ctetb.builderVar = ctetb.args.Add(builder)
47+
ctetb.marker = cteTableMarkerAfterAs
48+
return ctetb
49+
}
50+
51+
// String returns the compiled CTE string.
52+
func (ctetb *CTETableBuilder) String() string {
53+
sql, _ := ctetb.Build()
54+
return sql
55+
}
56+
57+
// Build returns compiled CTE string and args.
58+
func (ctetb *CTETableBuilder) Build() (sql string, args []interface{}) {
59+
return ctetb.BuildWithFlavor(ctetb.args.Flavor)
60+
}
61+
62+
// BuildWithFlavor builds a CTE with the specified flavor and initial arguments.
63+
func (ctetb *CTETableBuilder) BuildWithFlavor(flavor Flavor, initialArg ...interface{}) (sql string, args []interface{}) {
64+
buf := newStringBuilder()
65+
ctetb.injection.WriteTo(buf, cteTableMarkerInit)
66+
67+
if ctetb.name != "" {
68+
buf.WriteLeadingString(ctetb.name)
69+
70+
if len(ctetb.cols) > 0 {
71+
buf.WriteLeadingString("(")
72+
buf.WriteStrings(ctetb.cols, ", ")
73+
buf.WriteString(")")
74+
}
75+
76+
ctetb.injection.WriteTo(buf, cteTableMarkerAfterTable)
77+
}
78+
79+
if ctetb.builderVar != "" {
80+
buf.WriteLeadingString("AS (")
81+
buf.WriteString(ctetb.builderVar)
82+
buf.WriteRune(')')
83+
84+
ctetb.injection.WriteTo(buf, cteTableMarkerAfterAs)
85+
}
86+
87+
return ctetb.args.CompileWithFlavor(buf.String(), flavor, initialArg...)
88+
}
89+
90+
// SetFlavor sets the flavor of compiled sql.
91+
func (ctetb *CTETableBuilder) SetFlavor(flavor Flavor) (old Flavor) {
92+
old = ctetb.args.Flavor
93+
ctetb.args.Flavor = flavor
94+
return
95+
}
96+
97+
// SQL adds an arbitrary sql to current position.
98+
func (ctetb *CTETableBuilder) SQL(sql string) *CTETableBuilder {
99+
ctetb.injection.SQL(ctetb.marker, sql)
100+
return ctetb
101+
}
102+
103+
// TableName returns the CTE table name.
104+
func (ctetb *CTETableBuilder) TableName() string {
105+
return ctetb.name
106+
}

flavor.go

Lines changed: 14 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -141,6 +141,20 @@ func (f Flavor) NewUnionBuilder() *UnionBuilder {
141141
return b
142142
}
143143

144+
// NewCTEBuilder creates a new CTE builder with flavor.
145+
func (f Flavor) NewCTEBuilder() *CTEBuilder {
146+
b := newCTEBuilder()
147+
b.SetFlavor(f)
148+
return b
149+
}
150+
151+
// NewCTETableBuilder creates a new CTE table builder with flavor.
152+
func (f Flavor) NewCTETableBuilder() *CTETableBuilder {
153+
b := newCTETableBuilder()
154+
b.SetFlavor(f)
155+
return b
156+
}
157+
144158
// Quote adds quote for name to make sure the name can be used safely
145159
// as table name or field name.
146160
//

select.go

Lines changed: 15 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -11,6 +11,7 @@ import (
1111

1212
const (
1313
selectMarkerInit injectionMarker = iota
14+
selectMarkerAfterWith
1415
selectMarkerAfterSelect
1516
selectMarkerAfterFrom
1617
selectMarkerAfterJoin
@@ -65,6 +66,7 @@ type SelectBuilder struct {
6566
whereClauseProxy *whereClauseProxy
6667
whereClauseExpr string
6768

69+
cteBuilder string
6870
distinct bool
6971
tables []string
7072
selectCols []string
@@ -92,6 +94,14 @@ func Select(col ...string) *SelectBuilder {
9294
return DefaultFlavor.NewSelectBuilder().Select(col...)
9395
}
9496

97+
// With sets WITH clause (the Common Table Expression) before SELECT.
98+
func (sb *SelectBuilder) With(builder *CTEBuilder) *SelectBuilder {
99+
sb.marker = selectMarkerAfterWith
100+
sb.cteBuilder = sb.Var(builder)
101+
sb.tables = builder.TableNames()
102+
return sb
103+
}
104+
95105
// Select sets columns in SELECT.
96106
func (sb *SelectBuilder) Select(col ...string) *SelectBuilder {
97107
sb.selectCols = col
@@ -269,6 +279,11 @@ func (sb *SelectBuilder) BuildWithFlavor(flavor Flavor, initialArg ...interface{
269279

270280
oraclePage := flavor == Oracle && (sb.limit >= 0 || sb.offset >= 0)
271281

282+
if sb.cteBuilder != "" {
283+
buf.WriteLeadingString(sb.cteBuilder)
284+
sb.injection.WriteTo(buf, selectMarkerAfterWith)
285+
}
286+
272287
if len(sb.selectCols) > 0 {
273288
buf.WriteLeadingString("SELECT ")
274289

struct_test.go

Lines changed: 1 addition & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -638,9 +638,7 @@ func ExampleStruct_buildDELETE() {
638638

639639
// Prepare DELETE query.
640640
user := &User{
641-
ID: 1234,
642-
Name: "Huan Du",
643-
Status: 1,
641+
ID: 1234,
644642
}
645643
b := userStruct.DeleteFrom("user")
646644
b.Where(b.Equal("id", user.ID))

0 commit comments

Comments
 (0)