docs: documentation for upsert

This commit is contained in:
Reinaldy Rafli 2021-07-31 11:44:21 +07:00
parent 0f060565d6
commit 4a022225f2
4 changed files with 108 additions and 20 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)
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).
@ -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
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.RenameTable(currentTable, desiredName)` - Rename a table (`rename table "users" to "people"`)
* `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
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.Count(tableName, columnName)` - Count query (`select count("active") from "users"`)

58
bob.go
View File

@ -14,10 +14,10 @@ var ErrEmptyTablePgx = errors.New("no rows in result set")
var ErrDialectNotSupported = errors.New("provided database dialect is not supported")
const (
Mysql int = iota
Postgresql
Sqlite
MSSql
MySQL int = iota
PostgreSQL
SQLite
MSSQL
)
// BobBuilderType is the type for BobBuilder
@ -76,6 +76,23 @@ func (b BobBuilderType) Upsert(table string, dialect int) UpsertBuilder {
var BobStmtBuilder = BobBuilderType(builder.EmptyBuilder)
// 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 {
return BobStmtBuilder.CreateTable(table)
}
@ -117,6 +134,39 @@ func Truncate(table string) TruncateBuilder {
// 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

@ -100,7 +100,7 @@ func (d *upsertData) ToSql() (sqlStr string, args []interface{}, err error) {
sql := &bytes.Buffer{}
if d.Dialect == MSSql {
if d.Dialect == MSSQL {
if len(d.Key) == 0 {
err = errors.New("unique key and value must be provided for MS SQL")
return
@ -145,12 +145,12 @@ func (d *upsertData) ToSql() (sqlStr string, args []interface{}, err error) {
replaces = append(replaces, replace)
}
if d.Dialect == Mysql {
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 {
} 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 {
@ -163,7 +163,7 @@ func (d *upsertData) ToSql() (sqlStr string, args []interface{}, err error) {
sql.WriteString("DO UPDATE SET ")
sql.WriteString(strings.Join(replaces, ", "))
} else if d.Dialect == MSSql {
} 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)

View File

@ -10,7 +10,7 @@ import (
func TestUpsert(t *testing.T) {
t.Run("should be able to generate upsert query for mysql", func(t *testing.T) {
sql, args, err := bob.
Upsert("users", bob.Mysql).
Upsert("users", bob.MySQL).
Columns("name", "email").
Values("John Doe", "john@doe.com").
Replace("name", "John Does").
@ -32,7 +32,7 @@ func TestUpsert(t *testing.T) {
t.Run("should be able to generate upsert query for postgres", func(t *testing.T) {
sql, args, err := bob.
Upsert("users", bob.Postgresql).
Upsert("users", bob.PostgreSQL).
Columns("name", "email").
Values("John Doe", "john@doe.com").
Key("email").
@ -56,7 +56,7 @@ func TestUpsert(t *testing.T) {
t.Run("should be able to generate upsert query for sqlite", func(t *testing.T) {
sql, args, err := bob.
Upsert("users", bob.Sqlite).
Upsert("users", bob.SQLite).
Columns("name", "email").
Values("John Doe", "john@doe.com").
Key("email").
@ -80,7 +80,7 @@ func TestUpsert(t *testing.T) {
t.Run("should be able to generate upsert query for mssql", func(t *testing.T) {
sql, args, err := bob.
Upsert("users", bob.MSSql).
Upsert("users", bob.MSSQL).
Columns("name", "email").
Values("John Doe", "john@doe.com").
Key("email", "john@doe.com").
@ -103,42 +103,42 @@ func TestUpsert(t *testing.T) {
})
t.Run("should emit error without table name", func(t *testing.T) {
_, _, err := bob.Upsert("", bob.Mysql).ToSql()
_, _, 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()
_, _, 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()
_, _, 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()
_, _, 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()
_, _, 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()
_, _, 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)