From 3b9960c014ee203c82969d108d9be6c5f9ef7000 Mon Sep 17 00:00:00 2001 From: Wilko Kunert Date: Wed, 26 Apr 2023 15:25:47 +0200 Subject: [PATCH] Fix upsert targeting composite keys for SQLite If the target consisted of multiple columns, they were wrapped in two pairs for parentheses, which was invalid SQL. Also a target is required with "DO UPDATE" upserts now as per the spec (cp. https://www.sqlite.org/lang_UPSERT.html). --- .../src/sqlite-core/query-builders/insert.ts | 8 +- integration-tests/tests/better-sqlite.test.ts | 79 ++++++++++++++++- integration-tests/tests/libsql.test.ts | 79 ++++++++++++++++- integration-tests/tests/sql.js.test.ts | 79 ++++++++++++++++- integration-tests/tests/sqlite-proxy.test.ts | 84 ++++++++++++++++++- 5 files changed, 316 insertions(+), 13 deletions(-) diff --git a/drizzle-orm/src/sqlite-core/query-builders/insert.ts b/drizzle-orm/src/sqlite-core/query-builders/insert.ts index 7f4762316..c198abaf8 100644 --- a/drizzle-orm/src/sqlite-core/query-builders/insert.ts +++ b/drizzle-orm/src/sqlite-core/query-builders/insert.ts @@ -116,20 +116,22 @@ export class SQLiteInsert< if (config.target === undefined) { this.config.onConflict = sql`do nothing`; } else { + const targetSql = Array.isArray(config.target) ? sql`${config.target}` : sql`${[config.target]}`; const whereSql = config.where ? sql` where ${config.where}` : sql``; - this.config.onConflict = sql`(${config.target})${whereSql} do nothing`; + this.config.onConflict = sql`${targetSql}${whereSql} do nothing`; } return this; } onConflictDoUpdate(config: { - target?: IndexColumn | IndexColumn[]; + target: IndexColumn | IndexColumn[]; where?: SQL; set: SQLiteUpdateSetSource; }): this { + const targetSql = Array.isArray(config.target) ? sql`${config.target}` : sql`${[config.target]}`; const whereSql = config.where ? sql` where ${config.where}` : sql``; const setSql = this.dialect.buildUpdateSet(this.config.table, mapUpdateSet(this.config.table, config.set)); - this.config.onConflict = sql`(${config.target})${whereSql} do update set ${setSql}`; + this.config.onConflict = sql`${targetSql}${whereSql} do update set ${setSql}`; return this; } diff --git a/integration-tests/tests/better-sqlite.test.ts b/integration-tests/tests/better-sqlite.test.ts index e50f83547..33afe0706 100644 --- a/integration-tests/tests/better-sqlite.test.ts +++ b/integration-tests/tests/better-sqlite.test.ts @@ -71,8 +71,8 @@ const anotherUsersMigratorTable = sqliteTable('another_users', { email: text('email').notNull(), }); -const _pkExample = sqliteTable('pk_example', { - id: integer('id').primaryKey(), +const pkExampleTable = sqliteTable('pk_example', { + id: integer('id').notNull(), name: text('name').notNull(), email: text('email').notNull(), }, (table) => ({ @@ -113,6 +113,7 @@ test.beforeEach((t) => { ctx.db.run(sql`drop table if exists ${coursesTable}`); ctx.db.run(sql`drop table if exists ${courseCategoriesTable}`); ctx.db.run(sql`drop table if exists ${orders}`); + ctx.db.run(sql`drop table if exists ${pkExampleTable}`); ctx.db.run(sql` create table ${usersTable} ( @@ -158,6 +159,14 @@ test.beforeEach((t) => { quantity integer not null ) `); + ctx.db.run(sql` + create table ${pkExampleTable} ( + id integer not null, + name text not null, + email text not null, + primary key (id, name) + ) + `); }); test.serial('select all fields', (t) => { @@ -1531,6 +1540,29 @@ test.serial('insert with onConflict do nothing', (t) => { t.deepEqual(res, [{ id: 1, name: 'John' }]); }); +test.serial('insert with onConflict do nothing using composite pk', (t) => { + const { db } = t.context; + + db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john@example.com' }) + .run(); + + db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john1@example.com' }) + .onConflictDoNothing() + .run(); + + const res = db + .select({ id: pkExampleTable.id, name: pkExampleTable.name, email: pkExampleTable.email }) + .from(pkExampleTable) + .where(eq(pkExampleTable.id, 1)) + .all(); + + t.deepEqual(res, [{ id: 1, name: 'John', email: 'john@example.com' }]); +}); + test.serial('insert with onConflict do nothing using target', (t) => { const { db } = t.context; @@ -1551,6 +1583,29 @@ test.serial('insert with onConflict do nothing using target', (t) => { t.deepEqual(res, [{ id: 1, name: 'John' }]); }); +test.serial('insert with onConflict do nothing using composite pk as target', (t) => { + const { db } = t.context; + + db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john@example.com' }) + .run(); + + db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john1@example.com' }) + .onConflictDoNothing({ target: [pkExampleTable.id, pkExampleTable.name] }) + .run(); + + const res = db + .select({ id: pkExampleTable.id, name: pkExampleTable.name, email: pkExampleTable.email }) + .from(pkExampleTable) + .where(eq(pkExampleTable.id, 1)) + .all(); + + t.deepEqual(res, [{ id: 1, name: 'John', email: 'john@example.com' }]); +}); + test.serial('insert with onConflict do update', (t) => { const { db } = t.context; @@ -1571,6 +1626,26 @@ test.serial('insert with onConflict do update', (t) => { t.deepEqual(res, [{ id: 1, name: 'John1' }]); }); +test.serial('insert with onConflict do update using composite pk', (t) => { + const { db } = t.context; + + db.insert(pkExampleTable).values({ id: 1, name: 'John', email: 'john@example.com' }).run(); + + db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john@example.com' }) + .onConflictDoUpdate({ target: [pkExampleTable.id, pkExampleTable.name], set: { email: 'john1@example.com' } }) + .run(); + + const res = db + .select({ id: pkExampleTable.id, name: pkExampleTable.name, email: pkExampleTable.email }) + .from(pkExampleTable) + .where(eq(pkExampleTable.id, 1)) + .all(); + + t.deepEqual(res, [{ id: 1, name: 'John', email: 'john1@example.com' }]); +}); + test.serial('insert undefined', (t) => { const { db } = t.context; diff --git a/integration-tests/tests/libsql.test.ts b/integration-tests/tests/libsql.test.ts index afd9e6308..b10ce2138 100644 --- a/integration-tests/tests/libsql.test.ts +++ b/integration-tests/tests/libsql.test.ts @@ -89,8 +89,8 @@ const anotherUsersMigratorTable = sqliteTable('another_users', { email: text('email').notNull(), }); -const _pkExample = sqliteTable('pk_example', { - id: integer('id').primaryKey(), +const pkExampleTable = sqliteTable('pk_example', { + id: integer('id').notNull(), name: text('name').notNull(), email: text('email').notNull(), }, (table) => ({ @@ -139,6 +139,7 @@ test.beforeEach(async (t) => { await ctx.db.run(sql`drop table if exists ${coursesTable}`); await ctx.db.run(sql`drop table if exists ${courseCategoriesTable}`); await ctx.db.run(sql`drop table if exists ${orders}`); + await ctx.db.run(sql`drop table if exists ${pkExampleTable}`); await ctx.db.run(sql` create table ${usersTable} ( @@ -186,6 +187,14 @@ test.beforeEach(async (t) => { quantity integer not null ) `); + await ctx.db.run(sql` + create table ${pkExampleTable} ( + id integer not null, + name text not null, + email text not null, + primary key (id, name) + ) + `); }); test.serial('select all fields', async (t) => { @@ -1497,6 +1506,29 @@ test.serial('insert with onConflict do nothing', async (t) => { t.deepEqual(res, [{ id: 1, name: 'John' }]); }); +test.serial('insert with onConflict do nothing using composite pk', async (t) => { + const { db } = t.context; + + await db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john@example.com' }) + .run(); + + await db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john1@example.com' }) + .onConflictDoNothing() + .run(); + + const res = await db + .select({ id: pkExampleTable.id, name: pkExampleTable.name, email: pkExampleTable.email }) + .from(pkExampleTable) + .where(eq(pkExampleTable.id, 1)) + .all(); + + t.deepEqual(res, [{ id: 1, name: 'John', email: 'john@example.com' }]); +}); + test.serial('insert with onConflict do nothing using target', async (t) => { const { db } = t.context; @@ -1517,6 +1549,29 @@ test.serial('insert with onConflict do nothing using target', async (t) => { t.deepEqual(res, [{ id: 1, name: 'John' }]); }); +test.serial('insert with onConflict do nothing using composite pk as target', async (t) => { + const { db } = t.context; + + await db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john@example.com' }) + .run(); + + await db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john1@example.com' }) + .onConflictDoNothing({ target: [pkExampleTable.id, pkExampleTable.name] }) + .run(); + + const res = await db + .select({ id: pkExampleTable.id, name: pkExampleTable.name, email: pkExampleTable.email }) + .from(pkExampleTable) + .where(eq(pkExampleTable.id, 1)) + .all(); + + t.deepEqual(res, [{ id: 1, name: 'John', email: 'john@example.com' }]); +}); + test.serial('insert with onConflict do update', async (t) => { const { db } = t.context; @@ -1537,6 +1592,26 @@ test.serial('insert with onConflict do update', async (t) => { t.deepEqual(res, [{ id: 1, name: 'John1' }]); }); +test.serial('insert with onConflict do update using composite pk', async (t) => { + const { db } = t.context; + + await db.insert(pkExampleTable).values({ id: 1, name: 'John', email: 'john@example.com' }).run(); + + await db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john@example.com' }) + .onConflictDoUpdate({ target: [pkExampleTable.id, pkExampleTable.name], set: { email: 'john1@example.com' } }) + .run(); + + const res = await db + .select({ id: pkExampleTable.id, name: pkExampleTable.name, email: pkExampleTable.email }) + .from(pkExampleTable) + .where(eq(pkExampleTable.id, 1)) + .all(); + + t.deepEqual(res, [{ id: 1, name: 'John', email: 'john1@example.com' }]); +}); + test.serial('insert undefined', async (t) => { const { db } = t.context; diff --git a/integration-tests/tests/sql.js.test.ts b/integration-tests/tests/sql.js.test.ts index 9d8f4c220..ccc539e12 100644 --- a/integration-tests/tests/sql.js.test.ts +++ b/integration-tests/tests/sql.js.test.ts @@ -73,8 +73,8 @@ const anotherUsersMigratorTable = sqliteTable('another_users', { email: text('email').notNull(), }); -const _pkExample = sqliteTable('pk_example', { - id: integer('id').primaryKey(), +const pkExampleTable = sqliteTable('pk_example', { + id: integer('id').notNull(), name: text('name').notNull(), email: text('email').notNull(), }, (table) => ({ @@ -110,6 +110,7 @@ test.beforeEach((t) => { ctx.db.run(sql`drop table if exists ${coursesTable}`); ctx.db.run(sql`drop table if exists ${courseCategoriesTable}`); ctx.db.run(sql`drop table if exists ${orders}`); + ctx.db.run(sql`drop table if exists ${pkExampleTable}`); ctx.db.run(sql` create table ${usersTable} ( @@ -155,6 +156,14 @@ test.beforeEach((t) => { quantity integer not null ) `); + ctx.db.run(sql` + create table ${pkExampleTable} ( + id integer not null, + name text not null, + email text not null, + primary key (id, name) + ) + `); }); test.serial('select all fields', (t) => { @@ -1466,6 +1475,29 @@ test.serial('insert with onConflict do nothing', (t) => { t.deepEqual(res, [{ id: 1, name: 'John' }]); }); +test.serial('insert with onConflict do nothing using composite pk', (t) => { + const { db } = t.context; + + db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john@example.com' }) + .run(); + + db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john1@example.com' }) + .onConflictDoNothing() + .run(); + + const res = db + .select({ id: pkExampleTable.id, name: pkExampleTable.name, email: pkExampleTable.email }) + .from(pkExampleTable) + .where(eq(pkExampleTable.id, 1)) + .all(); + + t.deepEqual(res, [{ id: 1, name: 'John', email: 'john@example.com' }]); +}); + test.serial('insert with onConflict do nothing using target', (t) => { const { db } = t.context; @@ -1486,6 +1518,29 @@ test.serial('insert with onConflict do nothing using target', (t) => { t.deepEqual(res, [{ id: 1, name: 'John' }]); }); +test.serial('insert with onConflict do nothing using composite pk as target', (t) => { + const { db } = t.context; + + db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john@example.com' }) + .run(); + + db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john1@example.com' }) + .onConflictDoNothing({ target: [pkExampleTable.id, pkExampleTable.name] }) + .run(); + + const res = db + .select({ id: pkExampleTable.id, name: pkExampleTable.name, email: pkExampleTable.email }) + .from(pkExampleTable) + .where(eq(pkExampleTable.id, 1)) + .all(); + + t.deepEqual(res, [{ id: 1, name: 'John', email: 'john@example.com' }]); +}); + test.serial('insert with onConflict do update', (t) => { const { db } = t.context; @@ -1506,6 +1561,26 @@ test.serial('insert with onConflict do update', (t) => { t.deepEqual(res, [{ id: 1, name: 'John1' }]); }); +test.serial('insert with onConflict do update using composite pk', (t) => { + const { db } = t.context; + + db.insert(pkExampleTable).values({ id: 1, name: 'John', email: 'john@example.com' }).run(); + + db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john@example.com' }) + .onConflictDoUpdate({ target: [pkExampleTable.id, pkExampleTable.name], set: { email: 'john1@example.com' } }) + .run(); + + const res = db + .select({ id: pkExampleTable.id, name: pkExampleTable.name, email: pkExampleTable.email }) + .from(pkExampleTable) + .where(eq(pkExampleTable.id, 1)) + .all(); + + t.deepEqual(res, [{ id: 1, name: 'John', email: 'john1@example.com' }]); +}); + test.serial('insert undefined', (t) => { const { db } = t.context; diff --git a/integration-tests/tests/sqlite-proxy.test.ts b/integration-tests/tests/sqlite-proxy.test.ts index 4f3d708dc..b398e4d86 100644 --- a/integration-tests/tests/sqlite-proxy.test.ts +++ b/integration-tests/tests/sqlite-proxy.test.ts @@ -76,8 +76,8 @@ const anotherUsersMigratorTable = sqliteTable('another_users', { email: text('email').notNull(), }); -const _pkExample = sqliteTable('pk_example', { - id: integer('id').primaryKey(), +const pkExampleTable = sqliteTable('pk_example', { + id: integer('id').notNull(), name: text('name').notNull(), email: text('email').notNull(), }, (table) => ({ @@ -118,8 +118,10 @@ test.before((t) => { test.beforeEach(async (t) => { const ctx = t.context; - ctx.db.run(sql`drop table if exists ${usersTable}`); - ctx.db.run(sql` + await ctx.db.run(sql`drop table if exists ${usersTable}`); + await ctx.db.run(sql`drop table if exists ${pkExampleTable}`); + + await ctx.db.run(sql` create table ${usersTable} ( id integer primary key, name text not null, @@ -128,6 +130,14 @@ test.beforeEach(async (t) => { created_at integer not null default (strftime('%s', 'now')) ) `); + await ctx.db.run(sql` + create table ${pkExampleTable} ( + id integer not null, + name text not null, + email text not null, + primary key (id, name) + ) + `); }); test.serial('select all fields', async (t) => { @@ -764,6 +774,29 @@ test.serial('insert with onConflict do nothing', async (t) => { t.deepEqual(res, [{ id: 1, name: 'John' }]); }); +test.serial('insert with onConflict do nothing using composite pk', async (t) => { + const { db } = t.context; + + await db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john@example.com' }) + .run(); + + await db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john1@example.com' }) + .onConflictDoNothing() + .run(); + + const res = await db + .select({ id: pkExampleTable.id, name: pkExampleTable.name, email: pkExampleTable.email }) + .from(pkExampleTable) + .where(eq(pkExampleTable.id, 1)) + .all(); + + t.deepEqual(res, [{ id: 1, name: 'John', email: 'john@example.com' }]); +}); + test.serial('insert with onConflict do nothing using target', async (t) => { const { db } = t.context; @@ -784,6 +817,29 @@ test.serial('insert with onConflict do nothing using target', async (t) => { t.deepEqual(res, [{ id: 1, name: 'John' }]); }); +test.serial('insert with onConflict do nothing using composite pk as target', async (t) => { + const { db } = t.context; + + await db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john@example.com' }) + .run(); + + await db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john1@example.com' }) + .onConflictDoNothing({ target: [pkExampleTable.id, pkExampleTable.name] }) + .run(); + + const res = await db + .select({ id: pkExampleTable.id, name: pkExampleTable.name, email: pkExampleTable.email }) + .from(pkExampleTable) + .where(eq(pkExampleTable.id, 1)) + .all(); + + t.deepEqual(res, [{ id: 1, name: 'John', email: 'john@example.com' }]); +}); + test.serial('insert with onConflict do update', async (t) => { const { db } = t.context; @@ -804,6 +860,26 @@ test.serial('insert with onConflict do update', async (t) => { t.deepEqual(res, [{ id: 1, name: 'John1' }]); }); +test.serial('insert with onConflict do update using composite pk', async (t) => { + const { db } = t.context; + + await db.insert(pkExampleTable).values({ id: 1, name: 'John', email: 'john@example.com' }).run(); + + await db + .insert(pkExampleTable) + .values({ id: 1, name: 'John', email: 'john@example.com' }) + .onConflictDoUpdate({ target: [pkExampleTable.id, pkExampleTable.name], set: { email: 'john1@example.com' } }) + .run(); + + const res = await db + .select({ id: pkExampleTable.id, name: pkExampleTable.name, email: pkExampleTable.email }) + .from(pkExampleTable) + .where(eq(pkExampleTable.id, 1)) + .all(); + + t.deepEqual(res, [{ id: 1, name: 'John', email: 'john1@example.com' }]); +}); + test.serial('insert undefined', async (t) => { const { db } = t.context;