From 9f91fd705aae7864b635bfea8beecb56fa68216c Mon Sep 17 00:00:00 2001 From: go-jet Date: Fri, 11 Feb 2022 13:09:49 +0100 Subject: [PATCH] Global `AND` and `OR` functions for better indentation of a complex condition in the Go code and in the generated SQL. --- internal/jet/clause.go | 4 +- internal/jet/expression.go | 63 +++++++++++- internal/jet/func_expression.go | 12 +++ internal/jet/func_expression_test.go | 22 ++++ internal/jet/sql_builder.go | 1 + internal/jet/utils.go | 11 ++ mysql/functions.go | 9 ++ mysql/select_statement_test.go | 8 +- postgres/functions.go | 9 ++ sqlite/functions.go | 9 ++ sqlite/select_statement_test.go | 8 +- tests/mysql/with_test.go | 6 +- tests/postgres/chinook_db_test.go | 146 +++++++++++++++++++++++++++ tests/postgres/delete_test.go | 14 ++- tests/postgres/select_test.go | 22 ++-- tests/postgres/with_test.go | 26 ++--- tests/sqlite/with_test.go | 12 +-- 17 files changed, 338 insertions(+), 44 deletions(-) diff --git a/internal/jet/clause.go b/internal/jet/clause.go index ce99a6b5..aa450055 100644 --- a/internal/jet/clause.go +++ b/internal/jet/clause.go @@ -98,9 +98,9 @@ func (c *ClauseWhere) Serialize(statementType StatementType, out *SQLBuilder, op } out.WriteString("WHERE") - out.IncreaseIdent() + out.IncreaseIdent(6) c.Condition.serialize(statementType, out, NoWrap.WithFallTrough(options)...) - out.DecreaseIdent() + out.DecreaseIdent(6) } // ClauseGroupBy struct diff --git a/internal/jet/expression.go b/internal/jet/expression.go index e657f30a..0fe78df0 100644 --- a/internal/jet/expression.go +++ b/internal/jet/expression.go @@ -123,6 +123,65 @@ func (c *binaryOperatorExpression) serialize(statement StatementType, out *SQLBu } } +type expressionListOperator struct { + ExpressionInterfaceImpl + + operator string + expressions []Expression +} + +func newExpressionListOperator(operator string, expressions ...Expression) *expressionListOperator { + ret := &expressionListOperator{ + operator: operator, + expressions: expressions, + } + + ret.ExpressionInterfaceImpl.Parent = ret + + return ret +} + +func newBoolExpressionListOperator(operator string, expressions ...BoolExpression) BoolExpression { + return BoolExp(newExpressionListOperator(operator, BoolExpressionListToExpressionList(expressions)...)) +} + +func (elo *expressionListOperator) serialize(statement StatementType, out *SQLBuilder, options ...SerializeOption) { + if len(elo.expressions) == 0 { + panic("jet: syntax error, expression list empty") + } + + shouldWrap := len(elo.expressions) > 1 + if shouldWrap { + out.WriteByte('(') + out.IncreaseIdent(tabSize) + out.NewLine() + } + + for i, expression := range elo.expressions { + if i == 1 { + out.IncreaseIdent(tabSize) + } + if i > 0 { + out.NewLine() + out.WriteString(elo.operator) + } + + out.IncreaseIdent(len(elo.operator) + 1) + expression.serialize(statement, out, FallTrough(options)...) + out.DecreaseIdent(len(elo.operator) + 1) + } + + if len(elo.expressions) > 1 { + out.DecreaseIdent(tabSize) + } + + if shouldWrap { + out.DecreaseIdent(tabSize) + out.NewLine() + out.WriteByte(')') + } +} + // A prefix operator Expression type prefixExpression struct { ExpressionInterfaceImpl @@ -209,8 +268,8 @@ type complexExpression struct { expressions Expression } -func complexExpr(expressions Expression) Expression { - complexExpression := &complexExpression{expressions: expressions} +func complexExpr(expression Expression) Expression { + complexExpression := &complexExpression{expressions: expression} complexExpression.ExpressionInterfaceImpl.Parent = complexExpression return complexExpression diff --git a/internal/jet/func_expression.go b/internal/jet/func_expression.go index 3e40edfe..cfac71f8 100644 --- a/internal/jet/func_expression.go +++ b/internal/jet/func_expression.go @@ -1,5 +1,17 @@ package jet +// AND function adds AND operator between expressions. This function can be used, instead of method AND, +// to have a better inlining of a complex condition in the Go code and in the generated SQL. +func AND(expressions ...BoolExpression) BoolExpression { + return newBoolExpressionListOperator("AND", expressions...) +} + +// OR function adds OR operator between expressions. This function can be used, instead of method OR, +// to have a better inlining of a complex condition in the Go code and in the generated SQL. +func OR(expressions ...BoolExpression) BoolExpression { + return newBoolExpressionListOperator("OR", expressions...) +} + // ROW is construct one table row from list of expressions. func ROW(expressions ...Expression) Expression { return NewFunc("ROW", expressions, nil) diff --git a/internal/jet/func_expression_test.go b/internal/jet/func_expression_test.go index 264be956..048ade29 100644 --- a/internal/jet/func_expression_test.go +++ b/internal/jet/func_expression_test.go @@ -4,6 +4,28 @@ import ( "testing" ) +func TestAND(t *testing.T) { + assertClauseSerializeErr(t, AND(), "jet: syntax error, expression list empty") + assertClauseSerialize(t, AND(table1ColInt.IS_NULL()), `table1.col_int IS NULL`) // IS NULL doesn't add parenthesis + assertClauseSerialize(t, AND(table1ColInt.LT(Int(11))), `(table1.col_int < $1)`, int64(11)) + assertClauseSerialize(t, AND(table1ColInt.GT(Int(11)), table1ColFloat.EQ(Float(0))), + `( + (table1.col_int > $1) + AND (table1.col_float = $2) +)`, int64(11), 0.0) +} + +func TestOR(t *testing.T) { + assertClauseSerializeErr(t, OR(), "jet: syntax error, expression list empty") + assertClauseSerialize(t, OR(table1ColInt.IS_NULL()), `table1.col_int IS NULL`) // IS NULL doesn't add parenthesis + assertClauseSerialize(t, OR(table1ColInt.LT(Int(11))), `(table1.col_int < $1)`, int64(11)) + assertClauseSerialize(t, OR(table1ColInt.GT(Int(11)), table1ColFloat.EQ(Float(0))), + `( + (table1.col_int > $1) + OR (table1.col_float = $2) +)`, int64(11), 0.0) +} + func TestFuncAVG(t *testing.T) { assertClauseSerialize(t, AVG(table1ColFloat), "AVG(table1.col_float)") assertClauseSerialize(t, AVG(table1ColInt), "AVG(table1.col_int)") diff --git a/internal/jet/sql_builder.go b/internal/jet/sql_builder.go index 6241feec..e3fb61b2 100644 --- a/internal/jet/sql_builder.go +++ b/internal/jet/sql_builder.go @@ -26,6 +26,7 @@ type SQLBuilder struct { Debug bool } +const tabSize = 4 const defaultIdent = 5 // IncreaseIdent adds ident or defaultIdent number of spaces to each new line diff --git a/internal/jet/utils.go b/internal/jet/utils.go index 524c2c53..4ab3fae9 100644 --- a/internal/jet/utils.go +++ b/internal/jet/utils.go @@ -113,6 +113,17 @@ func ExpressionListToSerializerList(expressions []Expression) []Serializer { return ret } +// BoolExpressionListToExpressionList converts list of bool expressions to list of expressions +func BoolExpressionListToExpressionList(expressions []BoolExpression) []Expression { + var ret []Expression + + for _, expression := range expressions { + ret = append(ret, expression) + } + + return ret +} + // ColumnListToProjectionList func func ColumnListToProjectionList(columns []ColumnExpression) []Projection { var ret []Projection diff --git a/mysql/functions.go b/mysql/functions.go index 6d8193d9..b794ef70 100644 --- a/mysql/functions.go +++ b/mysql/functions.go @@ -2,6 +2,15 @@ package mysql import "github.com/go-jet/jet/v2/internal/jet" +// This functions can be used, instead of its method counterparts, to have a better indentation of a complex condition +// in the Go code and in the generated SQL. +var ( + // AND function adds AND operator between expressions. + AND = jet.AND + // OR function adds OR operator between expressions. + OR = jet.OR +) + // ROW is construct one table row from list of expressions. var ROW = jet.ROW diff --git a/mysql/select_statement_test.go b/mysql/select_statement_test.go index 37827d5f..bd3a0e9c 100644 --- a/mysql/select_statement_test.go +++ b/mysql/select_statement_test.go @@ -148,9 +148,9 @@ func TestSelect_NOT_EXISTS(t *testing.T) { SELECT table1.col_int AS "table1.col_int" FROM db.table1 WHERE NOT (EXISTS ( - SELECT table2.col_int AS "table2.col_int" - FROM db.table2 - WHERE table1.col_int = table2.col_int - )); + SELECT table2.col_int AS "table2.col_int" + FROM db.table2 + WHERE table1.col_int = table2.col_int + )); `) } diff --git a/postgres/functions.go b/postgres/functions.go index a20d1e11..cd2c130a 100644 --- a/postgres/functions.go +++ b/postgres/functions.go @@ -2,6 +2,15 @@ package postgres import "github.com/go-jet/jet/v2/internal/jet" +// This functions can be used, instead of its method counterparts, to have a better indentation of a complex condition +// in the Go code and in the generated SQL. +var ( + // AND function adds AND operator between expressions. + AND = jet.AND + // OR function adds OR operator between expressions. + OR = jet.OR +) + // ROW is construct one table row from list of expressions. var ROW = jet.ROW diff --git a/sqlite/functions.go b/sqlite/functions.go index 2b70714b..d7142747 100644 --- a/sqlite/functions.go +++ b/sqlite/functions.go @@ -6,6 +6,15 @@ import ( "time" ) +// This functions can be used, instead of its method counterparts, to have a better indentation of a complex condition +// in the Go code and in the generated SQL. +var ( + // AND function adds AND operator between expressions. + AND = jet.AND + // OR function adds OR operator between expressions. + OR = jet.OR +) + // ROW is construct one table row from list of expressions. func ROW(expressions ...Expression) Expression { return jet.NewFunc("", expressions, nil) diff --git a/sqlite/select_statement_test.go b/sqlite/select_statement_test.go index a42fe06d..5c4f9c3c 100644 --- a/sqlite/select_statement_test.go +++ b/sqlite/select_statement_test.go @@ -148,9 +148,9 @@ func TestSelect_NOT_EXISTS(t *testing.T) { SELECT table1.col_int AS "table1.col_int" FROM db.table1 WHERE NOT (EXISTS ( - SELECT table2.col_int AS "table2.col_int" - FROM db.table2 - WHERE table1.col_int = table2.col_int - )); + SELECT table2.col_int AS "table2.col_int" + FROM db.table2 + WHERE table1.col_int = table2.col_int + )); `) } diff --git a/tests/mysql/with_test.go b/tests/mysql/with_test.go index cc8dfd6f..d7d8d3d7 100644 --- a/tests/mysql/with_test.go +++ b/tests/mysql/with_test.go @@ -165,9 +165,9 @@ WITH payments_to_delete AS ( ) DELETE FROM dvds.payment WHERE payment.payment_id IN ( - SELECT payments_to_delete.''payment.payment_id'' AS "payment.payment_id" - FROM payments_to_delete - ); + SELECT payments_to_delete.''payment.payment_id'' AS "payment.payment_id" + FROM payments_to_delete + ); `, "''", "`")) tx, err := db.Begin() diff --git a/tests/postgres/chinook_db_test.go b/tests/postgres/chinook_db_test.go index 684abc2c..2d9821cb 100644 --- a/tests/postgres/chinook_db_test.go +++ b/tests/postgres/chinook_db_test.go @@ -38,6 +38,152 @@ ORDER BY "Album"."AlbumId" ASC; requireQueryLogged(t, stmt, 347) } +func TestComplex_AND_OR(t *testing.T) { + stmt := SELECT( + Artist.AllColumns, + Album.AllColumns, + Track.AllColumns, + ).FROM( + Artist. + LEFT_JOIN(Album, Artist.ArtistId.EQ(Album.ArtistId)). + LEFT_JOIN(Track, Track.AlbumId.EQ(Album.AlbumId)), + ).WHERE( + AND( + Artist.ArtistId.BETWEEN(Int(5), Int(11)), + Album.AlbumId.GT_EQ(Int(7)), + Track.TrackId.GT(Int(74)), + OR( + Track.GenreId.EQ(Int(2)), + Track.UnitPrice.GT(Float(1.01)), + ), + Track.TrackId.LT(Int(125)), + ), + ).ORDER_BY( + Artist.ArtistId, + Album.AlbumId, + Track.TrackId, + ) + + testutils.AssertDebugStatementSql(t, stmt, ` +SELECT "Artist"."ArtistId" AS "Artist.ArtistId", + "Artist"."Name" AS "Artist.Name", + "Album"."AlbumId" AS "Album.AlbumId", + "Album"."Title" AS "Album.Title", + "Album"."ArtistId" AS "Album.ArtistId", + "Track"."TrackId" AS "Track.TrackId", + "Track"."Name" AS "Track.Name", + "Track"."AlbumId" AS "Track.AlbumId", + "Track"."MediaTypeId" AS "Track.MediaTypeId", + "Track"."GenreId" AS "Track.GenreId", + "Track"."Composer" AS "Track.Composer", + "Track"."Milliseconds" AS "Track.Milliseconds", + "Track"."Bytes" AS "Track.Bytes", + "Track"."UnitPrice" AS "Track.UnitPrice" +FROM chinook."Artist" + LEFT JOIN chinook."Album" ON ("Artist"."ArtistId" = "Album"."ArtistId") + LEFT JOIN chinook."Track" ON ("Track"."AlbumId" = "Album"."AlbumId") +WHERE ( + ("Artist"."ArtistId" BETWEEN 5 AND 11) + AND ("Album"."AlbumId" >= 7) + AND ("Track"."TrackId" > 74) + AND ( + ("Track"."GenreId" = 2) + OR ("Track"."UnitPrice" > 1.01) + ) + AND ("Track"."TrackId" < 125) + ) +ORDER BY "Artist"."ArtistId", "Album"."AlbumId", "Track"."TrackId"; +`) + + var dest []struct { + model.Artist + + Albums []struct { + model.Album + + Tracks []model.Track + } + } + + err := stmt.Query(db, &dest) + require.NoError(t, err) + + testutils.AssertJSON(t, dest, ` +[ + { + "ArtistId": 6, + "Name": "Ant�nio Carlos Jobim", + "Albums": [ + { + "AlbumId": 8, + "Title": "Warner 25 Anos", + "ArtistId": 6, + "Tracks": [ + { + "TrackId": 75, + "Name": "O Boto (B�to)", + "AlbumId": 8, + "MediaTypeId": 1, + "GenreId": 2, + "Composer": null, + "Milliseconds": 366837, + "Bytes": 12089673, + "UnitPrice": 0.99 + }, + { + "TrackId": 76, + "Name": "Canta, Canta Mais", + "AlbumId": 8, + "MediaTypeId": 1, + "GenreId": 2, + "Composer": null, + "Milliseconds": 271856, + "Bytes": 8719426, + "UnitPrice": 0.99 + } + ] + } + ] + }, + { + "ArtistId": 10, + "Name": "Billy Cobham", + "Albums": [ + { + "AlbumId": 13, + "Title": "The Best Of Billy Cobham", + "ArtistId": 10, + "Tracks": [ + { + "TrackId": 123, + "Name": "Quadrant", + "AlbumId": 13, + "MediaTypeId": 1, + "GenreId": 2, + "Composer": "Billy Cobham", + "Milliseconds": 261851, + "Bytes": 8538199, + "UnitPrice": 0.99 + }, + { + "TrackId": 124, + "Name": "Snoopy's search-Red baron", + "AlbumId": 13, + "MediaTypeId": 1, + "GenreId": 2, + "Composer": "Billy Cobham", + "Milliseconds": 456071, + "Bytes": 15075616, + "UnitPrice": 0.99 + } + ] + } + ] + } +] +`) +} + func TestJoinEverything(t *testing.T) { manager := Employee.AS("Manager") diff --git a/tests/postgres/delete_test.go b/tests/postgres/delete_test.go index 47637e1e..abbb3449 100644 --- a/tests/postgres/delete_test.go +++ b/tests/postgres/delete_test.go @@ -124,9 +124,11 @@ func TestDeleteFrom(t *testing.T) { table.Actor, ). WHERE( - table.Staff.StaffID.EQ(table.Rental.StaffID). - AND(table.Staff.StaffID.EQ(Int(2))). - AND(table.Rental.RentalID.LT(Int(10))), + AND( + table.Staff.StaffID.EQ(table.Rental.StaffID), + table.Store.StoreID.EQ(Int(2)), + table.Rental.RentalID.LT(Int(10)), + ), ). RETURNING( table.Rental.AllColumns, @@ -138,7 +140,11 @@ DELETE FROM dvds.rental USING dvds.staff INNER JOIN dvds.store ON (store.store_id = staff.staff_id), dvds.actor -WHERE ((staff.staff_id = rental.staff_id) AND (staff.staff_id = $1)) AND (rental.rental_id < $2) +WHERE ( + (staff.staff_id = rental.staff_id) + AND (store.store_id = $1) + AND (rental.rental_id < $2) + ) RETURNING rental.rental_id AS "rental.rental_id", rental.rental_date AS "rental.rental_date", rental.inventory_id AS "rental.inventory_id", diff --git a/tests/postgres/select_test.go b/tests/postgres/select_test.go index e95d92ad..304acb8c 100644 --- a/tests/postgres/select_test.go +++ b/tests/postgres/select_test.go @@ -395,8 +395,15 @@ func TestExecution1(t *testing.T) { Customer.CustomerID, Customer.LastName, ). - WHERE(City.City.EQ(String("London")).OR(City.City.EQ(String("York")))). - ORDER_BY(City.CityID, Address.AddressID, Customer.CustomerID) + WHERE( + OR( + City.City.EQ(String("London")), + City.City.EQ(String("York")), + ), + ). + ORDER_BY( + City.CityID, Address.AddressID, Customer.CustomerID, + ) testutils.AssertDebugStatementSql(t, stmt, ` SELECT city.city_id AS "city.city_id", @@ -408,7 +415,10 @@ SELECT city.city_id AS "city.city_id", FROM dvds.city INNER JOIN dvds.address ON (address.city_id = city.city_id) INNER JOIN dvds.customer ON (customer.address_id = address.address_id) -WHERE (city.city = 'London') OR (city.city = 'York') +WHERE ( + (city.city = 'London') + OR (city.city = 'York') + ) ORDER BY city.city_id, address.address_id, customer.customer_id; `, "London", "York") @@ -1073,9 +1083,9 @@ SELECT film.film_id AS "film.film_id", film.fulltext AS "film.fulltext" FROM dvds.film WHERE film.rental_rate = ( - SELECT MAX(film.rental_rate) - FROM dvds.film - ) + SELECT MAX(film.rental_rate) + FROM dvds.film + ) ORDER BY film.film_id ASC; ` diff --git a/tests/postgres/with_test.go b/tests/postgres/with_test.go index e6d23ee8..c78ca8a4 100644 --- a/tests/postgres/with_test.go +++ b/tests/postgres/with_test.go @@ -73,9 +73,9 @@ WITH regional_sales AS ( SELECT regional_sales."orders.ship_region" AS "orders.ship_region" FROM regional_sales WHERE regional_sales.total_sales > (( - SELECT SUM(regional_sales.total_sales) - FROM regional_sales - ) / 50) + SELECT SUM(regional_sales.total_sales) + FROM regional_sales + ) / 50) ) SELECT orders.ship_region AS "orders.ship_region", order_details.product_id AS "order_details.product_id", @@ -84,9 +84,9 @@ SELECT orders.ship_region AS "orders.ship_region", FROM northwind.orders INNER JOIN northwind.order_details ON (orders.order_id = order_details.order_id) WHERE orders.ship_region IN ( - SELECT top_region."orders.ship_region" AS "orders.ship_region" - FROM top_region - ) + SELECT top_region."orders.ship_region" AS "orders.ship_region" + FROM top_region + ) GROUP BY orders.ship_region, order_details.product_id ORDER BY SUM(order_details.quantity) DESC; `) @@ -150,18 +150,18 @@ func TestWithStatementDeleteAndInsert(t *testing.T) { WITH remove_discontinued_orders AS ( DELETE FROM northwind.order_details WHERE order_details.product_id IN ( - SELECT products.product_id AS "products.product_id" - FROM northwind.products - WHERE products.discontinued = $1 - ) + SELECT products.product_id AS "products.product_id" + FROM northwind.products + WHERE products.discontinued = $1 + ) RETURNING order_details.product_id AS "order_details.product_id" ),update_discontinued_price AS ( UPDATE northwind.products SET unit_price = $2 WHERE products.product_id IN ( - SELECT remove_discontinued_orders."order_details.product_id" AS "order_details.product_id" - FROM remove_discontinued_orders - ) + SELECT remove_discontinued_orders."order_details.product_id" AS "order_details.product_id" + FROM remove_discontinued_orders + ) RETURNING products.product_id AS "products.product_id", products.product_name AS "products.product_name", products.supplier_id AS "products.supplier_id", diff --git a/tests/sqlite/with_test.go b/tests/sqlite/with_test.go index 92cd331e..402df2f0 100644 --- a/tests/sqlite/with_test.go +++ b/tests/sqlite/with_test.go @@ -154,9 +154,9 @@ WITH payments_to_update AS ( UPDATE payment SET amount = 0 WHERE payment.payment_id IN ( - SELECT payments_to_update.''payment.payment_id'' AS "payment.payment_id" - FROM payments_to_update - ); + SELECT payments_to_update.''payment.payment_id'' AS "payment.payment_id" + FROM payments_to_update + ); `, "''", "`", -1)) tx := beginDBTx(t) @@ -206,9 +206,9 @@ WITH payments_to_delete AS ( ) DELETE FROM payment WHERE payment.payment_id IN ( - SELECT payments_to_delete.''payment.payment_id'' AS "payment.payment_id" - FROM payments_to_delete - ); + SELECT payments_to_delete.''payment.payment_id'' AS "payment.payment_id" + FROM payments_to_delete + ); `, "''", "`", -1)) tx := beginDBTx(t)