@@ -87,9 +87,9 @@ func TestUnionForSQLite(t *testing.T) {
8787 a := assert .New (t )
8888 sb1 := Select ("id" , "name" ).From ("users" ).Where ("created_at > DATE('now', '-15 days')" )
8989 sb2 := Select ("id" , "nick_name" ).From ("user_extras" ).Where ("status IN (1, 2, 3)" )
90- sql , _ := UnionAll (sb1 , sb2 ).OrderBy ("id" ).BuildWithFlavor (SQLite )
90+ sql , _ := UnionAll (sb1 , sb2 ).OrderBy ("id" ).Limit ( 100 ). Offset ( 5 ). BuildWithFlavor (SQLite )
9191
92- 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" )
92+ 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 ? " )
9393}
9494
9595func TestUnionBuilderGetFlavor (t * testing.T ) {
@@ -104,3 +104,144 @@ func TestUnionBuilderGetFlavor(t *testing.T) {
104104 flavor = ubClick .Flavor ()
105105 a .Equal (ClickHouse , flavor )
106106}
107+
108+ func ExampleUnionBuilder_limit_offset () {
109+ flavors := []Flavor {MySQL , PostgreSQL , SQLite , SQLServer , CQL , ClickHouse , Presto , Oracle , Informix , Doris }
110+ results := make ([][]string , len (flavors ))
111+
112+ ub := NewUnionBuilder ()
113+ saveResults := func () {
114+ sb1 := NewSelectBuilder ()
115+ sb1 .Select ("*" ).From ("user1" )
116+ sb2 := NewSelectBuilder ()
117+ sb2 .Select ("*" ).From ("user2" )
118+ ub .Union (sb1 , sb2 )
119+ for i , f := range flavors {
120+ s , _ := ub .BuildWithFlavor (f )
121+ results [i ] = append (results [i ], s )
122+ }
123+ }
124+
125+ // Case #1: limit < 0 and offset < 0
126+ //
127+ // All: No limit or offset in query.
128+ ub .Limit (- 1 )
129+ ub .Offset (- 1 )
130+ saveResults ()
131+
132+ // Case #2: limit < 0 and offset >= 0
133+ //
134+ // MySQL and SQLite: Ignore offset if the limit is not set.
135+ // PostgreSQL: Offset can be set without limit.
136+ // SQLServer: Offset can be set without limit.
137+ // CQL: Ignore offset.
138+ // Oracle: Offset can be set without limit.
139+ ub .Limit (- 1 )
140+ ub .Offset (0 )
141+ saveResults ()
142+
143+ // Case #3: limit >= 0 and offset >= 0
144+ //
145+ // CQL: Ignore offset.
146+ // All others: Set both limit and offset.
147+ ub .Limit (1 )
148+ ub .Offset (0 )
149+ saveResults ()
150+
151+ // Case #4: limit >= 0 and offset < 0
152+ //
153+ // All: Set limit in query.
154+ ub .Limit (1 )
155+ ub .Offset (- 1 )
156+ saveResults ()
157+
158+ // Case #5: limit >= 0 and offset >= 0 order by id
159+ //
160+ // CQL: Ignore offset.
161+ // All others: Set both limit and offset.
162+ ub .Limit (1 )
163+ ub .Offset (1 )
164+ ub .OrderBy ("id" )
165+ saveResults ()
166+
167+ for i , result := range results {
168+ fmt .Println ()
169+ fmt .Println (flavors [i ])
170+
171+ for n , s := range result {
172+ fmt .Printf ("#%d: %s\n " , n + 1 , s )
173+ }
174+ }
175+
176+ // Output:
177+ //
178+ // MySQL
179+ // #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
180+ // #2: (SELECT * FROM user1) UNION (SELECT * FROM user2)
181+ // #3: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT ? OFFSET ?
182+ // #4: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT ?
183+ // #5: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY id LIMIT ? OFFSET ?
184+ //
185+ // PostgreSQL
186+ // #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
187+ // #2: (SELECT * FROM user1) UNION (SELECT * FROM user2) OFFSET $1
188+ // #3: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT $1 OFFSET $2
189+ // #4: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT $1
190+ // #5: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY id LIMIT $1 OFFSET $2
191+ //
192+ // SQLite
193+ // #1: SELECT * FROM user1 UNION SELECT * FROM user2
194+ // #2: SELECT * FROM user1 UNION SELECT * FROM user2
195+ // #3: SELECT * FROM user1 UNION SELECT * FROM user2 LIMIT ? OFFSET ?
196+ // #4: SELECT * FROM user1 UNION SELECT * FROM user2 LIMIT ?
197+ // #5: SELECT * FROM user1 UNION SELECT * FROM user2 ORDER BY id LIMIT ? OFFSET ?
198+ //
199+ // SQLServer
200+ // #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
201+ // #2: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY 1 OFFSET @p1 ROWS
202+ // #3: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY 1 OFFSET @p1 ROWS FETCH NEXT @p2 ROWS ONLY
203+ // #4: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY 1 OFFSET 0 ROWS FETCH NEXT @p1 ROWS ONLY
204+ // #5: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY id OFFSET @p1 ROWS FETCH NEXT @p2 ROWS ONLY
205+ //
206+ // CQL
207+ // #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
208+ // #2: (SELECT * FROM user1) UNION (SELECT * FROM user2)
209+ // #3: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT ?
210+ // #4: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT ?
211+ // #5: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY id LIMIT ?
212+ //
213+ // ClickHouse
214+ // #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
215+ // #2: (SELECT * FROM user1) UNION (SELECT * FROM user2)
216+ // #3: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT ? OFFSET ?
217+ // #4: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT ?
218+ // #5: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY id LIMIT ? OFFSET ?
219+ //
220+ // Presto
221+ // #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
222+ // #2: (SELECT * FROM user1) UNION (SELECT * FROM user2) OFFSET ?
223+ // #3: (SELECT * FROM user1) UNION (SELECT * FROM user2) OFFSET ? LIMIT ?
224+ // #4: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT ?
225+ // #5: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY id OFFSET ? LIMIT ?
226+ //
227+ // Oracle
228+ // #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
229+ // #2: SELECT * FROM ( (SELECT * FROM user1) UNION (SELECT * FROM user2) ) OFFSET :1 ROWS
230+ // #3: SELECT * FROM ( (SELECT * FROM user1) UNION (SELECT * FROM user2) ) OFFSET :1 ROWS FETCH NEXT :2 ROWS ONLY
231+ // #4: SELECT * FROM ( (SELECT * FROM user1) UNION (SELECT * FROM user2) ) OFFSET 0 ROWS FETCH NEXT :1 ROWS ONLY
232+ // #5: SELECT * FROM ( (SELECT * FROM user1) UNION (SELECT * FROM user2) ) ORDER BY id OFFSET :1 ROWS FETCH NEXT :2 ROWS ONLY
233+ //
234+ // Informix
235+ // #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
236+ // #2: (SELECT * FROM user1) UNION (SELECT * FROM user2)
237+ // #3: SELECT * FROM ( (SELECT * FROM user1) UNION (SELECT * FROM user2) ) SKIP ? FIRST ?
238+ // #4: SELECT * FROM ( (SELECT * FROM user1) UNION (SELECT * FROM user2) ) FIRST ?
239+ // #5: SELECT * FROM ( (SELECT * FROM user1) UNION (SELECT * FROM user2) ) ORDER BY id SKIP ? FIRST ?
240+ //
241+ // Doris
242+ // #1: (SELECT * FROM user1) UNION (SELECT * FROM user2)
243+ // #2: (SELECT * FROM user1) UNION (SELECT * FROM user2)
244+ // #3: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT 1 OFFSET 0
245+ // #4: (SELECT * FROM user1) UNION (SELECT * FROM user2) LIMIT 1
246+ // #5: (SELECT * FROM user1) UNION (SELECT * FROM user2) ORDER BY id LIMIT 1 OFFSET 1
247+ }
0 commit comments