Skip to content

Commit

Permalink
feat: add option to upsert to skip update if the row already exists a…
Browse files Browse the repository at this point in the history
…nd no values would be changed (#8679)

* feat: add an option to upsert to allow skipping the update if no values have changed

* fix: relocate InsertOrUpdateOptions file with query-builder

* fix: only allow where is distinct from excluded on postgres

* fix: only expect postgres to skip the upsert update where nothing changed
  • Loading branch information
joeflateau authored Feb 22, 2022
1 parent 7facbab commit 8744395
Show file tree
Hide file tree
Showing 7 changed files with 86 additions and 7 deletions.
27 changes: 24 additions & 3 deletions docs/repository-api.md
Original file line number Diff line number Diff line change
@@ -1,8 +1,10 @@
# Repository APIs

* [Repository API](#repository-api)
* [TreeRepository API](#treerepository-api)
* [MongoRepository API](#mongorepository-api)
- [Repository APIs](#repository-apis)
- [`Repository` API](#repository-api)
- [Additional Options](#additional-options)
- [`TreeRepository` API](#treerepository-api)
- [`MongoRepository` API](#mongorepository-api)

## `Repository` API

Expand Down Expand Up @@ -170,6 +172,25 @@ await repository.upsert([
**/
```

```typescript
await repository.upsert([
{ externalId:"abc123", firstName: "Rizzrak" },
{ externalId:"bca321", firstName: "Karzzir" },
], {
conflictPaths: ["externalId"],
skipUpdateIfNoValuesChanged: true // supported by postgres, skips update if it would not change row values
});
/** executes
* INSERT INTO user
* VALUES
* (externalId = abc123, firstName = Rizzrak),
* (externalId = cba321, firstName = Karzzir),
* ON CONFLICT (externalId) DO UPDATE
* SET firstName = EXCLUDED.firstName
* WHERE user.firstName IS DISTINCT FROM EXCLUDED.firstName
**/
```

* `delete` - Deletes entities by entity id, ids or given conditions:

```typescript
Expand Down
5 changes: 4 additions & 1 deletion src/entity-manager/EntityManager.ts
Original file line number Diff line number Diff line change
Expand Up @@ -514,7 +514,10 @@ export class EntityManager {
.values(entities)
.orUpdate(
[...conflictColumns, ...overwriteColumns].map((col) => col.databaseName),
conflictColumns.map((col) => col.databaseName)
conflictColumns.map((col) => col.databaseName),
{
skipUpdateIfNoValuesChanged: options.skipUpdateIfNoValuesChanged
}
)
.execute();
}
Expand Down
3 changes: 3 additions & 0 deletions src/query-builder/InsertOrUpdateOptions.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
export type InsertOrUpdateOptions = {
skipUpdateIfNoValuesChanged?: boolean;
};
16 changes: 13 additions & 3 deletions src/query-builder/InsertQueryBuilder.ts
Original file line number Diff line number Diff line change
Expand Up @@ -19,6 +19,7 @@ import {OracleDriver} from "../driver/oracle/OracleDriver";
import {AuroraDataApiDriver} from "../driver/aurora-data-api/AuroraDataApiDriver";
import {TypeORMError} from "../error";
import {v4 as uuidv4} from "uuid";
import { InsertOrUpdateOptions } from "./InsertOrUpdateOptions";

/**
* Allows to build complex sql queries in a fashion way and execute those queries.
Expand Down Expand Up @@ -285,24 +286,27 @@ export class InsertQueryBuilder<Entity> extends QueryBuilder<Entity> {
*/
orUpdate(statement?: { columns?: string[], overwrite?: string[], conflict_target?: string | string[] }): this;

orUpdate(overwrite: string[], conflictTarget?: string | string[]): this;
orUpdate(overwrite: string[], conflictTarget?: string | string[], orUpdateOptions?: InsertOrUpdateOptions): this;

/**
* Adds additional update statement supported in databases.
*/
orUpdate(statementOrOverwrite?: { columns?: string[], overwrite?: string[], conflict_target?: string | string[] } | string[], conflictTarget?: string | string[]): this {
orUpdate(statementOrOverwrite?: { columns?: string[], overwrite?: string[], conflict_target?: string | string[] } | string[], conflictTarget?: string | string[], orUpdateOptions?: InsertOrUpdateOptions): this {

if (!Array.isArray(statementOrOverwrite)) {
this.expressionMap.onUpdate = {
conflict: statementOrOverwrite?.conflict_target,
columns: statementOrOverwrite?.columns,
overwrite: statementOrOverwrite?.overwrite,
skipUpdateIfNoValuesChanged: orUpdateOptions?.skipUpdateIfNoValuesChanged
};
return this;
}

this.expressionMap.onUpdate = {
overwrite: statementOrOverwrite,
conflict: conflictTarget,
skipUpdateIfNoValuesChanged: orUpdateOptions?.skipUpdateIfNoValuesChanged
};
return this;
}
Expand Down Expand Up @@ -363,7 +367,7 @@ export class InsertQueryBuilder<Entity> extends QueryBuilder<Entity> {
} else if (this.expressionMap.onConflict) {
query += ` ON CONFLICT ${this.expressionMap.onConflict} `;
} else if (this.expressionMap.onUpdate) {
const { overwrite, columns, conflict } = this.expressionMap.onUpdate;
const { overwrite, columns, conflict, skipUpdateIfNoValuesChanged } = this.expressionMap.onUpdate;

let conflictTarget = "ON CONFLICT";

Expand All @@ -382,6 +386,12 @@ export class InsertQueryBuilder<Entity> extends QueryBuilder<Entity> {
query += columns.map(column => `${this.escape(column)} = :${column}`).join(", ");
query += " ";
}

if (Array.isArray(overwrite) && skipUpdateIfNoValuesChanged && this.connection.driver instanceof PostgresDriver) {
query += ` WHERE (`;
query += overwrite.map(column => `${tableName}.${this.escape(column)} IS DISTINCT FROM EXCLUDED.${this.escape(column)}`).join(" OR ");
query += ") ";
}
}
} else if (this.connection.driver.supportedUpsertType === "on-duplicate-key-update") {
if (this.expressionMap.onUpdate) {
Expand Down
1 change: 1 addition & 0 deletions src/query-builder/QueryExpressionMap.ts
Original file line number Diff line number Diff line change
Expand Up @@ -100,6 +100,7 @@ export class QueryExpressionMap {
conflict?: string | string[],
columns?: string[],
overwrite?: string[],
skipUpdateIfNoValuesChanged?: boolean
};

/**
Expand Down
4 changes: 4 additions & 0 deletions src/repository/UpsertOptions.ts
Original file line number Diff line number Diff line change
Expand Up @@ -4,4 +4,8 @@
// eslint-disable-next-line @typescript-eslint/no-unused-vars
export interface UpsertOptions<Entity> {
conflictPaths: string[]
/**
* If true, postgres will skip the update if no values would be changed (reduces writes)
*/
skipUpdateIfNoValuesChanged?: boolean;
}
Original file line number Diff line number Diff line change
Expand Up @@ -15,6 +15,8 @@ import { EmbeddedUniqueConstraintEntity } from "./entity/EmbeddedUniqueConstrain
import { RelationAsPrimaryKey } from "./entity/RelationAsPrimaryKey";
import { TwoUniqueColumnsEntity } from "./entity/TwoUniqueColumns";
import { OneToOneRelationEntity } from "./entity/OneToOneRelation";
import { UpsertOptions } from "../../../../src/repository/UpsertOptions";
import { PostgresDriver } from "../../../../src/driver/postgres/PostgresDriver";

describe("repository > basic methods", () => {

Expand Down Expand Up @@ -481,6 +483,41 @@ describe("repository > basic methods", () => {
(await postObjects.findOneOrFail(({ externalId }))).subTitle.should.equal("subtitle");
(await postObjects.findOneOrFail(({ externalId }))).title.should.equal("title updated");
})));
it("should skip update when nothing has changed", () => Promise.all(connections.map(async (connection) => {
if (!(connection.driver instanceof PostgresDriver)) return;

const postObjects = connection.getRepository(Post);
const externalId1 = "external-skip-update-nothing-changed1";
const externalId2 = "external-skip-update-nothing-changed2";

const upsertOptions: UpsertOptions<Post> = {
conflictPaths: ["externalId"],
skipUpdateIfNoValuesChanged: true
};

const insertResult = await postObjects.upsert([
{ externalId:externalId1, title: "title1" },
{ externalId:externalId2, title: "title2" }
], upsertOptions);
insertResult.raw.should.have.length(2); // insert
(await postObjects.findOneOrFail(({ externalId: externalId1}))).title.should.equal("title1");
(await postObjects.findOneOrFail(({ externalId: externalId2}))).title.should.equal("title2");

const updatedResult = await postObjects.upsert([
{ externalId: externalId1, title: "title updated1" },
{ externalId: externalId2, title: "title updated2" },
], upsertOptions);
updatedResult.raw.should.have.length(2); // update
(await postObjects.findOneOrFail(({ externalId: externalId1 }))).title.should.equal("title updated1");
(await postObjects.findOneOrFail(({ externalId: externalId2 }))).title.should.equal("title updated2");

const skippedUpdateResult = await postObjects.upsert([
{ externalId: externalId1, title: "title updated1" },
{ externalId: externalId2, title: "title updated2" },
], upsertOptions);
skippedUpdateResult.raw.should.have.length(0); // update skipped

})));
it("should upsert with embedded columns", () => Promise.all(connections.map(async (connection) => {
if (connection.driver.supportedUpsertType == null) return;

Expand Down

0 comments on commit 8744395

Please sign in to comment.