8f590425dc
* Add icon to add images * Open file explorer to select image * Upload images to S3 on selection * Show uploaded images below text input * Link and remove image * Fetch unsubmitted images from database * Mark S3 images as submitted in imgproxy job * Add margin-top * Mark images as submitted on client after successful mutation * Also delete objects in S3 * Allow items to have multiple uploads linked * Overwrite old avatar * Add fees for presigned URLs * Use Github style upload * removed upfront fees * removed images provider since we no longer need to keep track of unsubmitted images on the client * removed User.images resolver * removed deleteImage mutation * use Github style upload where it shows ![Uploading <filename>...]() first and then replaces that with ![<filename>](<url>) after successful upload * Add Upload.paid boolean column One item can have multiple images linked to it, but an image can also be used in multiple items (many-to-many relation). Since we don't really care to which item an image is linked and vice versa, we just use a boolean column to mark if an image was already paid for. This makes fee calculation easier since no JOINs are required. * Add image fees during item creation/update * we calculate image fees during item creation and update now * function imageFees returns queries which deduct fees from user and mark images as paid + fees * queries need to be run inside same transaction as item creation/update * Allow anons to get presigned URLs * Add comments regarding avatar upload * Use megabytes in error message * Remove unnecessary avatar check during image fees calculation * Show image fees in frontend * Also update image fees on blur This makes sure that the images fees reflect the current state. For example, if an image was removed. We could also add debounced requests. * Show amount of unpaid images in receipt * Fix fees in sats deducted from msats * Fix algebraic order of fees Spam fees must come immediately after the base fee since it multiplies the base fee. * Fix image fees in edit receipt * Fix stale fees shown If we pay for an image and then want to edit the comment, the cache might return stale date; suggesting we didn't pay for the existing image yet. * Add 0 base fee in edit receipt * Remove 's' from 'image fees' in receipts * Remove unnecessary async * Remove 'Uploading <name>...' from text input on error * Support upload of multiple files at once * Add schedule to delete unused images * Fix image fee display in receipts * Use Drag and Drop API for image upload * Remove dragOver style on drop * Increase max upload size to 10MB to allow HQ camera pictures * Fix free upload quota * Fix stale image fees served * Fix bad image fee return statements * Fix multiplication with feesPerImage * Fix NULL returned for size24h, sizeNow * Remove unnecessary text field in query * refactor: Unify <ImageUpload> and <Upload> component * Add avatar cache busting using random query param * 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` * Fix line break in receipt * Update upload limits * Add comment about `e.target.value = null` * Use debounce instead of onBlur to update image fees info * Fix invoice amount * Refactor avatar upload control flow * Update image fees in onChange * Fix rescheduling of other jobs * also update schedule from every minute to every hour * Add image fees in calling context * keep item ids on uploads * Fix incompatible onSubmit signature * Revert "keep item ids on uploads" This reverts commit 4688962abcd54fdc5850109372a7ad054cf9b2e4. * many2many item uploads * pretty subdomain for images * handle upload conditions for profile images and job logos --------- Co-authored-by: ekzyis <ek@ekzyis.com> Co-authored-by: ekzyis <ek@stacker.news>
242 lines
9.0 KiB
PL/PgSQL
242 lines
9.0 KiB
PL/PgSQL
-- 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;
|
|
$$;
|