From b9390c18ab59b9e196fed4bf260bb4fb34d3c8e5 Mon Sep 17 00:00:00 2001 From: Joseph Ferano Date: Fri, 21 Apr 2023 18:23:11 +0700 Subject: [PATCH] Add some additional checking and clearer error messages to sql functions --- .gitignore | 1 + sql/procedures.sql | 60 +++++++++++++++++++---- src/pages/api/user/[userId]/clear-data.ts | 2 +- 3 files changed, 52 insertions(+), 11 deletions(-) diff --git a/.gitignore b/.gitignore index 6a97f6f..eae272c 100644 --- a/.gitignore +++ b/.gitignore @@ -43,3 +43,4 @@ database.db /sql/create-users.sql /.dir-locals.el sql/queries.sql +/project.todo diff --git a/sql/procedures.sql b/sql/procedures.sql index 79c7b47..c768844 100644 --- a/sql/procedures.sql +++ b/sql/procedures.sql @@ -87,6 +87,7 @@ begin select id from resource where name = resource_name ); exception + -- TODO: Test this out to see if it is properly returned when others then sale_result := 'Error: Insufficient amount'; end; @@ -223,7 +224,12 @@ declare begin select value into price from game_constants where key = 'price'; - update bank_account set balance = balance - price where user_id = p_user_id; + begin + update bank_account set balance = balance - price where user_id = p_user_id; + exception + when check_violation then + raise exception 'Insufficient funds'; + end; select * into source_item from staking_source_item order by random() limit 1; select substr(md5(random()::text), 1, 16) AS random_string into address; @@ -280,9 +286,22 @@ declare item_price integer; begin select price into item_price from store_item where store_item.id = p_store_item_id; - update bank_account set balance = balance - item_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; + + begin + update bank_account set balance = balance - item_price where user_id = p_user_id; + exception + when check_violation then + raise exception 'Insufficient funds'; + end; + + begin + insert into inventory_item (user_id, store_item_id) values (p_user_id, p_store_item_id) + returning id into new_item_id; + exception + when unique_violation then + raise exception 'User already owns this weapons'; + end; + return new_item_id; end; $$ language plpgsql; @@ -297,19 +316,30 @@ declare item_insert_id uuid; upgrade_price integer; begin + select upgrade_item.price into upgrade_price from inventory_item join store_item on inventory_item.store_item_id = store_item.id join upgrade_item on store_item.id = upgrade_item.store_item_id where inventory_item.id = p_item_id and upgrade_item.tier = inventory_item.tier + 1; - update bank_account set balance = balance - upgrade_price where user_id = p_user_id; + if upgrade_price is null then + raise exception 'Inventory item not found'; + end if; + + begin + update bank_account set balance = balance - upgrade_price where user_id = p_user_id; + exception + when check_violation then + raise exception 'Insufficient funds'; + end; + 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'; + raise exception 'Inventory item does not belong to the user'; end if; insert into upgrade_event(inventory_item_id) values (p_item_id) returning id into upgrade_event_id; @@ -332,7 +362,9 @@ declare stake_id uuid; stake_created_at timestamp; total_stake_amount integer; + found_resource_well_id uuid; begin + select completion_time_in_mins into item_stake_duration from inventory_item @@ -351,15 +383,13 @@ begin into inv_id, stake_id, stake_created_at; if inv_id is null then - raise exception sqlstate '90001' - using message = 'Unable to find an inventory item that belongs to the user'; + raise exception 'Unable to find an inventory item that belongs to the user'; end if; stake_end_time := stake_created_at + (item_stake_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'; + raise exception 'Unable to find an inventory item that is owned and not actively staked'; end if; select claim_amount @@ -370,6 +400,16 @@ begin and upgrade_item.tier = inventory_item.tier where inventory_item.id = p_inventory_item_id; + select resource_well.id + into found_resource_well_id + from resource_well + join staking_source on source_id = staking_source.id + where user_id = p_user_id and resource_well.id = p_well_id; + + if not found then + raise exception 'Resource well does not belong to this user'; + 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, item_stake_duration, total_stake_amount) returning id into staking_event_id; diff --git a/src/pages/api/user/[userId]/clear-data.ts b/src/pages/api/user/[userId]/clear-data.ts index 1adb7dd..10352d4 100644 --- a/src/pages/api/user/[userId]/clear-data.ts +++ b/src/pages/api/user/[userId]/clear-data.ts @@ -12,7 +12,7 @@ export default async function handler( const db = postgresConnection; const result = await db.query("select clear_user_data($1)", [userId]); - console.log(result); + if (result.rowCount > 0) { return res.status(200).json({message: "Success!"}); } else {