Calculate image fee info in postgres function

* we now calculate image fee info in a postgres function which is much cleaner
* we use this function inside `create_item` and `update_item`: image fees are now deducted in the same transaction as creating/updating the item!
* reversed changes in `serializeInvoiceable`
This commit is contained in:
ekzyis 2023-10-27 00:39:04 +02:00
parent 31fa3dcf26
commit fe267cd3b9
9 changed files with 303 additions and 161 deletions

View File

@ -1,92 +1,23 @@
import { ANON_USER_ID, AWS_S3_URL_REGEXP } from '../../lib/constants'
import { datePivot } from '../../lib/time'
import { msatsToSats } from '../../lib/format'
export default {
Query: {
imageFees: async (parent, { s3Keys }, { models, me }) => {
const imgFees = await imageFees(s3Keys, { models, me })
delete imgFees.queries
// database returns NULL for sizes if no rows are found
imgFees.size24h ??= 0
imgFees.sizeNow ??= 0
// add defaults so we can be sure these properties always exist in the frontend
return Object.assign({ fees: 0, unpaid: 0, feesPerImage: 0, size24h: 0, sizeNow: 0 }, imgFees)
imageFeesInfo: async (parent, { s3Keys }, { models, me }) => {
return imageFeesInfo(s3Keys, { models, me })
}
}
}
export async function imageFeesFromText (text, { models, me }) {
// no text means no image fees
if (!text) return { queries: itemId => [], fees: 0 }
// parse all s3 keys (= image ids) from text
const textS3Keys = [...text.matchAll(AWS_S3_URL_REGEXP)].map(m => Number(m[1]))
if (!textS3Keys.length) return { queries: itemId => [], fees: 0 }
return imageFees(textS3Keys, { models, me })
export function uploadIdsFromText (text, { models }) {
if (!text) return null
return [...text.matchAll(AWS_S3_URL_REGEXP)].map(m => Number(m[1]))
}
export async function imageFees (s3Keys, { models, me }) {
// To apply image fees, we return queries which need to be run, preferably in the same transaction as creating or updating an item.
function queries (userId, imgIds, imgFees) {
return itemId => {
return [
// pay fees
models.$queryRawUnsafe('SELECT * FROM user_fee($1::INTEGER, $2::INTEGER, $3::BIGINT)', userId, itemId, imgFees * 1000),
// mark images as paid
models.upload.updateMany({ where: { id: { in: imgIds } }, data: { paid: true } })
]
}
}
// we want to ignore image ids for which someone already paid during fee calculation
// to make sure that every image is only paid once
const unpaidS3Keys = (await models.upload.findMany({ select: { id: true }, where: { id: { in: s3Keys }, paid: false } })).map(({ id }) => id)
const unpaid = unpaidS3Keys.length
if (!unpaid) return { queries: itemId => [], fees: 0 }
if (!me) {
// anons pay for every new image 100 sats
const feesPerImage = 100
const fees = feesPerImage * unpaid
return { queries: queries(ANON_USER_ID, unpaidS3Keys, fees), fees, feesPerImage, unpaid }
}
// check how much stacker uploaded in last 24 hours
const { _sum: { size: size24h } } = await models.upload.aggregate({
_sum: { size: true },
where: {
userId: me.id,
createdAt: { gt: datePivot(new Date(), { days: -1 }) },
paid: true
}
})
// check how much stacker uploaded now in size
const { _sum: { size: sizeNow } } = await models.upload.aggregate({
_count: { id: true },
_sum: { size: true },
where: { id: { in: unpaidS3Keys } }
})
// total size that we consider to calculate fees includes size of images within last 24 hours and size of incoming images
const size = size24h + sizeNow
const MB = 1024 * 1024 // factor for bytes -> megabytes
// 10 MB per 24 hours are free. fee is also 0 if there are no incoming images (obviously)
let feesPerImage
if (!sizeNow || size <= 10 * MB) {
feesPerImage = 0
} else if (size <= 25 * MB) {
feesPerImage = 10
} else if (size <= 50 * MB) {
feesPerImage = 100
} else if (size <= 100 * MB) {
feesPerImage = 1000
} else {
feesPerImage = 10000
}
const fees = feesPerImage * unpaid
return { queries: queries(me.id, unpaidS3Keys, fees * unpaid), fees, feesPerImage, unpaid, size24h, sizeNow }
export async function imageFeesInfo (s3Keys, { models, me }) {
const [info] = await models.$queryRawUnsafe('SELECT * FROM image_fees_info($1::INTEGER, $2::INTEGER[])', me ? me.id : ANON_USER_ID, s3Keys)
const imageFee = msatsToSats(info.imageFeeMsats)
const totalFeesMsats = info.nUnpaid * Number(info.imageFeeMsats)
const totalFees = msatsToSats(totalFeesMsats)
return { ...info, imageFee, totalFees, totalFeesMsats }
}

View File

@ -1,6 +1,6 @@
import { GraphQLError } from 'graphql'
import { ensureProtocol, removeTracking } from '../../lib/url'
import serialize, { serializeInvoicable } from './serial'
import { serializeInvoicable } from './serial'
import { decodeCursor, LIMIT, nextCursorEncoded } from '../../lib/cursor'
import { getMetadata, metadataRuleSets } from 'page-metadata-parser'
import { ruleSet as publicationDateRuleSet } from '../../lib/timedate-scraper'
@ -19,7 +19,7 @@ import { sendUserNotification } from '../webPush'
import { defaultCommentSort, isJob, deleteItemByAuthor, getDeleteCommand, hasDeleteCommand } from '../../lib/item'
import { notifyItemParents, notifyUserSubscribers, notifyZapped } from '../../lib/push-notifications'
import { datePivot } from '../../lib/time'
import { imageFeesFromText } from './image'
import { imageFeesInfo, uploadIdsFromText } from './image'
export async function commentFilterClause (me, models) {
let clause = ` AND ("Item"."weightedVotes" - "Item"."weightedDownVotes" > -${ITEM_FILTER_THRESHOLD}`
@ -1091,13 +1091,12 @@ export const updateItem = async (parent, { sub: subName, forward, options, ...it
item = { subName, userId: me.id, ...item }
const fwdUsers = await getForwardUsers(models, forward)
const { queries: imgQueriesFn, fees: imgFees } = await imageFeesFromText(item.text, { models, me })
const uploadIds = uploadIdsFromText(item.text, { models })
const { fees: imgFees } = await imageFeesInfo(uploadIds, { models, me })
item = await serializeInvoicable(
[
models.$queryRawUnsafe(`${SELECT} FROM update_item($1::JSONB, $2::JSONB, $3::JSONB) AS "Item"`,
JSON.stringify(item), JSON.stringify(fwdUsers), JSON.stringify(options)),
...imgQueriesFn(Number(item.id))
],
models.$queryRawUnsafe(`${SELECT} FROM update_item($1::JSONB, $2::JSONB, $3::JSONB, $4::INTEGER[]) AS "Item"`,
JSON.stringify(item), JSON.stringify(fwdUsers), JSON.stringify(options), uploadIds),
{ models, lnd, hash, hmac, me, enforceFee: imgFees }
)
@ -1128,19 +1127,17 @@ export const createItem = async (parent, { forward, options, ...item }, { me, mo
item.url = removeTracking(item.url)
}
const { queries: imgQueriesFn, fees: imgFees } = await imageFeesFromText(item.text, { models, me })
const uploadIds = uploadIdsFromText(item.text, { models })
const { fees: imgFees } = await imageFeesInfo(uploadIds, { models, me })
const enforceFee = (me ? undefined : (item.parentId ? ANON_COMMENT_FEE : (ANON_POST_FEE + (item.boost || 0)))) + imgFees
item = await serializeInvoicable(
models.$queryRawUnsafe(
`${SELECT} FROM create_item($1::JSONB, $2::JSONB, $3::JSONB, '${spamInterval}'::INTERVAL) AS "Item"`,
JSON.stringify(item), JSON.stringify(fwdUsers), JSON.stringify(options)),
`${SELECT} FROM create_item($1::JSONB, $2::JSONB, $3::JSONB, '${spamInterval}'::INTERVAL, $4::INTEGER[]) AS "Item"`,
JSON.stringify(item), JSON.stringify(fwdUsers), JSON.stringify(options), uploadIds),
{ models, lnd, hash, hmac, me, enforceFee }
)
// TODO run image queries in same transaction as create_item
const imgQueries = imgQueriesFn(item.id)
if (imgQueries.length > 0) await serialize(models, ...imgQueries)
await createMentions(item, models)
await enqueueDeletionJob(item, models)

View File

@ -59,29 +59,25 @@ export default async function serialize (models, ...calls) {
})
}
export async function serializeInvoicable (queries, { models, lnd, hash, hmac, me, enforceFee }) {
export async function serializeInvoicable (query, { models, lnd, hash, hmac, me, enforceFee }) {
if (!me && !hash) {
throw new Error('you must be logged in or pay')
}
let trx = Array.isArray(queries) ? queries : [queries]
// save offset to the first query in arguments relative to queries that we will run
let queryOffset = 0
let trx = [query]
let invoice
if (hash) {
invoice = await checkInvoice(models, hash, hmac, enforceFee)
trx = [
models.$queryRaw`UPDATE users SET msats = msats + ${invoice.msatsReceived} WHERE id = ${invoice.user.id}`,
...trx,
query,
models.invoice.update({ where: { hash: invoice.hash }, data: { confirmedAt: new Date() } })
]
// first query in arguments is now at index 1
queryOffset = 1
}
const results = await serialize(models, ...trx)
const result = trx.length > 1 ? results[queryOffset][0] : results[0]
const result = trx.length > 1 ? results[1][0] : results[0]
if (invoice?.isHeld) await settleHodlInvoice({ secret: invoice.preimage, lnd })

View File

@ -1,14 +1,16 @@
import { gql } from 'graphql-tag'
export default gql`
type ImageFees {
fees: Int!
unpaid: Int!
feesPerImage: Int!
sizeNow: Int!
size24h: Int!
type ImageFeesInfo {
totalFees: Int!
totalFeesMsats: Int!
imageFee: Int!
imageFeeMsats: Int!
nUnpaid: Int!
bytesUnpaid: Int!
bytes24h: Int!
}
extend type Query {
imageFees(s3Keys: [Int]!): ImageFees!
imageFeesInfo(s3Keys: [Int]!): ImageFeesInfo!
}
`

View File

@ -12,7 +12,7 @@ import AnonIcon from '../svgs/spy-fill.svg'
import { useShowModal } from './modal'
import Link from 'next/link'
function Receipt ({ cost, repetition, imageFees, baseFee, parentId, boost }) {
function Receipt ({ cost, repetition, imageFeesInfo, baseFee, parentId, boost }) {
return (
<Table className={styles.receipt} borderless size='sm'>
<tbody>
@ -25,9 +25,9 @@ function Receipt ({ cost, repetition, imageFees, baseFee, parentId, boost }) {
<td>x 10<sup>{repetition}</sup></td>
<td className='font-weight-light' align='right'>{repetition} {parentId ? 'repeat or self replies' : 'posts'} in 10m</td>
</tr>}
{imageFees.fees > 0 &&
{imageFeesInfo.totalFees > 0 &&
<tr>
<td>+ {imageFees.unpaid} x {numWithUnits(imageFees.feesPerImage, { abbreviate: false })}</td>
<td>+ {imageFeesInfo.nUnpaid} x {numWithUnits(imageFeesInfo.imageFee, { abbreviate: false })}</td>
<td align='right' className='font-weight-light'>image fee</td>
</tr>}
{boost > 0 &&
@ -85,8 +85,8 @@ export default function FeeButton ({ parentId, baseFee, ChildButton, variant, te
formik?.setFieldValue('cost', cost)
}, [formik?.getFieldProps('cost').value, cost])
const imageFees = formik?.getFieldProps('imageFees').value || { fees: 0 }
const totalCost = cost + imageFees.fees
const imageFeesInfo = formik?.getFieldProps('imageFeesInfo').value || { totalFees: 0 }
const totalCost = cost + imageFeesInfo.totalFees
const show = alwaysShow || !formik?.isSubmitting
return (
@ -97,13 +97,13 @@ export default function FeeButton ({ parentId, baseFee, ChildButton, variant, te
{!me && <AnonInfo />}
{totalCost > baseFee && show &&
<Info>
<Receipt baseFee={baseFee} imageFees={imageFees} repetition={repetition} cost={totalCost} parentId={parentId} boost={boost} />
<Receipt baseFee={baseFee} imageFeesInfo={imageFeesInfo} repetition={repetition} cost={totalCost} parentId={parentId} boost={boost} />
</Info>}
</div>
)
}
function EditReceipt ({ cost, paidSats, imageFees, boost, parentId }) {
function EditReceipt ({ cost, paidSats, imageFeesInfo, boost, parentId }) {
return (
<Table className={styles.receipt} borderless size='sm'>
<tbody>
@ -111,9 +111,9 @@ function EditReceipt ({ cost, paidSats, imageFees, boost, parentId }) {
<td>{numWithUnits(0, { abbreviate: false })}</td>
<td align='right' className='font-weight-light'>edit fee</td>
</tr>
{imageFees.fees > 0 &&
{imageFeesInfo.totalFees > 0 &&
<tr>
<td>+ {imageFees.unpaid} x {numWithUnits(imageFees.feesPerImage, { abbreviate: false })}</td>
<td>+ {imageFeesInfo.nUnpaid} x {numWithUnits(imageFeesInfo.imageFee, { abbreviate: false })}</td>
<td align='right' className='font-weight-light'>image fee</td>
</tr>}
{boost > 0 &&
@ -141,8 +141,8 @@ export function EditFeeButton ({ paidSats, ChildButton, variant, text, alwaysSho
formik?.setFieldValue('cost', cost)
}, [formik?.getFieldProps('cost').value, cost])
const imageFees = formik?.getFieldProps('imageFees').value || { fees: 0 }
const totalCost = cost + imageFees.fees
const imageFeesInfo = formik?.getFieldProps('imageFeesInfo').value || { totalFees: 0 }
const totalCost = cost + imageFeesInfo.totalFees
const show = alwaysShow || !formik?.isSubmitting
return (
@ -152,7 +152,7 @@ export function EditFeeButton ({ paidSats, ChildButton, variant, text, alwaysSho
</ActionTooltip>
{totalCost > 0 && show &&
<Info>
<EditReceipt paidSats={paidSats} imageFees={imageFees} cost={totalCost} parentId={parentId} boost={boost} />
<EditReceipt paidSats={paidSats} imageFeesInfo={imageFeesInfo} cost={totalCost} parentId={parentId} boost={boost} />
</Info>}
</div>
)

View File

@ -104,14 +104,13 @@ export function MarkdownInput ({ label, topLevel, groupClassName, onChange, onKe
const previousTab = useRef(tab)
const formik = useFormikContext()
const toaster = useToast()
const [updateImageFees] = useLazyQuery(gql`
query imageFees($s3Keys: [Int]!) {
imageFees(s3Keys: $s3Keys) {
fees
unpaid
feesPerImage
size24h
sizeNow
const [updateImageFeesInfo] = useLazyQuery(gql`
query imageFeesInfo($s3Keys: [Int]!) {
imageFeesInfo(s3Keys: $s3Keys) {
totalFees
nUnpaid
imageFee
bytes24h
}
}`, {
fetchPolicy: 'no-cache',
@ -120,8 +119,8 @@ export function MarkdownInput ({ label, topLevel, groupClassName, onChange, onKe
console.log(err)
toaster.danger(err.message || err.toString?.())
},
onCompleted: ({ imageFees }) => {
formik?.setFieldValue('imageFees', imageFees)
onCompleted: ({ imageFeesInfo }) => {
formik?.setFieldValue('imageFeesInfo', imageFeesInfo)
}
})
@ -273,7 +272,7 @@ export function MarkdownInput ({ label, topLevel, groupClassName, onChange, onKe
text = text.replace(`![Uploading ${name}…]()`, `![${name}](${url})`)
helpers.setValue(text)
const s3Keys = [...text.matchAll(AWS_S3_URL_REGEXP)].map(m => Number(m[1]))
updateImageFees({ variables: { s3Keys } })
updateImageFeesInfo({ variables: { s3Keys } })
}}
onError={({ name }) => {
let text = innerRef.current.value
@ -305,7 +304,7 @@ export function MarkdownInput ({ label, topLevel, groupClassName, onChange, onKe
onBlur={() => {
const text = innerRef?.current.value
const s3Keys = text ? [...text.matchAll(AWS_S3_URL_REGEXP)].map(m => Number(m[1])) : []
updateImageFees({ variables: { s3Keys } })
updateImageFeesInfo({ variables: { s3Keys } })
setTimeout(resetSuggestions, 100)
}}
onDragEnter={onDragEnter}

View File

@ -232,9 +232,9 @@ export const useInvoiceable = (onSubmit, options = defaultOptions) => {
// this function will be called before the Form's onSubmit handler is called
// and the form must include `cost` or `amount` as a value
const onSubmitWrapper = useCallback(async (formValues, ...submitArgs) => {
let { cost, imageFees, amount } = formValues
let { cost, imageFeesInfo, amount } = formValues
cost ??= amount
if (imageFees?.fees) cost += imageFees.fees
if (imageFeesInfo?.fees) cost += imageFeesInfo.fees
// action only allowed if logged in
if (!me && options.requireSession) {

View File

@ -1,24 +0,0 @@
-- function to manually deduct fees from user, for example for images fees
CREATE OR REPLACE FUNCTION user_fee(user_id INTEGER, item_id INTEGER, cost_msats BIGINT)
RETURNS users
LANGUAGE plpgsql
AS $$
DECLARE
user users;
user_msats BIGINT;
BEGIN
PERFORM ASSERT_SERIALIZED();
SELECT msats INTO user_msats FROM users WHERE id = user_id;
IF cost_msats > user_msats THEN
RAISE EXCEPTION 'SN_INSUFFICIENT_FUNDS';
END IF;
UPDATE users SET msats = msats - cost_msats WHERE id = user_id RETURNING * INTO user;
INSERT INTO "ItemAct" (msats, "itemId", "userId", act)
VALUES (cost_msats, item_id, user_id, 'FEE');
RETURN user;
END;
$$;

View File

@ -0,0 +1,241 @@
-- function to calculate image fees info for given user and upload ids
CREATE OR REPLACE FUNCTION image_fees_info(user_id INTEGER, upload_ids INTEGER[])
RETURNS TABLE (
"bytes24h" INTEGER,
"bytesUnpaid" INTEGER,
"nUnpaid" INTEGER,
"imageFeeMsats" BIGINT
)
LANGUAGE plpgsql
AS $$
BEGIN
RETURN QUERY SELECT
uploadinfo.*,
CASE
-- anons always pay 100 sats per image
WHEN user_id = 27 THEN 100000::BIGINT
ELSE CASE
-- 10 MB are free per stacker and 24 hours
WHEN uploadinfo."bytes24h" + uploadinfo."bytesUnpaid" <= 10 * 1024 * 1024 THEN 0::BIGINT
WHEN uploadinfo."bytes24h" + uploadinfo."bytesUnpaid" <= 25 * 1024 * 1024 THEN 10000::BIGINT
WHEN uploadinfo."bytes24h" + uploadinfo."bytesUnpaid" <= 50 * 1024 * 1024 THEN 100000::BIGINT
WHEN uploadinfo."bytes24h" + uploadinfo."bytesUnpaid" <= 100 * 1024 * 1024 THEN 1000000::BIGINT
ELSE 10000000::BIGINT
END
END AS "imageFeeMsats"
FROM (
SELECT
-- how much bytes did stacker upload in last 24 hours?
COALESCE(SUM(size) FILTER(WHERE paid = 't' AND created_at >= NOW() - interval '24 hours'), 0)::INTEGER AS "bytes24h",
-- how much unpaid bytes do they want to upload now?
COALESCE(SUM(size) FILTER(WHERE paid = 'f' AND id = ANY(upload_ids)), 0)::INTEGER AS "bytesUnpaid",
-- how many unpaid images do they want to upload now?
COALESCE(COUNT(id) FILTER(WHERE paid = 'f' AND id = ANY(upload_ids)), 0)::INTEGER AS "nUnpaid"
FROM "Upload"
WHERE "Upload"."userId" = user_id
) uploadinfo;
RETURN;
END;
$$;
-- add image fees
CREATE OR REPLACE FUNCTION create_item(
jitem JSONB, forward JSONB, poll_options JSONB, spam_within INTERVAL, upload_ids INTEGER[])
RETURNS "Item"
LANGUAGE plpgsql
AS $$
DECLARE
user_msats BIGINT;
cost_msats BIGINT;
freebie BOOLEAN;
item "Item";
med_votes FLOAT;
select_clause TEXT;
BEGIN
PERFORM ASSERT_SERIALIZED();
-- access fields with appropriate types
item := jsonb_populate_record(NULL::"Item", jitem);
SELECT msats INTO user_msats FROM users WHERE id = item."userId";
IF item."maxBid" IS NOT NULL THEN
cost_msats := 1000000;
ELSE
cost_msats := 1000 * POWER(10, item_spam(item."parentId", item."userId", spam_within));
END IF;
-- add image fees
IF upload_ids IS NOT NULL THEN
cost_msats := cost_msats + (SELECT "nUnpaid" * "imageFeeMsats" FROM image_fees_info(item."userId", upload_ids));
UPDATE "Upload" SET paid = 't' WHERE id = ANY(upload_ids);
END IF;
-- it's only a freebie if it's a 1 sat cost, they have < 1 sat, and boost = 0
freebie := (cost_msats <= 1000) AND (user_msats < 1000) AND (item.boost IS NULL OR item.boost = 0);
IF NOT freebie AND cost_msats > user_msats THEN
RAISE EXCEPTION 'SN_INSUFFICIENT_FUNDS';
END IF;
-- get this user's median item score
SELECT COALESCE(
percentile_cont(0.5) WITHIN GROUP(
ORDER BY "weightedVotes" - "weightedDownVotes"), 0)
INTO med_votes FROM "Item" WHERE "userId" = item."userId";
-- if their median votes are positive, start at 0
-- if the median votes are negative, start their post with that many down votes
-- basically: if their median post is bad, presume this post is too
-- addendum: if they're an anon poster, always start at 0
IF med_votes >= 0 OR item."userId" = 27 THEN
med_votes := 0;
ELSE
med_votes := ABS(med_votes);
END IF;
-- there's no great way to set default column values when using json_populate_record
-- so we need to only select fields with non-null values that way when func input
-- does not include a value, the default value is used instead of null
SELECT string_agg(quote_ident(key), ',') INTO select_clause
FROM jsonb_object_keys(jsonb_strip_nulls(jitem)) k(key);
-- insert the item
EXECUTE format($fmt$
INSERT INTO "Item" (%s, "weightedDownVotes", freebie)
SELECT %1$s, %L, %L
FROM jsonb_populate_record(NULL::"Item", %L) RETURNING *
$fmt$, select_clause, med_votes, freebie, jitem) INTO item;
INSERT INTO "ItemForward" ("itemId", "userId", "pct")
SELECT item.id, "userId", "pct" FROM jsonb_populate_recordset(NULL::"ItemForward", forward);
-- Automatically subscribe to one's own posts
INSERT INTO "ThreadSubscription" ("itemId", "userId")
VALUES (item.id, item."userId");
-- Automatically subscribe forward recipients to the new post
INSERT INTO "ThreadSubscription" ("itemId", "userId")
SELECT item.id, "userId" FROM jsonb_populate_recordset(NULL::"ItemForward", forward);
INSERT INTO "PollOption" ("itemId", "option")
SELECT item.id, "option" FROM jsonb_array_elements_text(poll_options) o("option");
IF NOT freebie THEN
UPDATE users SET msats = msats - cost_msats WHERE id = item."userId";
INSERT INTO "ItemAct" (msats, "itemId", "userId", act)
VALUES (cost_msats, item.id, item."userId", 'FEE');
END IF;
-- if this item has boost
IF item.boost > 0 THEN
PERFORM item_act(item.id, item."userId", 'BOOST', item.boost);
END IF;
-- if this is a job
IF item."maxBid" IS NOT NULL THEN
PERFORM run_auction(item.id);
END IF;
-- if this is a bio
IF item.bio THEN
UPDATE users SET "bioId" = item.id WHERE id = item."userId";
END IF;
-- schedule imgproxy job
INSERT INTO pgboss.job (name, data, retrylimit, retrybackoff, startafter)
VALUES ('imgproxy', jsonb_build_object('id', item.id), 21, true, now() + interval '5 seconds');
RETURN item;
END;
$$;
-- add image fees
CREATE OR REPLACE FUNCTION update_item(
jitem JSONB, forward JSONB, poll_options JSONB, upload_ids INTEGER[])
RETURNS "Item"
LANGUAGE plpgsql
AS $$
DECLARE
user_msats INTEGER;
cost_msats BIGINT;
item "Item";
select_clause TEXT;
BEGIN
PERFORM ASSERT_SERIALIZED();
item := jsonb_populate_record(NULL::"Item", jitem);
SELECT msats INTO user_msats FROM users WHERE id = item."userId";
cost_msats := 0;
-- add image fees
IF upload_ids IS NOT NULL THEN
cost_msats := cost_msats + (SELECT "nUnpaid" * "imageFeeMsats" FROM image_fees_info(item."userId", upload_ids));
UPDATE "Upload" SET paid = 't' WHERE id = ANY(upload_ids);
END IF;
IF cost_msats > 0 AND cost_msats > user_msats THEN
RAISE EXCEPTION 'SN_INSUFFICIENT_FUNDS';
ELSE
UPDATE users SET msats = msats - cost_msats WHERE id = item."userId";
INSERT INTO "ItemAct" (msats, "itemId", "userId", act)
VALUES (cost_msats, item.id, item."userId", 'FEE');
END IF;
IF item.boost > 0 THEN
UPDATE "Item" SET boost = boost + item.boost WHERE id = item.id;
PERFORM item_act(item.id, item."userId", 'BOOST', item.boost);
END IF;
IF item.status IS NOT NULL THEN
UPDATE "Item" SET "statusUpdatedAt" = now_utc()
WHERE id = item.id AND status <> item.status;
END IF;
SELECT string_agg(quote_ident(key), ',') INTO select_clause
FROM jsonb_object_keys(jsonb_strip_nulls(jitem)) k(key)
WHERE key <> 'boost';
EXECUTE format($fmt$
UPDATE "Item" SET (%s) = (
SELECT %1$s
FROM jsonb_populate_record(NULL::"Item", %L)
) WHERE id = %L RETURNING *
$fmt$, select_clause, jitem, item.id) INTO item;
-- Delete any old thread subs if the user is no longer a fwd recipient
DELETE FROM "ThreadSubscription"
WHERE "itemId" = item.id
-- they aren't in the new forward list
AND NOT EXISTS (SELECT 1 FROM jsonb_populate_recordset(NULL::"ItemForward", forward) as nf WHERE "ThreadSubscription"."userId" = nf."userId")
-- and they are in the old forward list
AND EXISTS (SELECT 1 FROM "ItemForward" WHERE "ItemForward"."itemId" = item.id AND "ItemForward"."userId" = "ThreadSubscription"."userId" );
-- Automatically subscribe any new forward recipients to the post
INSERT INTO "ThreadSubscription" ("itemId", "userId")
SELECT item.id, "userId" FROM jsonb_populate_recordset(NULL::"ItemForward", forward)
EXCEPT
SELECT item.id, "userId" FROM "ItemForward" WHERE "itemId" = item.id;
-- Delete all old forward entries, to recreate in next command
DELETE FROM "ItemForward" WHERE "itemId" = item.id;
INSERT INTO "ItemForward" ("itemId", "userId", "pct")
SELECT item.id, "userId", "pct" FROM jsonb_populate_recordset(NULL::"ItemForward", forward);
INSERT INTO "PollOption" ("itemId", "option")
SELECT item.id, "option" FROM jsonb_array_elements_text(poll_options) o("option");
-- if this is a job
IF item."maxBid" IS NOT NULL THEN
PERFORM run_auction(item.id);
END IF;
-- schedule imgproxy job
INSERT INTO pgboss.job (name, data, retrylimit, retrybackoff, startafter)
VALUES ('imgproxy', jsonb_build_object('id', item.id), 21, true, now() + interval '5 seconds');
RETURN item;
END;
$$;