stacker.news/prisma/migrations/20221213203919_add_bounty/migration.sql

94 lines
3.1 KiB
PL/PgSQL

-- AlterTable
ALTER TABLE "Item" ADD COLUMN "bounty" INTEGER;
ALTER TABLE "Item" ADD CONSTRAINT "bounty" CHECK ("bounty" IS NULL OR "bounty" > 0) NOT VALID;
CREATE OR REPLACE FUNCTION create_item(
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;
free_posts INTEGER;
free_comments INTEGER;
freebie BOOLEAN;
item "Item";
med_votes FLOAT;
BEGIN
PERFORM ASSERT_SERIALIZED();
SELECT msats, "freePosts", "freeComments"
INTO user_msats, free_posts, free_comments
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, boost = 0, and they have freebies left
freebie := (cost_msats <= 1000) AND (user_msats < 1000) AND (boost = 0) AND ((parent_id IS NULL AND free_posts > 0) OR (parent_id IS NOT NULL AND free_comments > 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
IF med_votes >= 0 THEN
med_votes := 0;
ELSE
med_votes := ABS(med_votes);
END IF;
INSERT INTO "Item" (title, url, text, bounty, "userId", "parentId", "fwdUserId", freebie, "weightedDownVotes", created_at, updated_at)
VALUES (title, url, text, bounty, user_id, parent_id, fwd_user_id, freebie, med_votes, now_utc(), now_utc()) RETURNING * INTO item;
IF freebie THEN
IF parent_id IS NULL THEN
UPDATE users SET "freePosts" = "freePosts" - 1 WHERE id = user_id;
ELSE
UPDATE users SET "freeComments" = "freeComments" - 1 WHERE id = user_id;
END IF;
ELSE
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;
$$;
CREATE OR REPLACE FUNCTION update_item(item_id INTEGER,
item_title TEXT, item_url TEXT, item_text TEXT, boost INTEGER,item_bounty INTEGER,
fwd_user_id INTEGER)
RETURNS "Item"
LANGUAGE plpgsql
AS $$
DECLARE
user_msats INTEGER;
item "Item";
BEGIN
PERFORM ASSERT_SERIALIZED();
UPDATE "Item" set title = item_title, url = item_url, text = item_text, bounty = item_bounty, "fwdUserId" = fwd_user_id
WHERE id = item_id
RETURNING * INTO item;
IF boost > 0 THEN
PERFORM item_act(item.id, item."userId", 'BOOST', boost);
END IF;
RETURN item;
END;
$$;