Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

SQLStore: Support Upserting multiple rows. #52228

Merged
merged 4 commits into from Jul 19, 2022
Merged
Show file tree
Hide file tree
Changes from 2 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
1 change: 1 addition & 0 deletions pkg/services/sqlstore/migrator/dialect.go
Expand Up @@ -49,6 +49,7 @@ type Dialect interface {
ColumnCheckSQL(tableName, columnName string) (string, []interface{})
// UpsertSQL returns the upsert sql statement for a dialect
UpsertSQL(tableName string, keyCols, updateCols []string) string
UpsertMultipleSQL(tableName string, keyCols, updateCols []string, count int) (string, error)

ColString(*Column) string
ColStringNoPk(*Column) string
Expand Down
24 changes: 21 additions & 3 deletions pkg/services/sqlstore/migrator/mysql_dialect.go
Expand Up @@ -212,6 +212,14 @@ func (db *MySQLDialect) IsDeadlock(err error) bool {

// UpsertSQL returns the upsert sql statement for PostgreSQL dialect
joeblubaugh marked this conversation as resolved.
Show resolved Hide resolved
func (db *MySQLDialect) UpsertSQL(tableName string, keyCols, updateCols []string) string {
q, _ := db.UpsertMultipleSQL(tableName, keyCols, updateCols, 1)
return q
}

func (db *MySQLDialect) UpsertMultipleSQL(tableName string, keyCols, updateCols []string, count int) (string, error) {
if count < 1 {
return "", fmt.Errorf("upsert statement must have count >= 1. Got %v", count)
}
columnsStr := strings.Builder{}
colPlaceHoldersStr := strings.Builder{}
setStr := strings.Builder{}
Expand All @@ -226,13 +234,23 @@ func (db *MySQLDialect) UpsertSQL(tableName string, keyCols, updateCols []string
setStr.WriteString(fmt.Sprintf("%s=VALUES(%s)%s", db.Quote(c), db.Quote(c), separator))
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Note that starting from MySQL 8.0.20 the use of VALUES() to refer to the new row and columns is deprecated and is subject from removal in the future.
So ideally, we have to use row and column aliases (introduced in MySQL 8.0.19) for supporting the latest MySQL versions and fallback to VALUES() when using older versions.

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The new syntax is this close to the Postgres syntax, but not quite. That's too bad.

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I've filed #52437

}

s := fmt.Sprintf(`INSERT INTO %s (%s) VALUES (%s) ON DUPLICATE KEY UPDATE %s`,
valuesStr := strings.Builder{}
separator = ", "
colPlaceHolders := colPlaceHoldersStr.String()
for i := 0; i < count; i++ {
if i == count-1 {
separator = ""
}
valuesStr.WriteString(fmt.Sprintf("(%s)%s", colPlaceHolders, separator))
}

s := fmt.Sprintf(`INSERT INTO %s (%s) VALUES %s ON DUPLICATE KEY UPDATE %s`,
tableName,
columnsStr.String(),
colPlaceHoldersStr.String(),
valuesStr.String(),
setStr.String(),
)
return s
return s, nil
}

func (db *MySQLDialect) Lock(cfg LockCfg) error {
Expand Down
25 changes: 22 additions & 3 deletions pkg/services/sqlstore/migrator/postgres_dialect.go
Expand Up @@ -224,6 +224,15 @@ func (db *PostgresDialect) PostInsertId(table string, sess *xorm.Session) error

// UpsertSQL returns the upsert sql statement for PostgreSQL dialect
func (db *PostgresDialect) UpsertSQL(tableName string, keyCols, updateCols []string) string {
str, _ := db.UpsertMultipleSQL(tableName, keyCols, updateCols, 1)
return str
}

// UpsertMultipleSQL returns the upsert sql statement for PostgreSQL dialect
func (db *PostgresDialect) UpsertMultipleSQL(tableName string, keyCols, updateCols []string, count int) (string, error) {
if count < 1 {
return "", fmt.Errorf("upsert statement must have count >= 1. Got %v", count)
}
columnsStr := strings.Builder{}
onConflictStr := strings.Builder{}
colPlaceHoldersStr := strings.Builder{}
Expand All @@ -249,14 +258,24 @@ func (db *PostgresDialect) UpsertSQL(tableName string, keyCols, updateCols []str
onConflictStr.WriteString(fmt.Sprintf("%s%s", db.Quote(c), separatorVar))
}

s := fmt.Sprintf(`INSERT INTO %s (%s) VALUES (%s) ON CONFLICT(%s) DO UPDATE SET %s`,
valuesStr := strings.Builder{}
separatorVar = separator
colPlaceHolders := colPlaceHoldersStr.String()
for i := 0; i < count; i++ {
if i == count-1 {
separatorVar = ""
}
valuesStr.WriteString(fmt.Sprintf("(%s)%s", colPlaceHolders, separatorVar))
}

s := fmt.Sprintf(`INSERT INTO %s (%s) VALUES %s ON CONFLICT(%s) DO UPDATE SET %s`,
tableName,
columnsStr.String(),
colPlaceHoldersStr.String(),
valuesStr.String(),
onConflictStr.String(),
setStr.String(),
)
return s
return s, nil
}

func (db *PostgresDialect) Lock(cfg LockCfg) error {
Expand Down
25 changes: 22 additions & 3 deletions pkg/services/sqlstore/migrator/sqlite_dialect.go
Expand Up @@ -151,6 +151,15 @@ func (db *SQLite3) IsDeadlock(err error) bool {

// UpsertSQL returns the upsert sql statement for SQLite dialect
func (db *SQLite3) UpsertSQL(tableName string, keyCols, updateCols []string) string {
str, _ := db.UpsertMultipleSQL(tableName, keyCols, updateCols, 1)
return str
}

// UpsertMultipleSQL returns the upsert sql statement for PostgreSQL dialect
func (db *SQLite3) UpsertMultipleSQL(tableName string, keyCols, updateCols []string, count int) (string, error) {
if count < 1 {
return "", fmt.Errorf("upsert statement must have count >= 1. Got %v", count)
}
columnsStr := strings.Builder{}
onConflictStr := strings.Builder{}
colPlaceHoldersStr := strings.Builder{}
Expand All @@ -176,12 +185,22 @@ func (db *SQLite3) UpsertSQL(tableName string, keyCols, updateCols []string) str
onConflictStr.WriteString(fmt.Sprintf("%s%s", db.Quote(c), separatorVar))
}

s := fmt.Sprintf(`INSERT INTO %s (%s) VALUES (%s) ON CONFLICT(%s) DO UPDATE SET %s`,
valuesStr := strings.Builder{}
separatorVar = separator
colPlaceHolders := colPlaceHoldersStr.String()
for i := 0; i < count; i++ {
if i == count-1 {
separatorVar = ""
}
valuesStr.WriteString(fmt.Sprintf("(%s)%s", colPlaceHolders, separatorVar))
}

s := fmt.Sprintf(`INSERT INTO %s (%s) VALUES %s ON CONFLICT(%s) DO UPDATE SET %s`,
tableName,
columnsStr.String(),
colPlaceHoldersStr.String(),
valuesStr.String(),
onConflictStr.String(),
setStr.String(),
)
return s
return s, nil
}
74 changes: 74 additions & 0 deletions pkg/services/sqlstore/migrator/upsert_test.go
@@ -0,0 +1,74 @@
package migrator

import (
"testing"

"github.com/stretchr/testify/require"
)

func TestUpsertMultiple(t *testing.T) {
tests := []struct {
name string
keyCols []string
updateCols []string
count int
expectedErr bool
expectedPostgresQuery string
expectedMySQLQuery string
expectedSQLiteQuery string
}{
{
"upsert one",
[]string{"key1", "key2"},
[]string{"key1", "key2", "val1", "val2"},
1,
false,
"INSERT INTO test_table (\"key1\", \"key2\", \"val1\", \"val2\") VALUES (?, ?, ?, ?) ON CONFLICT(\"key1\", \"key2\") DO UPDATE SET \"key1\"=excluded.\"key1\", \"key2\"=excluded.\"key2\", \"val1\"=excluded.\"val1\", \"val2\"=excluded.\"val2\"",
"INSERT INTO test_table (`key1`, `key2`, `val1`, `val2`) VALUES (?, ?, ?, ?) ON DUPLICATE KEY UPDATE `key1`=VALUES(`key1`), `key2`=VALUES(`key2`), `val1`=VALUES(`val1`), `val2`=VALUES(`val2`)",
"INSERT INTO test_table (`key1`, `key2`, `val1`, `val2`) VALUES (?, ?, ?, ?) ON CONFLICT(`key1`, `key2`) DO UPDATE SET `key1`=excluded.`key1`, `key2`=excluded.`key2`, `val1`=excluded.`val1`, `val2`=excluded.`val2`",
},
{
"upsert two",
[]string{"key1", "key2"},
[]string{"key1", "key2", "val1", "val2"},
2,
false,
"INSERT INTO test_table (\"key1\", \"key2\", \"val1\", \"val2\") VALUES (?, ?, ?, ?), (?, ?, ?, ?) ON CONFLICT(\"key1\", \"key2\") DO UPDATE SET \"key1\"=excluded.\"key1\", \"key2\"=excluded.\"key2\", \"val1\"=excluded.\"val1\", \"val2\"=excluded.\"val2\"",
"INSERT INTO test_table (`key1`, `key2`, `val1`, `val2`) VALUES (?, ?, ?, ?), (?, ?, ?, ?) ON DUPLICATE KEY UPDATE `key1`=VALUES(`key1`), `key2`=VALUES(`key2`), `val1`=VALUES(`val1`), `val2`=VALUES(`val2`)",
"INSERT INTO test_table (`key1`, `key2`, `val1`, `val2`) VALUES (?, ?, ?, ?), (?, ?, ?, ?) ON CONFLICT(`key1`, `key2`) DO UPDATE SET `key1`=excluded.`key1`, `key2`=excluded.`key2`, `val1`=excluded.`val1`, `val2`=excluded.`val2`",
},
{
"count error",
[]string{"key1", "key2"},
[]string{"key1", "key2", "val1", "val2"},
0,
true,
"",
"",
"",
},
}

for _, tc := range tests {
t.Run(tc.name, func(t *testing.T) {
var db Dialect
db = &PostgresDialect{}
q, err := db.UpsertMultipleSQL("test_table", tc.keyCols, tc.updateCols, tc.count)

require.True(t, (err != nil) == tc.expectedErr)
require.Equal(t, tc.expectedPostgresQuery, q, "Postgres query incorrect")

db = &MySQLDialect{}
q, err = db.UpsertMultipleSQL("test_table", tc.keyCols, tc.updateCols, tc.count)

require.True(t, (err != nil) == tc.expectedErr)
require.Equal(t, tc.expectedMySQLQuery, q, "MySQL query incorrect")

db = &SQLite3{}
q, err = db.UpsertMultipleSQL("test_table", tc.keyCols, tc.updateCols, tc.count)

require.True(t, (err != nil) == tc.expectedErr)
require.Equal(t, tc.expectedSQLiteQuery, q, "SQLite query incorrect")
})
}
}