attempts at serializable transactions

This commit is contained in:
keyan 2021-05-19 20:09:32 -05:00
parent 208980f302
commit 0eabe1463d
11 changed files with 182 additions and 105 deletions
api/resolvers
components
package.json
pages/withdrawls
prisma/migrations
20210511170231_vote
20210513002503_withdrawl_funcs
walletd

@ -1,4 +1,5 @@
import { UserInputError, AuthenticationError } from 'apollo-server-micro' import { UserInputError, AuthenticationError } from 'apollo-server-micro'
import serialize from './serial'
async function comments (models, id) { async function comments (models, id) {
const flat = await models.$queryRaw(` const flat = await models.$queryRaw(`
@ -106,15 +107,7 @@ export default {
throw new UserInputError('sats must be positive', { argumentName: 'sats' }) throw new UserInputError('sats must be positive', { argumentName: 'sats' })
} }
try { await serialize(models, models.$queryRaw`SELECT vote(${Number(id)}, ${me.name}, ${Number(sats)})`)
await models.$queryRaw`SELECT vote(${Number(id)}, ${me.name}, ${Number(sats)})`
} catch (error) {
const { meta: { message } } = error
if (message.includes('SN_INSUFFICIENT_FUNDS')) {
throw new UserInputError('insufficient funds')
}
throw error
}
return sats return sats
} }
}, },
@ -178,19 +171,11 @@ const createItem = async (parent, { title, url, text, parentId }, { me, models }
throw new AuthenticationError('you must be logged in') throw new AuthenticationError('you must be logged in')
} }
try { const [item] = await serialize(models, models.$queryRaw(
const [item] = await models.$queryRaw( `${SELECT} FROM create_item($1, $2, $3, $4, $5) AS "Item"`,
`${SELECT} FROM create_item($1, $2, $3, $4, $5) AS "Item"`, title, url, text, Number(parentId), me.name))
title, url, text, Number(parentId), me.name) item.comments = []
item.comments = [] return item
return item
} catch (error) {
const { meta: { message } } = error
if (message.includes('SN_INSUFFICIENT_FUNDS')) {
throw new UserInputError('insufficient funds')
}
throw error
}
} }
function nestComments (flat, parentId) { function nestComments (flat, parentId) {

24
api/resolvers/serial.js Normal file

@ -0,0 +1,24 @@
const { UserInputError } = require('apollo-server-micro')
async function serialize (models, call) {
try {
const [, result] = await models.$transaction([
models.$executeRaw(SERIALIZE),
call
])
return result
} catch (error) {
console.log(error)
if (error.message.includes('SN_INSUFFICIENT_FUNDS')) {
throw new UserInputError('insufficient funds')
}
if (error.message.includes('SN_NOT_SERIALIZABLE')) {
throw new Error('wallet transaction isolation level is not serializable')
}
throw error
}
}
const SERIALIZE = 'SET TRANSACTION ISOLATION LEVEL SERIALIZABLE'
module.exports = serialize

@ -1,24 +1,59 @@
import { createInvoice, decodePaymentRequest, subscribeToPayViaRequest } from 'ln-service' import { createInvoice, decodePaymentRequest, subscribeToPayViaRequest } from 'ln-service'
import { UserInputError, AuthenticationError } from 'apollo-server-micro' import { UserInputError, AuthenticationError } from 'apollo-server-micro'
import serialize from './serial'
export default { export default {
Query: { Query: {
invoice: async (parent, { id }, { me, models, lnd }) => { invoice: async (parent, { id }, { me, models, lnd }) => {
return await models.invoice.findUnique({ where: { id: Number(id) } }) if (!me) {
throw new AuthenticationError('you must be logged in')
}
const inv = await models.invoice.findUnique({
where: {
id: Number(id)
},
include: {
user: true
}
})
if (inv.user.name !== me.name) {
throw new AuthenticationError('not ur invoice')
}
return inv
}, },
withdrawl: async (parent, { id }, { me, models, lnd }) => { withdrawl: async (parent, { id }, { me, models, lnd }) => {
return await models.withdrawl.findUnique({ where: { id: Number(id) } }) if (!me) {
throw new AuthenticationError('you must be logged in')
}
const wdrwl = await models.withdrawl.findUnique({
where: {
id: Number(id)
},
include: {
user: true
}
})
if (wdrwl.user.name !== me.name) {
throw new AuthenticationError('not ur withdrawl')
}
return wdrwl
} }
}, },
Mutation: { Mutation: {
createInvoice: async (parent, { amount }, { me, models, lnd }) => { createInvoice: async (parent, { amount }, { me, models, lnd }) => {
if (!me) { if (!me) {
throw new AuthenticationError('You must be logged in') throw new AuthenticationError('you must be logged in')
} }
if (!amount || amount <= 0) { if (!amount || amount <= 0) {
throw new UserInputError('Amount must be positive', { argumentName: 'amount' }) throw new UserInputError('amount must be positive', { argumentName: 'amount' })
} }
// set expires at to 3 hours into future // set expires at to 3 hours into future
@ -47,65 +82,58 @@ export default {
}, },
createWithdrawl: async (parent, { invoice, maxFee }, { me, models, lnd }) => { createWithdrawl: async (parent, { invoice, maxFee }, { me, models, lnd }) => {
if (!me) { if (!me) {
throw new AuthenticationError('You must be logged in') throw new AuthenticationError('you must be logged in')
} }
// decode invoice to get amount // decode invoice to get amount
const decoded = await decodePaymentRequest({ lnd, request: invoice }) const decoded = await decodePaymentRequest({ lnd, request: invoice })
const msatsFee = Number(maxFee) * 1000 const msatsFee = Number(maxFee) * 1000
// create withdrawl transactionally (id, bolt11, amount, fee) // create withdrawl transactionally (id, bolt11, amount, fee)
try { const [withdrawl] = await serialize(models,
const [withdrawl] = models.$queryRaw`SELECT * FROM create_withdrawl(${decoded.id}, ${invoice},
await models.$queryRaw`SELECT * FROM create_withdrawl(${decoded.id}, ${invoice}, ${Number(decoded.mtokens)}, ${msatsFee}, ${me.name})`)
${Number(decoded.mtokens)}, ${msatsFee}, ${me.name})`
// create the payment, subscribing to its status // create the payment, subscribing to its status
const sub = subscribeToPayViaRequest({ const sub = subscribeToPayViaRequest({
lnd, lnd,
request: invoice, request: invoice,
// can't use max_fee_mtokens https://github.com/alexbosworth/ln-service/issues/141 // can't use max_fee_mtokens https://github.com/alexbosworth/ln-service/issues/141
max_fee: Number(maxFee), max_fee: Number(maxFee),
pathfinding_timeout: 30000 pathfinding_timeout: 30000
}) })
// if it's confirmed, update confirmed returning extra fees to user // if it's confirmed, update confirmed returning extra fees to user
sub.on('confirmed', async e => { sub.on('confirmed', async e => {
console.log(e) console.log(e)
// mtokens also contains the fee // mtokens also contains the fee
const fee = Number(e.fee_mtokens) const fee = Number(e.fee_mtokens)
const paid = Number(e.mtokens) - fee const paid = Number(e.mtokens) - fee
await models.$queryRaw` await serialize(models, models.$queryRaw`
SELECT confirm_withdrawl(${withdrawl.id}, ${paid}, ${fee})` SELECT confirm_withdrawl(${withdrawl.id}, ${paid}, ${fee})`)
}) })
// if the payment fails, we need to // if the payment fails, we need to
// 1. return the funds to the user // 1. return the funds to the user
// 2. update the widthdrawl as failed // 2. update the widthdrawl as failed
sub.on('failed', async e => { sub.on('failed', async e => {
console.log(e) console.log(e)
let status = 'UNKNOWN_FAILURE' let status = 'UNKNOWN_FAILURE'
if (e.is_insufficient_balance) { if (e.is_insufficient_balance) {
status = 'INSUFFICIENT_BALANCE' status = 'INSUFFICIENT_BALANCE'
} else if (e.is_invalid_payment) { } else if (e.is_invalid_payment) {
status = 'INVALID_PAYMENT' status = 'INVALID_PAYMENT'
} else if (e.is_pathfinding_timeout) { } else if (e.is_pathfinding_timeout) {
status = 'PATHFINDING_TIMEOUT' status = 'PATHFINDING_TIMEOUT'
} else if (e.is_route_not_found) { } else if (e.is_route_not_found) {
status = 'ROUTE_NOT_FOUND' status = 'ROUTE_NOT_FOUND'
}
await models.$queryRaw`
SELECT reverse_withdrawl(${withdrawl.id}, ${status})`
})
return withdrawl
} catch (error) {
const { meta: { message } } = error
if (message.includes('SN_INSUFFICIENT_FUNDS')) {
throw new UserInputError('insufficient funds')
} }
throw error await serialize(models, models.$queryRaw`
} SELECT reverse_withdrawl(${withdrawl.id}, ${status})`)
})
return withdrawl
} }
}, },

@ -90,7 +90,10 @@ export default function Comment ({ item, children, replyOpen, includeParent, cac
</div>} </div>}
{reply && {reply &&
<div className={styles.replyWrapper}> <div className={styles.replyWrapper}>
<Reply parentId={item.id} onSuccess={() => setReply(replyOpen || false)} cacheId={cacheId} /> <Reply
parentId={item.id} autoFocus={!replyOpen}
onSuccess={() => setReply(replyOpen || false)} cacheId={cacheId}
/>
</div>} </div>}
{children} {children}
<div className={`${styles.comments} ml-sm-1 ml-md-3`}> <div className={`${styles.comments} ml-sm-1 ml-md-3`}>

@ -93,7 +93,7 @@ export function Form ({
validationSchema={schema} validationSchema={schema}
validateOnBlur={false} validateOnBlur={false}
onSubmit={async (...args) => onSubmit={async (...args) =>
onSubmit && onSubmit(...args).catch(e => setError(e.message))} onSubmit && onSubmit(...args).catch(e => setError(e.message || e))}
> >
<FormikForm {...props} noValidate> <FormikForm {...props} noValidate>
{error && <Alert variant='danger' onClose={() => setError(undefined)} dismissible>{error}</Alert>} {error && <Alert variant='danger' onClose={() => setError(undefined)} dismissible>{error}</Alert>}

@ -8,7 +8,7 @@ export const CommentSchema = Yup.object({
text: Yup.string().required('required').trim() text: Yup.string().required('required').trim()
}) })
export default function Reply ({ parentId, onSuccess }) { export default function Reply ({ parentId, onSuccess, autoFocus }) {
const [createComment] = useMutation( const [createComment] = useMutation(
gql` gql`
${COMMENTS} ${COMMENTS}
@ -63,6 +63,7 @@ export default function Reply ({ parentId, onSuccess }) {
name='text' name='text'
as='textarea' as='textarea'
rows={4} rows={4}
autoFocus={autoFocus}
required required
/> />
<SubmitButton variant='secondary' className='mt-1'>reply</SubmitButton> <SubmitButton variant='secondary' className='mt-1'>reply</SubmitButton>

@ -46,4 +46,4 @@
"prisma": "^2.22.1", "prisma": "^2.22.1",
"standard": "^16.0.3" "standard": "^16.0.3"
} }
} }

@ -68,11 +68,11 @@ function LoadWithdrawl ({ query }) {
variant = 'failed' variant = 'failed'
break break
case 'PATHFINDING_TIMEOUT': case 'PATHFINDING_TIMEOUT':
status = <>timed out trying to find route <small className='ml-3'>try increasing max fee</small></> status = <>timed out finding route <small className='ml-3'>try increasing max fee</small></>
variant = 'failed' variant = 'failed'
break break
case 'ROUTE_NOT_FOUND': case 'ROUTE_NOT_FOUND':
status = <>could not find route <small className='ml-3'>try increasing max fee</small></> status = <>no route <small className='ml-3'>try increasing max fee</small></>
variant = 'failed' variant = 'failed'
break break
default: default:

@ -1,5 +1,17 @@
-- This is an empty migration. -- This is an empty migration.
create function now_utc() returns timestamp as $$
select now() at time zone 'utc';
$$ language sql;
create function ASSERT_SERIALIZED() returns void as $$
BEGIN
IF (select current_setting('transaction_isolation') <> 'serializable') THEN
RAISE EXCEPTION 'SN_NOT_SERIALIZABLE';
END IF;
END;
$$ language plpgsql;
CREATE OR REPLACE FUNCTION vote(item_id INTEGER, username TEXT, vote_sats INTEGER) CREATE OR REPLACE FUNCTION vote(item_id INTEGER, username TEXT, vote_sats INTEGER)
RETURNS INTEGER RETURNS INTEGER
LANGUAGE plpgsql LANGUAGE plpgsql
@ -8,6 +20,8 @@ DECLARE
user_id INTEGER; user_id INTEGER;
user_sats INTEGER; user_sats INTEGER;
BEGIN BEGIN
PERFORM ASSERT_SERIALIZED();
SELECT (msats / 1000), id INTO user_sats, user_id FROM users WHERE name = username; SELECT (msats / 1000), id INTO user_sats, user_id FROM users WHERE name = username;
IF vote_sats > user_sats THEN IF vote_sats > user_sats THEN
RAISE EXCEPTION 'SN_INSUFFICIENT_FUNDS'; RAISE EXCEPTION 'SN_INSUFFICIENT_FUNDS';
@ -16,12 +30,15 @@ BEGIN
UPDATE users SET msats = msats - (vote_sats * 1000) WHERE id = user_id; UPDATE users SET msats = msats - (vote_sats * 1000) WHERE id = user_id;
IF EXISTS (SELECT 1 FROM "Vote" WHERE "itemId" = item_id AND "userId" = user_id) THEN IF EXISTS (SELECT 1 FROM "Vote" WHERE "itemId" = item_id AND "userId" = user_id) THEN
INSERT INTO "Vote" (sats, "itemId", "userId", boost, updated_at) VALUES (vote_sats, item_id, user_id, true, 'now'); INSERT INTO "Vote" (sats, "itemId", "userId", boost, created_at, updated_at)
VALUES (vote_sats, item_id, user_id, true, now_utc(), now_utc());
ELSE ELSE
INSERT INTO "Vote" (sats, "itemId", "userId", updated_at) VALUES (1, item_id, user_id, 'now'); INSERT INTO "Vote" (sats, "itemId", "userId", created_at, updated_at)
VALUES (1, item_id, user_id, now_utc(), now_utc());
UPDATE users SET msats = msats + 1000 WHERE id = (SELECT "userId" FROM "Item" WHERE id = item_id); UPDATE users SET msats = msats + 1000 WHERE id = (SELECT "userId" FROM "Item" WHERE id = item_id);
IF vote_sats > 1 THEN IF vote_sats > 1 THEN
INSERT INTO "Vote" (sats, "itemId", "userId", boost, updated_at) VALUES (vote_sats - 1, item_id, user_id, true, 'now'); INSERT INTO "Vote" (sats, "itemId", "userId", boost, created_at, updated_at)
VALUES (vote_sats - 1, item_id, user_id, true, now_utc(), now_utc());
END IF; END IF;
END IF; END IF;
@ -38,6 +55,8 @@ DECLARE
user_sats INTEGER; user_sats INTEGER;
item "Item"; item "Item";
BEGIN BEGIN
PERFORM ASSERT_SERIALIZED();
SELECT (msats / 1000), id INTO user_sats, user_id FROM users WHERE name = username; SELECT (msats / 1000), id INTO user_sats, user_id FROM users WHERE name = username;
IF 1 > user_sats THEN IF 1 > user_sats THEN
RAISE EXCEPTION 'SN_INSUFFICIENT_FUNDS'; RAISE EXCEPTION 'SN_INSUFFICIENT_FUNDS';
@ -45,9 +64,11 @@ BEGIN
UPDATE users SET msats = msats - 1000 WHERE id = user_id; UPDATE users SET msats = msats - 1000 WHERE id = user_id;
INSERT INTO "Item" (title, url, text, "userId", "parentId", updated_at) INSERT INTO "Item" (title, url, text, "userId", "parentId", created_at, updated_at)
VALUES (title, url, text, user_id, parent_id, 'now') RETURNING * INTO item; VALUES (title, url, text, user_id, parent_id, now_utc(), now_utc()) RETURNING * INTO item;
INSERT INTO "Vote" (sats, "itemId", "userId", updated_at) VALUES (1, item.id, user_id, 'now');
INSERT INTO "Vote" (sats, "itemId", "userId", created_at, updated_at)
VALUES (1, item.id, user_id, now_utc(), now_utc());
RETURN item; RETURN item;
END; END;
@ -61,9 +82,12 @@ DECLARE
user_id INTEGER; user_id INTEGER;
confirmed_at TIMESTAMP; confirmed_at TIMESTAMP;
BEGIN BEGIN
PERFORM ASSERT_SERIALIZED();
SELECT "userId", "confirmedAt" INTO user_id, confirmed_at FROM "Invoice" WHERE hash = lnd_id; SELECT "userId", "confirmedAt" INTO user_id, confirmed_at FROM "Invoice" WHERE hash = lnd_id;
IF confirmed_at IS NULL THEN IF confirmed_at IS NULL THEN
UPDATE "Invoice" SET "msatsReceived" = lnd_received, "confirmedAt" = 'now' WHERE hash = lnd_id; UPDATE "Invoice" SET "msatsReceived" = lnd_received, "confirmedAt" = now_utc(), updated_at = now_utc()
WHERE hash = lnd_id;
UPDATE users SET msats = msats + lnd_received WHERE id = user_id; UPDATE users SET msats = msats + lnd_received WHERE id = user_id;
END IF; END IF;
RETURN 0; RETURN 0;

@ -7,13 +7,15 @@ DECLARE
user_msats INTEGER; user_msats INTEGER;
withdrawl "Withdrawl"; withdrawl "Withdrawl";
BEGIN BEGIN
PERFORM ASSERT_SERIALIZED();
SELECT msats, id INTO user_msats, user_id FROM users WHERE name = username; SELECT msats, id INTO user_msats, user_id FROM users WHERE name = username;
IF (msats_amount + msats_max_fee) > user_msats THEN IF (msats_amount + msats_max_fee) > user_msats THEN
RAISE EXCEPTION 'SN_INSUFFICIENT_FUNDS'; RAISE EXCEPTION 'SN_INSUFFICIENT_FUNDS';
END IF; END IF;
INSERT INTO "Withdrawl" (hash, bolt11, "msatsPaying", "msatsFeePaying", "userId", updated_at) INSERT INTO "Withdrawl" (hash, bolt11, "msatsPaying", "msatsFeePaying", "userId", created_at, updated_at)
VALUES (lnd_id, invoice, msats_amount, msats_max_fee, user_id, 'now') RETURNING * INTO withdrawl; VALUES (lnd_id, invoice, msats_amount, msats_max_fee, user_id, now_utc(), now_utc()) RETURNING * INTO withdrawl;
UPDATE users SET msats = msats - msats_amount - msats_max_fee WHERE id = user_id; UPDATE users SET msats = msats - msats_amount - msats_max_fee WHERE id = user_id;
@ -29,8 +31,13 @@ DECLARE
msats_fee_paying INTEGER; msats_fee_paying INTEGER;
user_id INTEGER; user_id INTEGER;
BEGIN BEGIN
PERFORM ASSERT_SERIALIZED();
IF EXISTS (SELECT 1 FROM "Withdrawl" WHERE id = wid AND status IS NULL) THEN IF EXISTS (SELECT 1 FROM "Withdrawl" WHERE id = wid AND status IS NULL) THEN
UPDATE "Withdrawl" SET status = 'CONFIRMED', "msatsPaid" = msats_paid, "msatsFeePaid" = msats_fee_paid WHERE id = wid; UPDATE "Withdrawl"
SET status = 'CONFIRMED', "msatsPaid" = msats_paid,
"msatsFeePaid" = msats_fee_paid, updated_at = now_utc()
WHERE id = wid;
SELECT "msatsFeePaying", "userId" INTO msats_fee_paying, user_id FROM "Withdrawl" WHERE id = wid; SELECT "msatsFeePaying", "userId" INTO msats_fee_paying, user_id FROM "Withdrawl" WHERE id = wid;
UPDATE users SET msats = msats + (msats_fee_paying - msats_fee_paid) WHERE id = user_id; UPDATE users SET msats = msats + (msats_fee_paying - msats_fee_paid) WHERE id = user_id;
END IF; END IF;
@ -48,8 +55,10 @@ DECLARE
msats_paying INTEGER; msats_paying INTEGER;
user_id INTEGER; user_id INTEGER;
BEGIN BEGIN
PERFORM ASSERT_SERIALIZED();
IF EXISTS (SELECT 1 FROM "Withdrawl" WHERE id = wid AND status IS NULL) THEN IF EXISTS (SELECT 1 FROM "Withdrawl" WHERE id = wid AND status IS NULL) THEN
UPDATE "Withdrawl" SET status = wstatus WHERE id = wid; UPDATE "Withdrawl" SET status = wstatus, updated_at = now_utc() WHERE id = wid;
SELECT "msatsPaying", "msatsFeePaying", "userId" INTO msats_paying, msats_fee_paying, user_id FROM "Withdrawl" WHERE id = wid; SELECT "msatsPaying", "msatsFeePaying", "userId" INTO msats_paying, msats_fee_paying, user_id FROM "Withdrawl" WHERE id = wid;
UPDATE users SET msats = msats + msats_paying + msats_fee_paying WHERE id = user_id; UPDATE users SET msats = msats + msats_paying + msats_fee_paying WHERE id = user_id;
END IF; END IF;

@ -1,6 +1,7 @@
const { PrismaClient } = require('@prisma/client') const { PrismaClient } = require('@prisma/client')
const { authenticatedLndGrpc, subscribeToInvoices, getInvoice, getPayment } = require('ln-service') const { authenticatedLndGrpc, subscribeToInvoices, getInvoice, getPayment } = require('ln-service')
const dotenv = require('dotenv') const dotenv = require('dotenv')
const serialize = require('../api/resolvers/serial')
dotenv.config({ path: '..' }) dotenv.config({ path: '..' })
@ -15,17 +16,19 @@ const models = new PrismaClient()
async function recordInvoiceStatus (inv) { async function recordInvoiceStatus (inv) {
console.log(inv) console.log(inv)
if (inv.is_confirmed) { if (inv.is_confirmed) {
await models.$queryRaw`SELECT confirm_invoice(${inv.id}, ${Number(inv.received_mtokens)})` await serialize(models,
models.$executeRaw`SELECT confirm_invoice(${inv.id}, ${Number(inv.received_mtokens)})`)
} else if (inv.is_canceled) { } else if (inv.is_canceled) {
// mark as cancelled // mark as cancelled
models.invoice.update({ await serialize(models,
where: { models.invoice.update({
hash: inv.id where: {
}, hash: inv.id
data: { },
cancelled: true data: {
} cancelled: true
}) }
}))
} }
} }
@ -67,8 +70,8 @@ async function recordWithdrawlStatus (id, wdrwl) {
// is this true for getPayment? // is this true for getPayment?
const fee = Number(wdrwl.payment.fee_mtokens) const fee = Number(wdrwl.payment.fee_mtokens)
const paid = Number(wdrwl.mtokens) - fee const paid = Number(wdrwl.mtokens) - fee
await models.$queryRaw` await serialize(models, models.$executeRaw`
SELECT confirm_withdrawl(${id}, ${paid}, ${fee})` SELECT confirm_withdrawl(${id}, ${paid}, ${fee})`)
} else if (wdrwl.is_failed) { } else if (wdrwl.is_failed) {
let status = 'UNKNOWN_FAILURE' let status = 'UNKNOWN_FAILURE'
if (wdrwl.failed.is_insufficient_balance) { if (wdrwl.failed.is_insufficient_balance) {
@ -80,8 +83,8 @@ async function recordWithdrawlStatus (id, wdrwl) {
} else if (wdrwl.failed.is_route_not_found) { } else if (wdrwl.failed.is_route_not_found) {
status = 'ROUTE_NOT_FOUND' status = 'ROUTE_NOT_FOUND'
} }
await models.$queryRaw` await serialize(models, models.$executeRaw`
SELECT reverse_withdrawl(${id}, ${status})` SELECT reverse_withdrawl(${id}, ${status})`)
} }
} }
@ -90,7 +93,7 @@ async function checkPendingWithdrawls () {
const leftovers = await models.withdrawl.findMany({ const leftovers = await models.withdrawl.findMany({
where: { where: {
createdAt: { createdAt: {
lt: new Date(new Date().setSeconds(new Date().getSeconds() + 30)) lt: new Date(new Date().setSeconds(new Date().getSeconds() - 30))
}, },
status: { status: {
equals: null equals: null