stacker.news/prisma/migrations/20230810234326_anon_func_ex.../migration.sql

144 lines
4.9 KiB
MySQL
Raw Normal View History

Allow zapping, posting and commenting without funds or an account (#336) * Add anon zaps * Add anon comments and posts (link, discussion, poll) * Use payment hash instead of invoice id as proof of payment Our invoice IDs can be enumerated. So there is a - even though very rare - chance that an attacker could find a paid invoice which is not used yet and use it for himself. Random payment hashes prevent this. Also, since we delete invoices after use, using database IDs as proof of payments are not suitable. If a user tells us an invoice ID after we deleted it, we can no longer tell if the invoice was paid or not since the LN node only knows about payment hashes but nothing about the database IDs. * Allow pay per invoice for stackers The modal which pops up if the stacker does not have enough sats now has two options: "fund wallet" and "pay invoice" * Fix onSuccess called twice For some reason, when calling `showModal`, `useMemo` in modal.js and the code for the modal component (here: <Invoice>) is called twice. This leads to the `onSuccess` callback being called twice and one failing since the first one deletes the invoice. * Keep invoice modal open if focus is lost * Skip anon user during trust calculation * Add error handling * Skip 'invoice not found' errors * Remove duplicate insufficient funds handling * Fix insufficient funds error detection * Fix invoice amount for comments * Allow pay per invoice for bounty and job posts * Also strike on payment after short press * Fix unexpected token 'export' * Fix eslint * Remove unused id param * Fix comment copy-paste error * Rename to useInvoiceable * Fix unexpected token 'export' * Fix onConfirmation called at every render * Add invoice HMAC This prevents entities which know the invoice hash (like all LN nodes on the payment path) from using the invoice hash on SN. Only the user which created the invoice knows the HMAC and thus can use the invoice hash. * make anon posting less hidden, add anon info button explainer * Fix anon users can't zap other anon users * Always show repeat and contacts on action error * Keep track of modal stack * give anon an icon * add generic date pivot helper * make anon user's invoices expire in 5 minutes * fix forgotten find and replace * use datePivot more places * add sat amounts to invoices * reduce anon invoice expiration to 3 minutes * don't abbreviate * Fix [object Object] as error message Any errors thrown here are already objects of shape { message: string } * Fix empty invoice creation attempts I stumbled across this while checking if anons can edit their items. I monkey patched the code to make it possible (so they can see the 'edit' button) and tried to edit an item but I got this error: Variable "$amount" of required type "Int!" was not provided. I fixed this even though this function should never be called without an amount anyway. It will return a sane error in that case now. * anon func mods, e.g. inv limits * anon tips should be denormalized * remove redundant meTotalSats * correct overlay zap text for anon * exclude anon from trust graph before algo runs * remove balance limit on anon * give anon a bio and remove cowboy hat/top stackers; * make anon hat appear on profile * concat hash and hmac and call it a token * Fix localStorage cleared because error were swallowed * fix qr layout shift * restyle fund error modal * Catch invoice errors in fund error modal * invoice check backoff * anon info typo * make invoice expiration times have saner defaults * add comma to anon info * use builtin copy input label --------- Co-authored-by: ekzyis <ek@stacker.news> Co-authored-by: keyan <keyan.kousha+huumn@gmail.com>
2023-08-11 23:50:57 +00:00
DROP FUNCTION IF EXISTS create_invoice(hash TEXT, bolt11 TEXT, expires_at timestamp(3) without time zone, msats_req BIGINT, user_id INTEGER, idesc TEXT);
-- make invoice limit and balance limit configurable
CREATE OR REPLACE FUNCTION create_invoice(hash TEXT, bolt11 TEXT, expires_at timestamp(3) without time zone,
msats_req BIGINT, user_id INTEGER, idesc TEXT, inv_limit INTEGER, balance_limit_msats BIGINT)
RETURNS "Invoice"
LANGUAGE plpgsql
AS $$
DECLARE
invoice "Invoice";
inv_limit_reached BOOLEAN;
balance_limit_reached BOOLEAN;
inv_pending_msats BIGINT;
BEGIN
PERFORM ASSERT_SERIALIZED();
-- prevent too many pending invoices
SELECT inv_limit > 0 AND count(*) >= inv_limit, sum("msatsRequested") INTO inv_limit_reached, inv_pending_msats
FROM "Invoice"
WHERE "userId" = user_id AND "expiresAt" > now_utc() AND "confirmedAt" IS NULL AND cancelled = false;
IF inv_limit_reached THEN
RAISE EXCEPTION 'SN_INV_PENDING_LIMIT';
END IF;
-- prevent pending invoices + msats from exceeding the limit
SELECT balance_limit_msats > 0 AND inv_pending_msats+msats_req+msats > balance_limit_msats INTO balance_limit_reached
FROM users
WHERE id = user_id;
IF balance_limit_reached THEN
RAISE EXCEPTION 'SN_INV_EXCEED_BALANCE';
END IF;
-- we good, proceed frens
INSERT INTO "Invoice" (hash, bolt11, "expiresAt", "msatsRequested", "userId", created_at, updated_at, "desc")
VALUES (hash, bolt11, expires_at, msats_req, user_id, now_utc(), now_utc(), idesc) RETURNING * INTO invoice;
INSERT INTO pgboss.job (name, data, retrylimit, retrybackoff, startafter)
VALUES ('checkInvoice', jsonb_build_object('hash', hash), 21, true, now() + interval '10 seconds');
RETURN invoice;
END;
$$;
-- don't presume outlaw status for anon posters
CREATE OR REPLACE FUNCTION create_item(
sub TEXT, title TEXT, url TEXT, text TEXT, boost INTEGER, bounty INTEGER,
parent_id INTEGER, user_id INTEGER, fwd_user_id INTEGER,
spam_within INTERVAL)
RETURNS "Item"
LANGUAGE plpgsql
AS $$
DECLARE
user_msats BIGINT;
cost_msats BIGINT;
freebie BOOLEAN;
item "Item";
med_votes FLOAT;
BEGIN
PERFORM ASSERT_SERIALIZED();
SELECT msats INTO user_msats FROM users WHERE id = user_id;
cost_msats := 1000 * POWER(10, item_spam(parent_id, user_id, spam_within));
-- 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 (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" = user_id;
-- 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 user_id = 27 THEN
med_votes := 0;
ELSE
med_votes := ABS(med_votes);
END IF;
INSERT INTO "Item"
("subName", title, url, text, bounty, "userId", "parentId", "fwdUserId",
freebie, "weightedDownVotes", created_at, updated_at)
VALUES
(sub, title, url, text, bounty, user_id, parent_id, fwd_user_id,
freebie, med_votes, now_utc(), now_utc()) RETURNING * INTO item;
IF NOT freebie THEN
UPDATE users SET msats = msats - cost_msats WHERE id = user_id;
INSERT INTO "ItemAct" (msats, "itemId", "userId", act, created_at, updated_at)
VALUES (cost_msats, item.id, user_id, 'FEE', now_utc(), now_utc());
END IF;
IF boost > 0 THEN
PERFORM item_act(item.id, user_id, 'BOOST', boost);
END IF;
RETURN item;
END;
$$;
-- keep item_spam unaware of anon user
CREATE OR REPLACE FUNCTION item_spam(parent_id INTEGER, user_id INTEGER, within INTERVAL)
RETURNS INTEGER
LANGUAGE plpgsql
AS $$
DECLARE
repeats INTEGER;
self_replies INTEGER;
BEGIN
-- no fee escalation
IF within = interval '0' THEN
RETURN 0;
END IF;
SELECT count(*) INTO repeats
FROM "Item"
WHERE (parent_id IS NULL AND "parentId" IS NULL OR "parentId" = parent_id)
AND "userId" = user_id
AND created_at > now_utc() - within;
IF parent_id IS NULL THEN
RETURN repeats;
END IF;
WITH RECURSIVE base AS (
SELECT "Item".id, "Item"."parentId", "Item"."userId"
FROM "Item"
WHERE id = parent_id AND "userId" = user_id AND created_at > now_utc() - within
UNION ALL
SELECT "Item".id, "Item"."parentId", "Item"."userId"
FROM base p
JOIN "Item" ON "Item".id = p."parentId" AND "Item"."userId" = p."userId" AND "Item".created_at > now_utc() - within)
SELECT count(*) INTO self_replies FROM base;
RETURN repeats + self_replies;
END;
$$;