CREATE OR REPLACE FUNCTION create_user( p_name VARCHAR, -- p_discord_id NUMERIC(20,0), p_wallet VARCHAR(64), p_user_id UUID DEFAULT NULL ) RETURNS UUID AS $$ DECLARE new_uuid UUID; res_id INTEGER; BEGIN IF p_user_id IS NULL THEN INSERT INTO users(name, wallet) VALUES (p_name, p_wallet) RETURNING id INTO new_uuid; ELSE new_uuid := p_user_id; INSERT INTO users(id, name, wallet) VALUES (p_user_id, p_name, p_wallet); END IF; INSERT INTO bank_account(user_id, balance) VALUES (new_uuid, 500); INSERT INTO resource_account (resource_id, user_id, balance) SELECT resource.id, new_uuid, 50 FROM resource LEFT JOIN LATERAL (VALUES (id)) AS subquery(value) ON TRUE; RETURN new_uuid; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION get_accounts(user_id UUID) RETURNS TABLE ( id INTEGER, "primaryBalance" INTEGER, "resourceAccounts" JSON ) AS $$ BEGIN RETURN QUERY SELECT bank_account.id, bank_account.balance, json_agg( json_build_object( 'id', resource_account.id, 'resourceType', resource.name, 'balance', resource_account.balance) ORDER BY resource.name) FROM bank_account JOIN resource_account ON bank_account.user_id = resource_account.user_id JOIN resource ON resource.id = resource_account.resource_id WHERE bank_account.user_id = $1 GROUP BY bank_account.id; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION get_staking_sources(user_id UUID) RETURNS TABLE ( id INTEGER, name varchar, description varchar, resourceWells JSON, activeStakes JSON ) AS $$ BEGIN RETURN QUERY SELECT staking_source.id as id, staking_source.name, staking_source.description, json_agg( json_build_object( 'id', resource_well.id, 'resourceType', resource.name, 'supply', resource_well.supply ) ) as "resourceWells", COALESCE (json_agg( json_build_object( 'id', se.id, 'resourceType', resource.name, 'inventoryItemId', se.inventory_item_id, 'durationInMins', se.duration_in_mins, 'stakeAmount', se.stake_amount, 'startTime', se.created_at ) ) FILTER (WHERE se.id IS NOT NULL), '[]'::json) as "activeStakes" FROM staking_source INNER JOIN resource_well ON resource_well.source_id = staking_source.id INNER JOIN resource ON resource.id = resource_well.resource_id LEFT JOIN ( SELECT staking_event.id, staking_event.well_id, staking_event.created_at, duration_in_mins, stake_amount, inventory_item_id FROM staking_event LEFT JOIN claim_event ON claim_event.staking_event_id = staking_event.id WHERE claim_event.staking_event_id IS NULL ) se ON se.well_id = resource_well.id WHERE staking_source.user_id = $1 GROUP BY staking_source.id; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION create_staking_source( p_user_id UUID, p_name VARCHAR, p_description VARCHAR, p_address VARCHAR, p_cost INTEGER, p_min_res INTEGER, p_max_res INTEGER ) RETURNS INTEGER AS $$ DECLARE new_source_id INTEGER; resource_ids INTEGER[]; res_id INTEGER; BEGIN UPDATE bank_account SET balance = balance - p_cost WHERE user_id = p_user_id; INSERT INTO staking_source(user_id, name, description, address) VALUES (p_user_id, p_name, p_description, p_address) RETURNING id INTO new_source_id; SELECT array_agg(id) FROM resource INTO resource_ids; FOREACH res_id IN ARRAY resource_ids LOOP WITH random_supply AS ( SELECT FLOOR(RANDOM() * (p_max_res - p_min_res) + p_min_res) AS supply ) INSERT INTO resource_well (source_id, resource_id, supply) SELECT new_source_id, res_id, random_supply.supply FROM random_supply; END LOOP; RETURN new_source_id AS result; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION purchase_item( p_user_id UUID, p_price INTEGER, p_store_item_id TEXT ) RETURNS INTEGER AS $$ DECLARE new_item_id INTEGER; BEGIN UPDATE bank_account SET balance = balance - p_price WHERE user_id = p_user_id; INSERT INTO inventory_item (user_id, store_item_id) VALUES (p_user_id, p_store_item_id) RETURNING id INTO new_item_id; RETURN new_item_id; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION upgrade_item( p_user_id UUID, p_item_id INTEGER, p_price INTEGER ) RETURNS INTEGER AS $$ DECLARE upgrade_event_id INTEGER; item_insert_id INTEGER; BEGIN UPDATE bank_account SET balance = balance - p_price WHERE user_id = p_user_id; UPDATE inventory_item SET tier = tier + 1 WHERE inventory_item.id = p_item_id AND inventory_item.user_id = p_user_id RETURNING id INTO item_insert_id; IF item_insert_id IS NULL THEN RAISE EXCEPTION 'No matching row found in inventory_item'; END IF; INSERT INTO upgrade_event(inventory_item_id) VALUES (p_item_id) RETURNING id INTO upgrade_event_id; RETURN upgrade_event_id; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION stake( p_user_id UUID, p_well_id INTEGER, p_inventory_item_id INTEGER, p_duration INTEGER, p_stake_amount INTEGER ) RETURNS INTEGER AS $$ DECLARE staking_event_id INTEGER; actual_duration INTEGER; stake_end_time TIMESTAMP; inv_id INTEGER; stake_id INTEGER; stake_created_at TIMESTAMP; BEGIN SELECT inventory_item.id AS inv_id, staking_event.id AS stake_id, staking_event.created_at AS stake_created_at, duration_in_mins FROM inventory_item LEFT JOIN staking_event ON staking_event.inventory_item_id = inv_id WHERE inventory_item.id = p_inventory_item_id AND inventory_item.user_id = p_user_id ORDER BY stake_created_at DESC LIMIT 1 INTO inv_id, stake_id, stake_created_at, actual_duration; IF inv_id IS NULL THEN RAISE EXCEPTION SQLSTATE '90001' USING MESSAGE = 'Unable to find an inventory item that belongs to the user'; END IF; IF actual_duration IS NULL THEN actual_duration := p_duration; END IF; stake_end_time := stake_created_at + (actual_duration * INTERVAL '1 MINUTE'); IF stake_id IS NOT NULL AND NOW() AT TIME ZONE 'UTC' < stake_end_time THEN RAISE EXCEPTION SQLSTATE '90001' USING MESSAGE = 'Unable to find an inventory item that is owned and not actively staked'; END IF; INSERT INTO staking_event(user_id, well_id, inventory_item_id, duration_in_mins, stake_amount) VALUES (p_user_id, p_well_id, p_inventory_item_id, actual_duration, p_stake_amount) RETURNING id INTO staking_event_id; RETURN staking_event_id; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION get_all_stakes(p_user_id UUID) RETURNS TABLE ( id INTEGER, "sourceId" INTEGER, "wellId" INTEGER, "inventoryItemId" INTEGER, "resourceType" VARCHAR, "stakeAmount" INTEGER, "stakeTime" TIMESTAMP WITH TIME ZONE, "durationInMins" INTEGER, unclaimed BOOL ) AS $$ BEGIN RETURN QUERY SELECT staking_event.id, staking_source.id AS sourceId, resource_well.id AS wellId, inventory_item_id AS inventoryItemId, resource.name AS resourceType, stake_amount AS stakeAmount, staking_event.created_at AS stakeTime, duration_in_mins AS durationInMins, CASE WHEN claim_event.staking_event_id IS NULL THEN true ELSE false END AS unclaimed FROM staking_event INNER JOIN resource_well ON well_id = resource_well.id INNER JOIN resource ON resource.id = resource_well.resource_id INNER JOIN staking_source ON source_id = staking_source.id LEFT JOIN claim_event ON staking_event.id = claim_event.staking_event_id WHERE staking_event.user_id = p_user_id; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION claim(p_user_id UUID, p_stake_id INTEGER) RETURNS INTEGER AS $$ DECLARE stake RECORD; claim_event_id INTEGER; stake_end_time TIMESTAMP; resource_supply INTEGER; final_supply INTEGER; BEGIN SELECT staking_event.id, resource.id AS res_id, staking_event.user_id, well_id, inventory_item_id, duration_in_mins, stake_amount, created_at INTO stake FROM staking_event JOIN resource_well ON resource_well.id = well_id JOIN resource ON resource.id = resource_well.resource_id WHERE staking_event.id = p_stake_id AND staking_event.user_id = p_user_id; IF stake IS NULL THEN RAISE EXCEPTION SQLSTATE '90001' USING MESSAGE = 'Staking event not found'; END IF; IF (SELECT id FROM claim_event WHERE staking_event_id = stake.id) IS NOT NULL THEN RAISE EXCEPTION SQLSTATE '90001' USING MESSAGE = 'Stake already claimed'; END IF; stake_end_time := stake.created_at + (stake.duration_in_mins * INTERVAL '1 MINUTE'); IF NOW() AT TIME ZONE 'UTC' < stake_end_time THEN RAISE EXCEPTION SQLSTATE '90001' USING MESSAGE = 'Stake has not finished, cannot claim'; END IF; SELECT supply FROM resource_well WHERE id = stake.well_id INTO resource_supply; final_supply := CASE WHEN resource_supply > stake.stake_amount THEN stake.stake_amount ELSE resource_supply END; UPDATE resource_account SET balance = balance + final_supply WHERE user_id = p_user_id AND resource_id = stake.res_id; UPDATE resource_well SET supply = supply - final_supply WHERE resource_id = stake.res_id; INSERT INTO claim_event(staking_event_id, claim_amount) VALUES (stake.id, final_supply) RETURNING id INTO claim_event_id; RETURN claim_event_id; END; $$ LANGUAGE plpgsql;