Merge pull request #3 from aldy505/feat/upsert

Feat/upsert (WIP)
This commit is contained in:
Reinaldy Rafli 2021-07-31 11:51:10 +07:00 committed by GitHub
commit cb9e7b01c4
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
14 changed files with 505 additions and 48 deletions

View File

@ -2,7 +2,7 @@
[![Go Reference](https://pkg.go.dev/badge/github.com/aldy505/bob.svg)](https://pkg.go.dev/github.com/aldy505/bob) [![Go Report Card](https://goreportcard.com/badge/github.com/aldy505/bob)](https://goreportcard.com/report/github.com/aldy505/bob) ![GitHub](https://img.shields.io/github/license/aldy505/bob) [![CodeFactor](https://www.codefactor.io/repository/github/aldy505/bob/badge)](https://www.codefactor.io/repository/github/aldy505/bob) [![codecov](https://codecov.io/gh/aldy505/bob/branch/master/graph/badge.svg?token=Noeexg5xEJ)](https://codecov.io/gh/aldy505/bob) [![Codacy Badge](https://app.codacy.com/project/badge/Grade/9b78970127c74c1a923533e05f65848d)](https://www.codacy.com/gh/aldy505/bob/dashboard?utm_source=github.com&utm_medium=referral&utm_content=aldy505/bob&utm_campaign=Badge_Grade) [![Build test](https://github.com/aldy505/bob/actions/workflows/build.yml/badge.svg)](https://github.com/aldy505/bob/actions/workflows/build.yml) [![Test and coverage](https://github.com/aldy505/bob/actions/workflows/coverage.yml/badge.svg)](https://github.com/aldy505/bob/actions/workflows/coverage.yml) [![Go Reference](https://pkg.go.dev/badge/github.com/aldy505/bob.svg)](https://pkg.go.dev/github.com/aldy505/bob) [![Go Report Card](https://goreportcard.com/badge/github.com/aldy505/bob)](https://goreportcard.com/report/github.com/aldy505/bob) ![GitHub](https://img.shields.io/github/license/aldy505/bob) [![CodeFactor](https://www.codefactor.io/repository/github/aldy505/bob/badge)](https://www.codefactor.io/repository/github/aldy505/bob) [![codecov](https://codecov.io/gh/aldy505/bob/branch/master/graph/badge.svg?token=Noeexg5xEJ)](https://codecov.io/gh/aldy505/bob) [![Codacy Badge](https://app.codacy.com/project/badge/Grade/9b78970127c74c1a923533e05f65848d)](https://www.codacy.com/gh/aldy505/bob/dashboard?utm_source=github.com&utm_medium=referral&utm_content=aldy505/bob&utm_campaign=Badge_Grade) [![Build test](https://github.com/aldy505/bob/actions/workflows/build.yml/badge.svg)](https://github.com/aldy505/bob/actions/workflows/build.yml) [![Test and coverage](https://github.com/aldy505/bob/actions/workflows/coverage.yml/badge.svg)](https://github.com/aldy505/bob/actions/workflows/coverage.yml)
Think of this as an extension of [Squirrel](https://github.com/Masterminds/squirrel) with functionability like [Knex](https://knexjs.org/). I still use Squirrel for other types of queries (insert, select, and all that), but I needed some SQL builder for create table and some other stuffs. Think of this as an extension of [Squirrel](https://github.com/Masterminds/squirrel) with functionability like [Knex](https://knexjs.org/). I still use Squirrel for other types of queries (insert, select, and all that), but I needed some SQL builder for create table and some other stuffs. Including database creation & upsert.
Oh, and of course, heavily inspired by [Bob the Builder](https://en.wikipedia.org/wiki/Bob_the_Builder). Oh, and of course, heavily inspired by [Bob the Builder](https://en.wikipedia.org/wiki/Bob_the_Builder).
@ -116,6 +116,44 @@ func main() {
} }
``` ```
### Upsert
```go
func main() {
sql, args, err := bob.
// Notice that you should give database dialect on the second params.
// Available database dialect are MySQL, PostgreSQL, SQLite, and MSSQL.
Upsert("users", bob.MySQL).
Columns("name", "email", "age").
// You could do multiple Values() call, but I'd suggest to not do it.
// Because this is an upsert function, not an insert one.
Values("Thomas Mueler", "tmueler@something.com", 25).
Replace("age", 25).
PlaceholderFormat(bob.Question).
ToSql()
// Another example for PostgreSQL
sql, args, err = bob.
Upsert("users", bob.PostgreSQL).
Columns("name", "email", "age").
Values("Billy Urtha", "billu@something.com", 30).
Key("email").
Replace("age", 40).
PlaceholderFormat(bob.Dollar).
ToSql()
// One more time, for MSSQL / SQL Server.
sql, args, err = bob.
Upsert("users", bob.MSSQL).
Columns("name", "email", "age").
Values("George Rust", "georgee@something.com", 19).
Key("email", "georgee@something.com").
Replace("age", 18).
PlaceholderFormat(bob.AtP).
ToSql()
}
```
### Placeholder format / Dialect ### Placeholder format / Dialect
Default placeholder is a question mark (MySQL-like). If you want to change it, simply use something like this: Default placeholder is a question mark (MySQL-like). If you want to change it, simply use something like this:
@ -222,12 +260,12 @@ func main() {
* `bob.DropTableIfExists(tableName)` - Drop a table if exists (`drop table if exists "users"`) * `bob.DropTableIfExists(tableName)` - Drop a table if exists (`drop table if exists "users"`)
* `bob.RenameTable(currentTable, desiredName)` - Rename a table (`rename table "users" to "people"`) * `bob.RenameTable(currentTable, desiredName)` - Rename a table (`rename table "users" to "people"`)
* `bob.Truncate(tableName)` - Truncate a table (`truncate "users"`) * `bob.Truncate(tableName)` - Truncate a table (`truncate "users"`)
* `bob.Upsert(tableName, dialect)` - UPSERT function (`insert into "users" ("name", "email") values (?, ?) on duplicate key update email = ?`)
### TODO ### TODO
Meaning these are some ideas for the future development of Bob. Meaning these are some ideas for the future development of Bob.
* `bob.Upsert(tableName)` - UPSERT function (`insert into "users" ("name", "email") values (?, ?) on duplicate key update email = ?`)
* `bob.ExecWith()` - Just like Squirrel's [ExecWith](https://pkg.go.dev/github.com/Masterminds/squirrel?utm_source=godoc#ExecWith) * `bob.ExecWith()` - Just like Squirrel's [ExecWith](https://pkg.go.dev/github.com/Masterminds/squirrel?utm_source=godoc#ExecWith)
* `bob.Count(tableName, columnName)` - Count query (`select count("active") from "users"`) * `bob.Count(tableName, columnName)` - Count query (`select count("active") from "users"`)

83
bob.go
View File

@ -8,9 +8,20 @@ import (
// ErrEmptyTable is a common database/sql error if a table is empty or no rows is returned by the query. // ErrEmptyTable is a common database/sql error if a table is empty or no rows is returned by the query.
var ErrEmptyTable = errors.New("sql: no rows in result set") var ErrEmptyTable = errors.New("sql: no rows in result set")
// ErrEmptyTable is a common pgx error if a table is empty or no rows is returned by the query. // ErrEmptyTable is a common pgx error if a table is empty or no rows is returned by the query.
var ErrEmptyTablePgx = errors.New("no rows in result set") var ErrEmptyTablePgx = errors.New("no rows in result set")
// ErrDialectNotSupported tells you whether the dialect is supported or not.
var ErrDialectNotSupported = errors.New("provided database dialect is not supported")
const (
MySQL int = iota
PostgreSQL
SQLite
MSSQL
)
// BobBuilderType is the type for BobBuilder // BobBuilderType is the type for BobBuilder
type BobBuilderType builder.Builder type BobBuilderType builder.Builder
@ -21,12 +32,12 @@ type BobBuilder interface {
// CreateTable creates a table with CreateBuilder interface // CreateTable creates a table with CreateBuilder interface
func (b BobBuilderType) CreateTable(table string) CreateBuilder { func (b BobBuilderType) CreateTable(table string) CreateBuilder {
return CreateBuilder(b).Name(table) return CreateBuilder(b).name(table)
} }
// CreateTableIfNotExists creates a table with CreateBuilder interface, if the table doesn't exists. // CreateTableIfNotExists creates a table with CreateBuilder interface, if the table doesn't exists.
func (b BobBuilderType) CreateTableIfNotExists(table string) CreateBuilder { func (b BobBuilderType) CreateTableIfNotExists(table string) CreateBuilder {
return CreateBuilder(b).Name(table).IfNotExists() return CreateBuilder(b).name(table).ifNotExists()
} }
// HasTable checks if a table exists with HasBuilder interface // HasTable checks if a table exists with HasBuilder interface
@ -41,28 +52,49 @@ func (b BobBuilderType) HasColumn(column string) HasBuilder {
// DropTable drops (delete contents & remove) a table from the database. // DropTable drops (delete contents & remove) a table from the database.
func (b BobBuilderType) DropTable(table string) DropBuilder { func (b BobBuilderType) DropTable(table string) DropBuilder {
return DropBuilder(b).DropTable(table) return DropBuilder(b).dropTable(table)
} }
// DropTable drops (delete contents & remove) a table from the database if the table exists. // DropTable drops (delete contents & remove) a table from the database if the table exists.
func (b BobBuilderType) DropTableIfExists(table string) DropBuilder { func (b BobBuilderType) DropTableIfExists(table string) DropBuilder {
return DropBuilder(b).DropTable(table).IfExists() return DropBuilder(b).dropTable(table).ifExists()
} }
// RenameTable simply renames an exisisting table. // RenameTable simply renames an exisisting table.
func (b BobBuilderType) RenameTable(from, to string) RenameBuilder { func (b BobBuilderType) RenameTable(from, to string) RenameBuilder {
return RenameBuilder(b).From(from).To(to) return RenameBuilder(b).from(from).to(to)
} }
// Truncate performs TRUNCATE function. It deletes all contents from a table but not deleting the table. // Truncate performs TRUNCATE function. It deletes all contents from a table but not deleting the table.
func (b BobBuilderType) Truncate(table string) TruncateBuilder { func (b BobBuilderType) Truncate(table string) TruncateBuilder {
return TruncateBuilder(b).Truncate(table) return TruncateBuilder(b).truncate(table)
}
func (b BobBuilderType) Upsert(table string, dialect int) UpsertBuilder {
return UpsertBuilder(b).dialect(dialect).into(table)
} }
// BobStmtBuilder is the parent builder for BobBuilderType // BobStmtBuilder is the parent builder for BobBuilderType
var BobStmtBuilder = BobBuilderType(builder.EmptyBuilder) var BobStmtBuilder = BobBuilderType(builder.EmptyBuilder)
// CreateTable creates a table with CreateBuilder interface. // CreateTable creates a table with CreateBuilder interface.
// Refer to README for available column definition types.
//
// // Note that CREATE TABLE doesn't returns args params.
// sql, _, err := bob.
// CreateTable("tableName").
// // The first parameter is the column's name.
// // The second parameters and so on forth are extras.
// StringColumn("id", "NOT NULL", "PRIMARY KEY", "AUTOINCREMENT").
// StringColumn("email", "NOT NULL", "UNIQUE").
// // See the list of available column definition types through pkg.go.dev or README.
// TextColumn("password").
// // Or add your custom type.
// AddColumn(bob.ColumnDef{Name: "tableName", Type: "customType", Extras: []string{"NOT NULL"}}).
// ToSql()
// if err != nil {
// // handle your error
// }
func CreateTable(table string) CreateBuilder { func CreateTable(table string) CreateBuilder {
return BobStmtBuilder.CreateTable(table) return BobStmtBuilder.CreateTable(table)
} }
@ -101,3 +133,42 @@ func RenameTable(from, to string) RenameBuilder {
func Truncate(table string) TruncateBuilder { func Truncate(table string) TruncateBuilder {
return BobStmtBuilder.Truncate(table) return BobStmtBuilder.Truncate(table)
} }
// Upsert performs a UPSERT query with specified database dialect.
// Supported database includes MySQL, PostgreSQL, SQLite and MSSQL.
//
// // MySQL example:
// sql, args, err := bob.
// // Notice that you should give database dialect on the second params.
// // Available database dialect are MySQL, PostgreSQL, SQLite, and MSSQL.
// Upsert("users", bob.MySQL).
// Columns("name", "email", "age").
// // You could do multiple Values() call, but I'd suggest to not do it.
// // Because this is an upsert function, not an insert one.
// Values("Thomas Mueler", "tmueler@something.com", 25).
// Replace("age", 25).
// PlaceholderFormat(bob.Question).
// ToSql()
//
// // Another example for PostgreSQL:
// sql, args, err = bob.
// Upsert("users", bob.PostgreSQL).
// Columns("name", "email", "age").
// Values("Billy Urtha", "billu@something.com", 30).
// Key("email").
// Replace("age", 40).
// PlaceholderFormat(bob.Dollar).
// ToSql()
//
// // One more time, for MSSQL / SQL Server:
// sql, args, err = bob.
// Upsert("users", bob.MSSQL).
// Columns("name", "email", "age").
// Values("George Rust", "georgee@something.com", 19).
// Key("email", "georgee@something.com").
// Replace("age", 18).
// PlaceholderFormat(bob.AtP).
// ToSql()
func Upsert(table string, dialect int) UpsertBuilder {
return BobStmtBuilder.Upsert(table, dialect)
}

View File

@ -27,13 +27,13 @@ func init() {
builder.Register(CreateBuilder{}, createData{}) builder.Register(CreateBuilder{}, createData{})
} }
// Name sets the table name // name sets the table name
func (b CreateBuilder) Name(name string) CreateBuilder { func (b CreateBuilder) name(name string) CreateBuilder {
return builder.Set(b, "TableName", name).(CreateBuilder) return builder.Set(b, "TableName", name).(CreateBuilder)
} }
// IfNotExists adds IF NOT EXISTS to the query // ifNotExists adds IF NOT EXISTS to the query
func (b CreateBuilder) IfNotExists() CreateBuilder { func (b CreateBuilder) ifNotExists() CreateBuilder {
return builder.Set(b, "IfNotExists", true).(CreateBuilder) return builder.Set(b, "IfNotExists", true).(CreateBuilder)
} }

View File

@ -19,11 +19,11 @@ func init() {
} }
// DropTable sets which table to be dropped // DropTable sets which table to be dropped
func (b DropBuilder) DropTable(name string) DropBuilder { func (b DropBuilder) dropTable(name string) DropBuilder {
return builder.Set(b, "TableName", name).(DropBuilder) return builder.Set(b, "TableName", name).(DropBuilder)
} }
func (b DropBuilder) IfExists() DropBuilder { func (b DropBuilder) ifExists() DropBuilder {
return builder.Set(b, "IfExists", true).(DropBuilder) return builder.Set(b, "IfExists", true).(DropBuilder)
} }
@ -46,7 +46,7 @@ func (d *dropData) ToSql() (sqlStr string, args []interface{}, err error) {
sql.WriteString("IF EXISTS ") sql.WriteString("IF EXISTS ")
} }
sql.WriteString("\""+d.TableName+"\";") sql.WriteString("\"" + d.TableName + "\";")
sqlStr = sql.String() sqlStr = sql.String()
return return

View File

@ -7,7 +7,7 @@ import (
) )
func TestDrop(t *testing.T) { func TestDrop(t *testing.T) {
t.Run("should be able to create regular drop query", func (t *testing.T) { t.Run("should be able to create regular drop query", func(t *testing.T) {
sql, _, err := bob.DropTable("users").ToSql() sql, _, err := bob.DropTable("users").ToSql()
if err != nil { if err != nil {
t.Error(err) t.Error(err)

3
has.go
View File

@ -8,9 +8,6 @@ import (
"github.com/lann/builder" "github.com/lann/builder"
) )
// TODO - The whole file is a todo
// Meant to find two things: HasTable and HasColumn(s)
type HasBuilder builder.Builder type HasBuilder builder.Builder
type hasData struct { type hasData struct {

View File

@ -1,13 +1,12 @@
package bob_test package bob_test
import ( import (
"reflect"
"testing" "testing"
"github.com/aldy505/bob" "github.com/aldy505/bob"
) )
// TODO - do more test
func TestHas(t *testing.T) { func TestHas(t *testing.T) {
t.Run("should be able to create a hasTable query", func(t *testing.T) { t.Run("should be able to create a hasTable query", func(t *testing.T) {
sql, args, err := bob.HasTable("users").ToSql() sql, args, err := bob.HasTable("users").ToSql()
@ -19,8 +18,8 @@ func TestHas(t *testing.T) {
if sql != result { if sql != result {
t.Fatal("sql is not equal with result:", sql) t.Fatal("sql is not equal with result:", sql)
} }
argsResult := []interface{}{"users"}
if len(args) != 1 { if !reflect.DeepEqual(args, argsResult) {
t.Fatal("args is not equal with argsResult:", args) t.Fatal("args is not equal with argsResult:", args)
} }
}) })
@ -36,7 +35,8 @@ func TestHas(t *testing.T) {
t.Fatal("sql is not equal with result:", sql) t.Fatal("sql is not equal with result:", sql)
} }
if len(args) != 2 { argsResult := []interface{}{"users", "name"}
if !reflect.DeepEqual(args, argsResult) {
t.Fatal("args is not equal with argsResult:", args) t.Fatal("args is not equal with argsResult:", args)
} }
}) })
@ -52,7 +52,8 @@ func TestHas(t *testing.T) {
t.Fatal("sql is not equal with result:", sql) t.Fatal("sql is not equal with result:", sql)
} }
if len(args) != 2 { argsResult := []interface{}{"users", "name"}
if !reflect.DeepEqual(args, argsResult) {
t.Fatal("args is not equal with argsResult:", args) t.Fatal("args is not equal with argsResult:", args)
} }
}) })
@ -68,12 +69,13 @@ func TestHas(t *testing.T) {
t.Fatal("sql is not equal with result:", sql) t.Fatal("sql is not equal with result:", sql)
} }
if len(args) != 2 { argsResult := []interface{}{"users", "private"}
if !reflect.DeepEqual(args, argsResult) {
t.Fatal("args is not equal with argsResult:", args) t.Fatal("args is not equal with argsResult:", args)
} }
}) })
t.Run("should be able to have a different placeholder", func(t *testing.T) { t.Run("should be able to have a different placeholder - dollar", func(t *testing.T) {
sql, args, err := bob.HasTable("users").HasColumn("name").PlaceholderFormat(bob.Dollar).ToSql() sql, args, err := bob.HasTable("users").HasColumn("name").PlaceholderFormat(bob.Dollar).ToSql()
if err != nil { if err != nil {
t.Fatal(err.Error()) t.Fatal(err.Error())
@ -84,7 +86,8 @@ func TestHas(t *testing.T) {
t.Fatal("sql is not equal with result:", sql) t.Fatal("sql is not equal with result:", sql)
} }
if len(args) != 2 { argsResult := []interface{}{"users", "name"}
if !reflect.DeepEqual(args, argsResult) {
t.Fatal("args is not equal with argsResult:", args) t.Fatal("args is not equal with argsResult:", args)
} }
}) })

View File

@ -17,13 +17,13 @@ func init() {
builder.Register(RenameBuilder{}, renameData{}) builder.Register(RenameBuilder{}, renameData{})
} }
// From sets existing table name // from sets existing table name
func (b RenameBuilder) From(name string) RenameBuilder { func (b RenameBuilder) from(name string) RenameBuilder {
return builder.Set(b, "From", name).(RenameBuilder) return builder.Set(b, "From", name).(RenameBuilder)
} }
// To sets desired table name // to sets desired table name
func (b RenameBuilder) To(name string) RenameBuilder { func (b RenameBuilder) to(name string) RenameBuilder {
return builder.Set(b, "To", name).(RenameBuilder) return builder.Set(b, "To", name).(RenameBuilder)
} }
@ -38,6 +38,6 @@ func (d *renameData) ToSql() (sqlStr string, args []interface{}, err error) {
if len(d.From) == 0 || d.From == "" || len(d.To) == 0 || d.To == "" { if len(d.From) == 0 || d.From == "" || len(d.To) == 0 || d.To == "" {
err = errors.New("rename statement must specify a table") err = errors.New("rename statement must specify a table")
} }
sqlStr = "RENAME TABLE \""+d.From+"\" TO \""+d.To+"\";" sqlStr = "RENAME TABLE \"" + d.From + "\" TO \"" + d.To + "\";"
return return
} }

View File

@ -7,7 +7,7 @@ import (
) )
func TestRename(t *testing.T) { func TestRename(t *testing.T) {
t.Run("should be able to create rename query", func (t *testing.T) { t.Run("should be able to create rename query", func(t *testing.T) {
sql, _, err := bob.RenameTable("users", "teachers").ToSql() sql, _, err := bob.RenameTable("users", "teachers").ToSql()
if err != nil { if err != nil {
t.Error(err) t.Error(err)

View File

@ -17,7 +17,7 @@ func init() {
} }
// Truncate sets which table to be dropped // Truncate sets which table to be dropped
func (b TruncateBuilder) Truncate(name string) TruncateBuilder { func (b TruncateBuilder) truncate(name string) TruncateBuilder {
return builder.Set(b, "TableName", name).(TruncateBuilder) return builder.Set(b, "TableName", name).(TruncateBuilder)
} }
@ -32,6 +32,6 @@ func (d *truncateData) ToSql() (sqlStr string, args []interface{}, err error) {
if len(d.TableName) == 0 || d.TableName == "" { if len(d.TableName) == 0 || d.TableName == "" {
err = errors.New("truncate statement must specify a table") err = errors.New("truncate statement must specify a table")
} }
sqlStr = "TRUNCATE \""+d.TableName+"\";" sqlStr = "TRUNCATE \"" + d.TableName + "\";"
return return
} }

View File

@ -7,7 +7,7 @@ import (
) )
func TestTruncate(t *testing.T) { func TestTruncate(t *testing.T) {
t.Run("should be able to create truncate query", func (t *testing.T) { t.Run("should be able to create truncate query", func(t *testing.T) {
sql, _, err := bob.Truncate("users").ToSql() sql, _, err := bob.Truncate("users").ToSql()
if err != nil { if err != nil {
t.Error(err) t.Error(err)

193
upsert.go Normal file
View File

@ -0,0 +1,193 @@
package bob
import (
"bytes"
"errors"
"strings"
"github.com/lann/builder"
)
type UpsertBuilder builder.Builder
type upsertData struct {
Dialect int
Into string
Columns []string
Values [][]interface{}
Key []interface{}
Replace [][]interface{}
Placeholder string
}
func init() {
builder.Register(UpsertBuilder{}, upsertData{})
}
// dialect specifies database dialect used.
func (u UpsertBuilder) dialect(db int) UpsertBuilder {
return builder.Set(u, "Dialect", db).(UpsertBuilder)
}
// Table sets which table to be dropped.
func (u UpsertBuilder) into(name string) UpsertBuilder {
return builder.Set(u, "Into", name).(UpsertBuilder)
}
// Columns sets the columns for the data to be inserted.
func (u UpsertBuilder) Columns(columns ...string) UpsertBuilder {
return builder.Extend(u, "Columns", columns).(UpsertBuilder)
}
// Values sets the values in relation with the columns.
// Please not that only string, int, and bool type are supported.
// Inputting other types other than those might result in your SQL not working properly.
func (u UpsertBuilder) Values(values ...interface{}) UpsertBuilder {
return builder.Append(u, "Values", values).(UpsertBuilder)
}
// Key specifies which key to be checked on conflict.
// Must be used on PostgreSQL and SQLite.
func (u UpsertBuilder) Key(key ...interface{}) UpsertBuilder {
var value interface{}
column := key[0]
if len(key) > 1 && key[0] != nil {
value = key[1]
} else {
value = ""
}
return builder.Extend(u, "Key", []interface{}{column, value}).(UpsertBuilder)
}
// Replace sets the column and value respectively for the data to be changed on
// a specific row.
func (u UpsertBuilder) Replace(column interface{}, value interface{}) UpsertBuilder {
return builder.Append(u, "Replace", []interface{}{column, value}).(UpsertBuilder)
}
// PlaceholderFormat changes the default placeholder (?) to desired placeholder.
func (u UpsertBuilder) PlaceholderFormat(f string) UpsertBuilder {
return builder.Set(u, "Placeholder", f).(UpsertBuilder)
}
// ToSql returns 3 variables filled out with the correct values based on bindings, etc.
func (u UpsertBuilder) ToSql() (string, []interface{}, error) {
data := builder.GetStruct(u).(upsertData)
return data.ToSql()
}
// ToSql returns 3 variables filled out with the correct values based on bindings, etc.
func (d *upsertData) ToSql() (sqlStr string, args []interface{}, err error) {
if len(d.Into) == 0 || d.Into == "" {
err = errors.New("upsert statements must specify a table")
return
}
if len(d.Columns) == 0 || d.Columns[0] == "" {
err = errors.New("upsert statement must have at least one column")
return
}
if len(d.Values) == 0 {
err = errors.New("upsert statements must have at least one set of values")
return
}
if len(d.Replace) == 0 {
err = errors.New("upsert statement must have at least one key value pair to be replaced")
return
}
sql := &bytes.Buffer{}
if d.Dialect == MSSQL {
if len(d.Key) == 0 {
err = errors.New("unique key and value must be provided for MS SQL")
return
}
sql.WriteString("IF NOT EXISTS (SELECT * FROM \"" + d.Into + "\" WHERE \"" + d.Key[0].(string) + "\" = ?) ")
args = append(args, d.Key[1])
}
sql.WriteString("INSERT INTO ")
sql.WriteString("\"" + d.Into + "\"")
sql.WriteString(" ")
var columns []string
for _, v := range d.Columns {
columns = append(columns, "\""+v+"\"")
}
sql.WriteString("(")
sql.WriteString(strings.Join(columns, ", "))
sql.WriteString(") ")
sql.WriteString("VALUES ")
var values []string
for i := 0; i < len(d.Values); i++ {
var tempValues []string
for _, v := range d.Values[i] {
args = append(args, v)
tempValues = append(tempValues, "?")
}
values = append(values, "("+strings.Join(tempValues, ", ")+")")
}
sql.WriteString(strings.Join(values, ", "))
sql.WriteString(" ")
var replaces []string
for i := 0; i < len(d.Replace); i++ {
args = append(args, d.Replace[i][1])
replace := "\"" + d.Replace[i][0].(string) + "\" = ?"
replaces = append(replaces, replace)
}
if d.Dialect == MySQL {
// INSERT INTO table (col) VALUES (values) ON DUPLICATE KEY UPDATE col = value
sql.WriteString("ON DUPLICATE KEY UPDATE ")
sql.WriteString(strings.Join(replaces, ", "))
} else if d.Dialect == PostgreSQL || d.Dialect == SQLite {
// INSERT INTO players (user_name, age) VALUES('steven', 32) ON CONFLICT(user_name) DO UPDATE SET age=excluded.age;
if len(d.Key) == 0 {
err = errors.New("unique key must be provided for PostgreSQL and SQLite")
return
}
sql.WriteString("ON CONFLICT ")
sql.WriteString("(\"" + d.Key[0].(string) + "\") ")
sql.WriteString("DO UPDATE SET ")
sql.WriteString(strings.Join(replaces, ", "))
} else if d.Dialect == MSSQL {
// IF NOT EXISTS (SELECT * FROM dbo.Table1 WHERE ID = @ID)
// INSERT INTO dbo.Table1(ID, Name, ItemName, ItemCatName, ItemQty)
// VALUES(@ID, @Name, @ItemName, @ItemCatName, @ItemQty)
// ELSE
// UPDATE dbo.Table1
// SET Name = @Name,
// ItemName = @ItemName,
// ItemCatName = @ItemCatName,
// ItemQty = @ItemQty
// WHERE ID = @ID
sql.WriteString("ELSE ")
sql.WriteString("UPDATE \"" + d.Into + "\" SET ")
sql.WriteString(strings.Join(replaces, ", "))
sql.WriteString(" WHERE \"" + d.Key[0].(string) + "\" = ?")
args = append(args, d.Key[1])
} else {
err = ErrDialectNotSupported
return
}
sql.WriteString(";")
sqlStr = ReplacePlaceholder(sql.String(), d.Placeholder)
return
}

155
upsert_test.go Normal file
View File

@ -0,0 +1,155 @@
package bob_test
import (
"reflect"
"testing"
"github.com/aldy505/bob"
)
func TestUpsert_MySQL(t *testing.T) {
sql, args, err := bob.
Upsert("users", bob.MySQL).
Columns("name", "email").
Values("John Doe", "john@doe.com").
Replace("name", "John Does").
ToSql()
if err != nil {
t.Error(err)
}
desiredSql := "INSERT INTO \"users\" (\"name\", \"email\") VALUES (?, ?) ON DUPLICATE KEY UPDATE \"name\" = ?;"
desiredArgs := []interface{}{"John Doe", "john@doe.com", "John Does"}
if sql != desiredSql {
t.Error("sql is not the same as result: ", sql)
}
if !reflect.DeepEqual(args, desiredArgs) {
t.Error("args is not the same as result: ", args)
}
}
func TestUpsert_PostgreSQL(t *testing.T) {
sql, args, err := bob.
Upsert("users", bob.PostgreSQL).
Columns("name", "email").
Values("John Doe", "john@doe.com").
Key("email").
Replace("name", "John Does").
PlaceholderFormat(bob.Dollar).
ToSql()
if err != nil {
t.Error(err)
}
desiredSql := "INSERT INTO \"users\" (\"name\", \"email\") VALUES ($1, $2) ON CONFLICT (\"email\") DO UPDATE SET \"name\" = $3;"
desiredArgs := []interface{}{"John Doe", "john@doe.com", "John Does"}
if sql != desiredSql {
t.Error("sql is not the same as result: ", sql)
}
if !reflect.DeepEqual(args, desiredArgs) {
t.Error("args is not the same as result: ", args)
}
}
func TestUpsert_SQLite(t *testing.T) {
sql, args, err := bob.
Upsert("users", bob.SQLite).
Columns("name", "email").
Values("John Doe", "john@doe.com").
Key("email").
Replace("name", "John Does").
PlaceholderFormat(bob.Question).
ToSql()
if err != nil {
t.Error(err)
}
desiredSql := "INSERT INTO \"users\" (\"name\", \"email\") VALUES (?, ?) ON CONFLICT (\"email\") DO UPDATE SET \"name\" = ?;"
desiredArgs := []interface{}{"John Doe", "john@doe.com", "John Does"}
if sql != desiredSql {
t.Error("sql is not the same as result: ", sql)
}
if !reflect.DeepEqual(args, desiredArgs) {
t.Error("args is not the same as result: ", args)
}
}
func TestUpsert_MSSQL(t *testing.T) {
sql, args, err := bob.
Upsert("users", bob.MSSQL).
Columns("name", "email").
Values("John Doe", "john@doe.com").
Key("email", "john@doe.com").
Replace("name", "John Does").
PlaceholderFormat(bob.AtP).
ToSql()
if err != nil {
t.Error(err)
}
desiredSql := "IF NOT EXISTS (SELECT * FROM \"users\" WHERE \"email\" = @p1) INSERT INTO \"users\" (\"name\", \"email\") VALUES (@p2, @p3) ELSE UPDATE \"users\" SET \"name\" = @p4 WHERE \"email\" = @p5;"
desiredArgs := []interface{}{"john@doe.com", "John Doe", "john@doe.com", "John Does", "john@doe.com"}
if sql != desiredSql {
t.Error("sql is not the same as result: ", sql)
}
if !reflect.DeepEqual(args, desiredArgs) {
t.Error("args is not the same as result: ", args)
}
}
func TestUpsert_EmitErrors(t *testing.T) {
t.Run("should emit error without table name", func(t *testing.T) {
_, _, err := bob.Upsert("", bob.MySQL).ToSql()
if err == nil && err.Error() != "upsert statement must specify a table" {
t.Error(err)
}
})
t.Run("should emit error without columns", func(t *testing.T) {
_, _, err := bob.Upsert("users", bob.PostgreSQL).ToSql()
if err.Error() != "upsert statement must have at least one column" {
t.Error(err)
}
})
t.Run("should emit error without values", func(t *testing.T) {
_, _, err := bob.Upsert("users", bob.PostgreSQL).Columns("name", "email").ToSql()
if err.Error() != "upsert statements must have at least one set of values" {
t.Error(err)
}
})
t.Run("should emit error without replaces", func(t *testing.T) {
_, _, err := bob.Upsert("users", bob.PostgreSQL).Columns("name", "email").Values("James", "james@mail.com").ToSql()
if err.Error() != "upsert statement must have at least one key value pair to be replaced" {
t.Error(err)
}
})
t.Run("should emit error without key and value for mssql", func(t *testing.T) {
_, _, err := bob.Upsert("users", bob.MSSQL).Columns("name", "email").Values("James", "james@mail.com").Replace("name", "Thomas").ToSql()
if err.Error() != "unique key and value must be provided for MS SQL" {
t.Error(err)
}
})
t.Run("should emit error without key and value for mssql", func(t *testing.T) {
_, _, err := bob.Upsert("users", bob.SQLite).Columns("name", "email").Values("James", "james@mail.com").Replace("name", "Thomas").ToSql()
if err.Error() != "unique key must be provided for PostgreSQL and SQLite" {
t.Log(err.Error())
t.Error(err)
}
})
t.Run("should emit error if dialect not supported", func(t *testing.T) {
_, _, err := bob.Upsert("users", 100).Columns("name", "email").Values("James", "james@mail.com").Replace("name", "Thomas").ToSql()
if err.Error() != "provided database dialect is not supported" {
t.Log(err.Error())
t.Error(err)
}
})
}

View File

@ -2,7 +2,7 @@ package util
// createArgs should create an argument []interface{} for SQL query // createArgs should create an argument []interface{} for SQL query
// I'm using the idiot approach for creating args // I'm using the idiot approach for creating args
func CreateArgs(keys ...string) []interface{} { func CreateArgs(keys ...interface{}) []interface{} {
var args []interface{} var args []interface{}
for _, v := range keys { for _, v := range keys {
if v == "" { if v == "" {