Skip to content

Commit

Permalink
Fix upsert targeting composite keys for SQLite
Browse files Browse the repository at this point in the history
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).
  • Loading branch information
wkunert committed Apr 26, 2023
1 parent aadde62 commit 3b9960c
Show file tree
Hide file tree
Showing 5 changed files with 316 additions and 13 deletions.
8 changes: 5 additions & 3 deletions drizzle-orm/src/sqlite-core/query-builders/insert.ts
Original file line number Diff line number Diff line change
Expand Up @@ -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<TTable>;
}): 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;
}

Expand Down
79 changes: 77 additions & 2 deletions integration-tests/tests/better-sqlite.test.ts
Original file line number Diff line number Diff line change
Expand Up @@ -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) => ({
Expand Down Expand Up @@ -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} (
Expand Down Expand Up @@ -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) => {
Expand Down Expand Up @@ -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;

Expand All @@ -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;

Expand All @@ -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;

Expand Down
79 changes: 77 additions & 2 deletions integration-tests/tests/libsql.test.ts
Original file line number Diff line number Diff line change
Expand Up @@ -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) => ({
Expand Down Expand Up @@ -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} (
Expand Down Expand Up @@ -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) => {
Expand Down Expand Up @@ -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;

Expand All @@ -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;

Expand All @@ -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;

Expand Down
79 changes: 77 additions & 2 deletions integration-tests/tests/sql.js.test.ts
Original file line number Diff line number Diff line change
Expand Up @@ -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) => ({
Expand Down Expand Up @@ -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} (
Expand Down Expand Up @@ -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) => {
Expand Down Expand Up @@ -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;

Expand All @@ -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;

Expand All @@ -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;

Expand Down
Loading

0 comments on commit 3b9960c

Please sign in to comment.