transactional wallet management in plpgsql

This commit is contained in:
keyan 2021-05-11 15:29:44 -05:00
parent bc0389e622
commit 67d1605666
7 changed files with 142 additions and 104 deletions

View File

@ -6,13 +6,13 @@ async function comments (models, id) {
${SELECT}, ARRAY[row_number() OVER (${ORDER_BY_SATS}, "Item".path)] AS sort_path
FROM "Item"
${LEFT_JOIN_SATS}
WHERE "parentId" = ${id}
WHERE "parentId" = $1
UNION ALL
${SELECT}, p.sort_path || row_number() OVER (${ORDER_BY_SATS}, "Item".path)
FROM base p
JOIN "Item" ON ltree2text(subpath("Item"."path", 0, -1)) = p."path"
${LEFT_JOIN_SATS})
SELECT * FROM base ORDER BY sort_path`)
SELECT * FROM base ORDER BY sort_path`, Number(id))
return nestComments(flat, id)[0]
}
@ -34,11 +34,10 @@ export default {
ORDER BY created_at DESC`)
},
item: async (parent, { id }, { models }) => {
const item = (await models.$queryRaw(`
const [item] = await models.$queryRaw(`
${SELECT}
FROM "Item"
WHERE id = ${id}`))[0]
WHERE id = $1`, Number(id))
item.comments = comments(models, id)
return item
},
@ -46,15 +45,15 @@ export default {
return await models.$queryRaw(`
${SELECT}
FROM "Item"
WHERE "userId" = ${userId} AND "parentId" IS NULL
ORDER BY created_at`)
WHERE "userId" = $1 AND "parentId" IS NULL
ORDER BY created_at`, Number(userId))
},
userComments: async (parent, { userId }, { models }) => {
return await models.$queryRaw(`
${SELECT}
FROM "Item"
WHERE "userId" = ${userId} AND "parentId" IS NOT NULL
ORDER BY created_at DESC`)
WHERE "userId" = $1 AND "parentId" IS NOT NULL
ORDER BY created_at DESC`, Number(userId))
},
root: async (parent, { id }, { models }) => {
return (await models.$queryRaw(`
@ -63,36 +62,36 @@ export default {
WHERE id = (
SELECT ltree2text(subltree(path, 0, 1))::integer
FROM "Item"
WHERE id = ${id})`))[0]
WHERE id = $1)`, Number(id)))[0]
}
},
Mutation: {
createLink: async (parent, { title, url }, { me, models }) => {
if (!title) {
throw new UserInputError('Link must have title', { argumentName: 'title' })
throw new UserInputError('link must have title', { argumentName: 'title' })
}
if (!url) {
throw new UserInputError('Link must have url', { argumentName: 'url' })
throw new UserInputError('link must have url', { argumentName: 'url' })
}
return await createItem(parent, { title, url }, { me, models })
},
createDiscussion: async (parent, { title, text }, { me, models }) => {
if (!title) {
throw new UserInputError('Link must have title', { argumentName: 'title' })
throw new UserInputError('link must have title', { argumentName: 'title' })
}
return await createItem(parent, { title, text }, { me, models })
},
createComment: async (parent, { text, parentId }, { me, models }) => {
if (!text) {
throw new UserInputError('Comment must have text', { argumentName: 'text' })
throw new UserInputError('comment must have text', { argumentName: 'text' })
}
if (!parentId) {
throw new UserInputError('Comment must have parent', { argumentName: 'text' })
throw new UserInputError('comment must have parent', { argumentName: 'text' })
}
return await createItem(parent, { text, parentId }, { me, models })
@ -100,37 +99,22 @@ export default {
vote: async (parent, { id, sats = 1 }, { me, models }) => {
// need to make sure we are logged in
if (!me) {
throw new AuthenticationError('You must be logged in')
throw new AuthenticationError('you must be logged in')
}
if (sats <= 0) {
throw new UserInputError('Sats must be positive', { argumentName: 'sats' })
throw new UserInputError('sats must be positive', { argumentName: 'sats' })
}
// TODO: check if we've already voted for the item ... XXX this isn't transactional
const boosted = await models.vote.findFirst({
where: {
itemId: parseInt(id),
userId: me.id
try {
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')
}
})
const data = {
sats,
item: {
connect: {
id: parseInt(id)
}
},
user: {
connect: {
name: me.name
}
},
boost: !!boosted
throw error
}
await models.vote.create({ data })
return sats
}
},
@ -189,33 +173,24 @@ export default {
}
}
const createItem = async (parent, { title, text, url, parentId }, { me, models }) => {
const createItem = async (parent, { title, url, text, parentId }, { me, models }) => {
if (!me) {
throw new AuthenticationError('You must be logged in')
throw new AuthenticationError('you must be logged in')
}
const data = {
title,
url,
text,
user: {
connect: {
name: me.name
}
try {
const [item] = await models.$queryRaw(
`${SELECT} FROM create_item($1, $2, $3, $4, $5) AS "Item"`,
title, url, text, Number(parentId), me.name)
item.comments = []
return item
} catch (error) {
const { meta: { message } } = error
if (message.includes('SN_INSUFFICIENT_FUNDS')) {
throw new UserInputError('insufficient funds')
}
throw error
}
if (parentId) {
data.parent = {
connect: {
id: parseInt(parentId)
}
}
}
const item = await models.item.create({ data })
item.comments = []
return item
}
function nestComments (flat, parentId) {

View File

@ -20,7 +20,7 @@ export default {
const [{ sum }] = await models.$queryRaw`
SELECT sum("Vote".sats)
FROM "Item"
LEFT JOIN "Vote" on "Vote"."itemId" = "Item".id
LEFT JOIN "Vote" on "Vote"."itemId" = "Item".id AND "Item"."userId" <> ${user.id}
WHERE "Item"."userId" = ${user.id}`
return sum || 0
},

View File

@ -15,46 +15,7 @@ const models = new PrismaClient()
async function recordStatus (inv) {
console.log(inv)
if (inv.is_confirmed) {
const received = Number(inv.received_mtokens)
// only increment iff this invoice has not yet confirmed
const updateUser = models.user.updateMany({
where: {
invoices: {
some: {
hash: inv.id,
confirmedAt: {
equals: null
}
}
}
},
data: {
msats: {
increment: received
}
}
})
// ATOMICALLY (with above) mark the invoice as confirmed
const updateInvoice = models.invoice.updateMany({
where: {
hash: inv.id,
AND: [
{
confirmedAt: {
equals: null
}
}
]
},
data: {
confirmedAt: inv.confirmed_at,
msatsReceived: received
}
})
models.$transaction([updateUser, updateInvoice])
await models.$queryRaw`SELECT confirm_invoice(${inv.id}, ${Number(inv.received_mtokens)})`
} else if (inv.is_canceled) {
// mark as cancelled
models.invoice.update({

View File

@ -55,7 +55,7 @@ export function DiscussionForm () {
export const LinkSchema = Yup.object({
title: Yup.string().required('required').trim(),
url: Yup.string().url('invalid url')
url: Yup.string().url('invalid url').required('required')
})
export function LinkForm () {

View File

@ -0,0 +1,8 @@
/*
Warnings:
- A unique constraint covering the columns `[hash]` on the table `Invoice` will be added. If there are existing duplicate values, this will fail.
*/
-- CreateIndex
CREATE UNIQUE INDEX "Invoice.hash_unique" ON "Invoice"("hash");

View File

@ -0,0 +1,68 @@
-- This is an empty migration.
CREATE OR REPLACE FUNCTION vote(item_id INTEGER, username TEXT, vote_sats INTEGER)
RETURNS INTEGER
LANGUAGE plpgsql
AS $$
DECLARE
user_id INTEGER;
user_sats INTEGER;
BEGIN
SELECT (msats / 1000), id INTO user_sats, user_id FROM users WHERE name = username;
IF vote_sats > user_sats THEN
RAISE EXCEPTION 'SN_INSUFFICIENT_FUNDS';
END IF;
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
INSERT INTO "Vote" (sats, "itemId", "userId", boost, updated_at) VALUES (vote_sats, item_id, user_id, true, 'now');
ELSE
INSERT INTO "Vote" (sats, "itemId", "userId", updated_at) VALUES (vote_sats, item_id, user_id, 'now');
UPDATE users SET msats = msats + (vote_sats * 1000) WHERE id = (SELECT "userId" FROM "Item" WHERE id = item_id);
END IF;
RETURN vote_sats;
END;
$$;
CREATE OR REPLACE FUNCTION create_item(title TEXT, url TEXT, text TEXT, parent_id INTEGER, username TEXT)
RETURNS "Item"
LANGUAGE plpgsql
AS $$
DECLARE
user_id INTEGER;
user_sats INTEGER;
item "Item";
BEGIN
SELECT (msats / 1000), id INTO user_sats, user_id FROM users WHERE name = username;
IF 1 > user_sats THEN
RAISE EXCEPTION 'SN_INSUFFICIENT_FUNDS';
END IF;
UPDATE users SET msats = msats - 1000 WHERE id = user_id;
INSERT INTO "Item" (title, url, text, "userId", "parentId", updated_at)
VALUES (title, url, text, user_id, parent_id, 'now') RETURNING * INTO item;
INSERT INTO "Vote" (sats, "itemId", "userId", updated_at) VALUES (1, item.id, user_id, 'now');
RETURN item;
END;
$$;
CREATE OR REPLACE FUNCTION confirm_invoice(lnd_id TEXT, lnd_received INTEGER)
RETURNS INTEGER
LANGUAGE plpgsql
AS $$
DECLARE
user_id INTEGER;
confirmed_at TIMESTAMP;
BEGIN
SELECT "userId", "confirmedAt" INTO user_id, confirmed_at FROM "Invoice" WHERE hash = lnd_id;
IF confirmed_at IS NULL THEN
UPDATE "Invoice" SET "msatsReceived" = lnd_received, "confirmedAt" = 'now' WHERE hash = lnd_id;
UPDATE users SET msats = msats + lnd_received WHERE id = user_id;
END IF;
RETURN 0;
END;
$$;

View File

@ -36,4 +36,30 @@ WITH RECURSIVE base AS (
FROM base p
JOIN "Item" ON ltree2text(subpath("Item"."path", 0, -1)) = p."path"
)
select * from base order by sort_path;
select * from base order by sort_path;
CREATE OR REPLACE FUNCTION vote(item_id INTEGER, username TEXT, vote_sats INTEGER)
RETURNS INTEGER
LANGUAGE plpgsql
AS $$
DECLARE
user_id INTEGER
user_sats INTEGER
BEGIN
SELECT sats, id INTO user_sats, user_id FROM "User" WHERE name = username;
IF vote_sats > user_sats THEN
RAISE EXCEPTION 'insufficient funds';
END IF;
UPDATE "User" SET sats = sats - vote_sats WHERE id = user_id;
IF EXISTS (SELECT 1 FROM "Vote" WHERE "itemId" = item_id AND "userId" = user_id) THEN
INSERT INTO "Vote" (sats, "itemId", "userId") VALUES (vote_sats, item_id, user_id);
UPDATE "User" SET sats = sats + vote_sats WHERE id = (SELECT "userId" FROM "Item" WHERE id = item_id);
ELSE
INSERT INTO "Vote" (sats, "itemId", "userId", boost) VALUES (vote_sats, item_id, user_id, true);
END IF;
RETURN sats
END;
$$;