diff --git a/.github/workflows/test.yml b/.github/workflows/test.yml index 3af94064..92ec7033 100644 --- a/.github/workflows/test.yml +++ b/.github/workflows/test.yml @@ -35,6 +35,7 @@ jobs: sudo apt-get -y install "postgresql-${{ matrix.postgres }}" sudo cp ./tests/pg_hba.conf /etc/postgresql/${{ matrix.postgres }}/main/pg_hba.conf sudo sed -i 's/.*wal_level.*/wal_level = logical/' /etc/postgresql/${{ matrix.postgres }}/main/postgresql.conf + sudo sed -i 's/.*max_prepared_transactions.*/max_prepared_transactions = 100/' /etc/postgresql/${{ matrix.postgres }}/main/postgresql.conf sudo sed -i 's/.*ssl = .*/ssl = on/' /etc/postgresql/${{ matrix.postgres }}/main/postgresql.conf openssl req -new -x509 -nodes -days 365 -text -subj "/CN=localhost" -extensions v3_req -config <(cat /etc/ssl/openssl.cnf <(printf "\n[v3_req]\nbasicConstraints=critical,CA:TRUE\nkeyUsage=nonRepudiation,digitalSignature,keyEncipherment\nsubjectAltName=DNS:localhost")) -keyout server.key -out server.crt sudo cp server.key /etc/postgresql/${{ matrix.postgres }}/main/server.key diff --git a/README.md b/README.md index 5e49a51f..b0e64a75 100644 --- a/README.md +++ b/README.md @@ -637,6 +637,26 @@ sql.begin('read write', async sql => { }) ``` + +#### PREPARE `await sql.prepare([name]) -> fn()` + +Indicates that the transactions should be prepared using the `PREPARED TRANASCTION [NAME]` statement +instead of being committed. + +```js +sql.begin('read write', async sql => { + const [user] = await sql` + insert into users ( + name + ) values ( + 'Murray' + ) + ` + + await sql.prepare('tx1') +}) +``` + Do note that you can often achieve the same result using [`WITH` queries (Common Table Expressions)](https://www.postgresql.org/docs/current/queries-with.html) instead of using transactions. ## Data Transformation diff --git a/cjs/src/index.js b/cjs/src/index.js index 3117627a..de4ae9f4 100644 --- a/cjs/src/index.js +++ b/cjs/src/index.js @@ -235,6 +235,7 @@ function Postgres(a, b) { const queries = Queue() let savepoints = 0 , connection + let transactionId = null try { await sql.unsafe('begin ' + options.replace(/[^a-z ]/ig, ''), [], { onexecute }).execute() @@ -246,6 +247,7 @@ function Postgres(a, b) { async function scope(c, fn, name) { const sql = Sql(handler) sql.savepoint = savepoint + sql.prepare = prepare let uncaughtError , result @@ -266,7 +268,11 @@ function Postgres(a, b) { throw e instanceof PostgresError && e.code === '25P02' && uncaughtError || e } - !name && await sql`commit` + if (transactionId) { + !name && await sql.unsafe(`prepare transaction '${transactionId}'`) + }else{ + !name && await sql`commit` + } return result function savepoint(name, fn) { @@ -285,6 +291,9 @@ function Postgres(a, b) { } } + async function prepare(name) { + transactionId = name + } function onexecute(c) { connection = c move(c, reserved) @@ -294,6 +303,7 @@ function Postgres(a, b) { } } + function move(c, queue) { c.queue.remove(c) queue.push(c) diff --git a/cjs/tests/index.js b/cjs/tests/index.js index 3d8b6162..2c703e2a 100644 --- a/cjs/tests/index.js +++ b/cjs/tests/index.js @@ -238,6 +238,19 @@ t('Savepoint returns Result', async() => { return [1, result[0].x] }) +t('Prepared transaction', async() => { + await sql`create table test (a int)` + + await sql.begin(async sql => { + await sql`insert into test values(1)` + await sql.prepare('tx1') + }) + + await sql.unsafe("commit prepared 'tx1'") + + return ['1', (await sql`select count(1) from test`)[0].count, await sql`drop table test`] +}) + t('Transaction requests are executed implicitly', async() => { const sql = postgres({ debug: true, idle_timeout: 1, fetch_types: false }) return [ diff --git a/deno/README.md b/deno/README.md index 054e53ab..f599a18f 100644 --- a/deno/README.md +++ b/deno/README.md @@ -633,6 +633,26 @@ sql.begin('read write', async sql => { }) ``` + +#### PREPARE `await sql.prepare([name]) -> fn()` + +Indicates that the transactions should be prepared using the `PREPARED TRANASCTION [NAME]` statement +instead of being committed. + +```js +sql.begin('read write', async sql => { + const [user] = await sql` + insert into users ( + name + ) values ( + 'Murray' + ) + ` + + await sql.prepare('tx1') +}) +``` + Do note that you can often achieve the same result using [`WITH` queries (Common Table Expressions)](https://www.postgresql.org/docs/current/queries-with.html) instead of using transactions. ## Data Transformation diff --git a/deno/src/index.js b/deno/src/index.js index 762bb589..fb1cda9b 100644 --- a/deno/src/index.js +++ b/deno/src/index.js @@ -236,6 +236,7 @@ function Postgres(a, b) { const queries = Queue() let savepoints = 0 , connection + let transactionId = null try { await sql.unsafe('begin ' + options.replace(/[^a-z ]/ig, ''), [], { onexecute }).execute() @@ -247,6 +248,7 @@ function Postgres(a, b) { async function scope(c, fn, name) { const sql = Sql(handler) sql.savepoint = savepoint + sql.prepare = prepare let uncaughtError , result @@ -267,7 +269,11 @@ function Postgres(a, b) { throw e instanceof PostgresError && e.code === '25P02' && uncaughtError || e } - !name && await sql`commit` + if (transactionId) { + !name && await sql.unsafe(`prepare transaction '${transactionId}'`) + }else{ + !name && await sql`commit` + } return result function savepoint(name, fn) { @@ -286,6 +292,9 @@ function Postgres(a, b) { } } + async function prepare(name) { + transactionId = name + } function onexecute(c) { connection = c move(c, reserved) @@ -295,6 +304,7 @@ function Postgres(a, b) { } } + function move(c, queue) { c.queue.remove(c) queue.push(c) diff --git a/deno/tests/index.js b/deno/tests/index.js index 4b4459bd..60f0f041 100644 --- a/deno/tests/index.js +++ b/deno/tests/index.js @@ -240,6 +240,19 @@ t('Savepoint returns Result', async() => { return [1, result[0].x] }) +t('Prepared transaction', async() => { + await sql`create table test (a int)` + + await sql.begin(async sql => { + await sql`insert into test values(1)` + await sql.prepare('tx1') + }) + + await sql.unsafe("commit prepared 'tx1'") + + return ['1', (await sql`select count(1) from test`)[0].count, await sql`drop table test`] +}) + t('Transaction requests are executed implicitly', async() => { const sql = postgres({ debug: true, idle_timeout: 1, fetch_types: false }) return [ diff --git a/deno/types/index.d.ts b/deno/types/index.d.ts index ca5a7446..64a00a4c 100644 --- a/deno/types/index.d.ts +++ b/deno/types/index.d.ts @@ -698,6 +698,8 @@ declare namespace postgres { interface TransactionSql = {}> extends Sql { savepoint(cb: (sql: TransactionSql) => T | Promise): Promise>; savepoint(name: string, cb: (sql: TransactionSql) => T | Promise): Promise>; + + prepare(name: string): Promise>; } } diff --git a/src/index.js b/src/index.js index 15c391e0..a254b617 100644 --- a/src/index.js +++ b/src/index.js @@ -235,6 +235,7 @@ function Postgres(a, b) { const queries = Queue() let savepoints = 0 , connection + let transactionId = null try { await sql.unsafe('begin ' + options.replace(/[^a-z ]/ig, ''), [], { onexecute }).execute() @@ -246,6 +247,7 @@ function Postgres(a, b) { async function scope(c, fn, name) { const sql = Sql(handler) sql.savepoint = savepoint + sql.prepare = prepare let uncaughtError , result @@ -266,7 +268,11 @@ function Postgres(a, b) { throw e instanceof PostgresError && e.code === '25P02' && uncaughtError || e } - !name && await sql`commit` + if (transactionId) { + !name && await sql.unsafe(`prepare transaction '${transactionId}'`) + }else{ + !name && await sql`commit` + } return result function savepoint(name, fn) { @@ -285,6 +291,9 @@ function Postgres(a, b) { } } + async function prepare(name) { + transactionId = name + } function onexecute(c) { connection = c move(c, reserved) @@ -294,6 +303,7 @@ function Postgres(a, b) { } } + function move(c, queue) { c.queue.remove(c) queue.push(c) diff --git a/tests/bootstrap.js b/tests/bootstrap.js index b30ca14b..0070c7b7 100644 --- a/tests/bootstrap.js +++ b/tests/bootstrap.js @@ -14,7 +14,6 @@ exec('createdb', ['postgres_js_test']) exec('psql', ['-c', 'grant all on database postgres_js_test to postgres_js_test']) exec('psql', ['-c', 'alter database postgres_js_test owner to postgres_js_test']) - export function exec(cmd, args) { const { stderr } = spawnSync(cmd, args, { stdio: 'pipe', encoding: 'utf8' }) if (stderr && !stderr.includes('already exists') && !stderr.includes('does not exist')) diff --git a/tests/index.js b/tests/index.js index 4bf03f58..dd0af57c 100644 --- a/tests/index.js +++ b/tests/index.js @@ -238,6 +238,19 @@ t('Savepoint returns Result', async() => { return [1, result[0].x] }) +t('Prepared transaction', async() => { + await sql`create table test (a int)` + + await sql.begin(async sql => { + await sql`insert into test values(1)` + await sql.prepare('tx1') + }) + + await sql.unsafe("commit prepared 'tx1'") + + return ['1', (await sql`select count(1) from test`)[0].count, await sql`drop table test`] +}) + t('Transaction requests are executed implicitly', async() => { const sql = postgres({ debug: true, idle_timeout: 1, fetch_types: false }) return [ diff --git a/types/index.d.ts b/types/index.d.ts index 1c85198c..ab797ee4 100644 --- a/types/index.d.ts +++ b/types/index.d.ts @@ -696,6 +696,8 @@ declare namespace postgres { interface TransactionSql = {}> extends Sql { savepoint(cb: (sql: TransactionSql) => T | Promise): Promise>; savepoint(name: string, cb: (sql: TransactionSql) => T | Promise): Promise>; + + prepare(name: string): Promise>; } }