diff --git a/.gitignore b/.gitignore index 63d8175..01ce800 100644 --- a/.gitignore +++ b/.gitignore @@ -41,3 +41,4 @@ next-env.d.ts database.db .env /sql/create-users.sql +/.dir-locals.el diff --git a/config/game-config.json b/config/game-config.json index 30e2aab..2fbc247 100644 --- a/config/game-config.json +++ b/config/game-config.json @@ -14,7 +14,7 @@ }, "store": [ { - "id": "item1", + "id": 2, "name": "LunarLite L100", "description": "LunarLite L100 is a lightweight, entry-level drill designed for beginners. With its easy-to-use interface and moderate drilling speed, it's perfect for getting started with lunar resource extraction.", "image": "/assets/drill_1.jpg", @@ -30,7 +30,7 @@ ] }, { - "id": "item2", + "id": 1, "name": "Lunar Regolith Extractor LRE-3000", "description": "The LRE-3000 is a high-efficiency drill designed for extracting regolith, the lunar soil composed of small rocks, dust, and other materials. This drill utilizes a unique auger system to bore into the moon's surface and collect regolith for further processing, ensuring minimal waste and maximum resource extraction.", "image": "/assets/drill_2.jpg", @@ -46,7 +46,7 @@ ] }, { - "id": "item3", + "id": 3, "name": "Electrostatic Dust Excavator EDE-700", "description": "The EDE-700 is a specialized excavator designed to collect fine lunar dust, which is rich in valuable elements such as helium-3, a potential fuel for future fusion reactors. The machine uses an electrostatic system to attract and capture dust particles, allowing for efficient collection and reduced risk of hazardous dust exposure for operators.", "image": "/assets/drill_3.jpg", @@ -62,7 +62,7 @@ ] }, { - "id": "item4", + "id": 4, "name": "Lunar Core Extractor LCE-360", "description": "The LCE-360 is a sophisticated drill designed to extract core samples from the moon's surface and subsurface layers. With its adjustable coring system, this machine can retrieve samples of various depths and diameters, providing valuable information about the moon's geological history and enabling efficient extraction of embedded resources.", "image": "/assets/drill_4.jpg", diff --git a/scripts/import-game-config.py b/scripts/import-game-config.py new file mode 100644 index 0000000..d120dfa --- /dev/null +++ b/scripts/import-game-config.py @@ -0,0 +1,20 @@ +import requests +import csv + +sheet_names = [ "storeitems", "stakingSources" ] + +spread_sheet_id = "1TitHE6rHFgmaRlBBLtMLarfNtp1UMzvRur4ZJ-PKhr0" + +for sheet_name in sheet_names: + url = ("https://docs.google.com/spreadsheets/d/" + + spread_sheet_id + + "/gviz/tq?tqx=out:csv&sheet=" + + sheet_name) + + response = requests.get(url) + + csv_data = response.content.decode('utf-8') + csv_reader = csv.DictReader(csv_data.splitlines(), delimiter=',') + + for row in csv_reader: + print(row) diff --git a/sql/data.sql b/sql/data.sql index d1e7c41..3dd3c3a 100644 --- a/sql/data.sql +++ b/sql/data.sql @@ -1,7 +1,8 @@ -GRANT USAGE ON SCHEMA public TO devs; -GRANT USAGE ON ALL SEQUENCES IN SCHEMA public TO devs; -GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA public TO devs; +grant usage on schema public to devs; +grant usage on all sequences in schema public to devs; +grant select, insert, update, delete on all tables in schema public to devs; +grant pg_read_server_files to devs; -INSERT INTO resource(name) -VALUES ('Sollux'), ('Shadowstone'), ('Azurium'), ('Novafor'), ('Nebulance'); +insert into resource(name) +values ('Sollux'), ('Shadowstone'), ('Azurium'), ('Novafor'), ('Nebulance'); diff --git a/sql/import-config.sql b/sql/import-config.sql new file mode 100644 index 0000000..8401ee5 --- /dev/null +++ b/sql/import-config.sql @@ -0,0 +1,151 @@ +create or replace function import_config() +returns void as $$ +begin + create temporary table if not exists storeItems( + id integer primary key, + name text not null, + description text not null, + image text not null, + claimAmount integer not null, + basePrice integer not null, + completionTimeInMins integer not null, + tier_1_price integer not null, + tier_1_claimboost integer not null, + tier_2_price integer not null, + tier_2_claimboost integer not null, + tier_3_price integer not null, + tier_3_claimboost integer not null, + tier_4_price integer not null, + tier_4_claimboost integer not null, + tier_5_price integer not null, + tier_5_claimboost integer not null + ) on commit drop; + create temporary table if not exists stakingSources( + id integer primary key, + name text not null, + description text not null, + image text not null + ) on commit drop; + create temporary table if not exists gameConstants( + key text primary key, + value float4 not null + ) on commit drop; + + perform download_sheets(); + + copy storeItems from '/tmp/storeItems.csv' with (delimiter ',', format csv, header true); + copy stakingSources from '/tmp/stakingSources.csv' (delimiter ',', format csv, header true); + copy gameConstants from '/tmp/gameConstants.csv' with (delimiter ',', format csv, header true); + + perform copy_store_items(); + + perform copy_upgrade_items(1); + perform copy_upgrade_items(2); + perform copy_upgrade_items(3); + perform copy_upgrade_items(4); + perform copy_upgrade_items(5); + + perform copy_staking_source_items(); + perform copy_game_constants(); + +end; +$$ language plpgsql; + +create or replace function copy_store_items() +returns void as $$ +begin + + insert into store_item( + id, + name, + description, + price, + image_name, + claim_amount, + completion_time_in_mins + ) + select + id, + name, + description, + basePrice, + image, + claimAmount, + completionTimeInMins + from storeItems + on conflict(id) + do update set + name = excluded.name, + description = excluded.description, + price = excluded.price, + image_name = excluded.image_name, + claim_amount = excluded.claim_amount, + completion_time_in_mins = excluded.completion_time_in_mins; + +end; +$$ language plpgsql; + +create or replace function copy_upgrade_items(p_tier integer) +returns void as $$ +begin + execute format(' + insert into upgrade_item(tier, store_item_id, price, claim_boost) + select %1$s, id, tier_%1$s_price, tier_%1$s_claimboost + from storeItems + on conflict(store_item_id, tier) do update set + price = excluded.price, + claim_boost = excluded.claim_boost; + ', p_tier); + +end; +$$ language plpgsql; + +create or replace function copy_staking_source_items() +returns void as $$ +begin + insert into staking_source_item(id, name, description, image_name) + select id, name, description, image + from stakingSources + on conflict(id) + do update set + name = excluded.name, + description = excluded.description, + image_name = excluded.image_name; +end; +$$ language plpgsql; + +create or replace function copy_game_constants() +returns void as $$ +begin + insert into game_constants(key, value) + select key, value from gameConstants + on conflict(key) do update set + value = excluded.value; +end; +$$ language plpgsql; + +create or replace function download_sheets() +returns void as $$ +import requests +import tempfile +import os + +# Download CSV file +sheet_names = [("storeItems", "0"),("stakingSources","1898988196"), ("gameConstants","583419882") ] + +spread_sheet_id = "1TitHE6rHFgmaRlBBLtMLarfNtp1UMzvRur4ZJ-PKhr0" +temp_files = [] +for (sheet_name,sheet_id) in sheet_names: + url = ("https://docs.google.com/spreadsheets/d/" + + spread_sheet_id + + "/export?format=csv&gid=" + + sheet_id) + + response = requests.get(url) + response.raise_for_status() + + # Save CSV to tmp directory file + with open(f'/tmp/{sheet_name}.csv', 'w') as f: + f.write(response.content.decode('utf-8')) + +$$ language plpython3u; diff --git a/sql/procedures.sql b/sql/procedures.sql index 8460f3f..9185c6e 100644 --- a/sql/procedures.sql +++ b/sql/procedures.sql @@ -1,43 +1,43 @@ -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 +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 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 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; + 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; + return new_uuid; +end; +$$ language plpgsql; -CREATE OR REPLACE FUNCTION get_accounts(user_id UUID) -RETURNS TABLE ( - id INTEGER, - "primaryBalance" INTEGER, - "resourceAccounts" JSON +create or replace function get_accounts(user_id uuid) +returns table ( + id uuid, + "primaryBalance" integer, + "resourceAccounts" json ) -AS $$ -BEGIN - RETURN QUERY - SELECT +as $$ +begin + return query + select bank_account.id, bank_account.balance, json_agg( @@ -45,31 +45,33 @@ BEGIN '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; + 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, +create or replace function get_staking_sources(user_id uuid) +returns table ( + id uuid, name varchar, description varchar, - resourceWells JSON, - activeStakes JSON + "imageName" text, + "resourceWells" json, + "activeStakes" json ) -AS $$ -BEGIN - RETURN QUERY - SELECT +as $$ +begin + return query + select staking_source.id as id, staking_source.name, staking_source.description, + staking_source.image_name, json_agg( json_build_object( 'id', resource_well.id, @@ -86,242 +88,263 @@ BEGIN '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, + ) 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; + 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; +create or replace function create_staking_source(p_user_id uuid) +returns uuid +as $$ +declare + source_item record; + new_source_id uuid; + res_id integer; + address varchar; + price integer; + min_res integer; + max_res integer; +begin + select value into price from game_constants where key = 'price'; - 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; + update bank_account set balance = balance - price where user_id = p_user_id; - SELECT array_agg(id) FROM resource INTO resource_ids; + 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; + select value into min_res from game_constants where key = 'resourceMinStartAmount'; + select value into max_res from game_constants where key = 'resourceMaxStartAmount'; - 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; + insert into staking_source(user_id, name, description, image_name, address) + values ( + p_user_id, + source_item.name, + source_item.description, + source_item.image_name, + '0x' || address + ) + returning id into new_source_id; -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; + insert into resource_well (source_id, resource_id, supply) + select new_source_id, resource.id, random_supply + from resource, + (select floor(random() * (max_res - min_res) + min_res) as random_supply) + subquery + left join lateral (values(id)) subquery2(value) on true; -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; + return new_source_id as result; +end; +$$ language plpgsql; - IF item_insert_id IS NULL THEN - RAISE EXCEPTION 'No matching row found in inventory_item'; - END IF; +create or replace function purchase_item( + p_user_id uuid, + p_store_item_id integer +) returns uuid +as $$ +declare + new_item_id uuid; + 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; + return new_item_id; +end; +$$ language plpgsql; - 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 upgrade_item( + p_user_id uuid, + p_item_id uuid +) returns uuid +as $$ +declare + upgrade_event_id uuid; + 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; -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 + update bank_account set balance = balance - upgrade_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; - 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 item_insert_id is null then + raise exception 'No matching row found in inventory_item'; + end if; - 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; + insert into upgrade_event(inventory_item_id) values (p_item_id) returning id into upgrade_event_id; + return upgrade_event_id; - IF actual_duration IS NULL THEN - actual_duration := p_duration; - END IF; +end; +$$ language plpgsql; - stake_end_time := stake_created_at + (actual_duration * INTERVAL '1 MINUTE'); +create or replace function stake( + p_user_id uuid, + p_well_id uuid, + p_inventory_item_id uuid +) returns uuid +as $$ +declare + staking_event_id uuid; + item_stake_duration integer; + stake_end_time timestamp; + inv_id uuid; + stake_id uuid; + stake_created_at timestamp; + stake_amount integer; +begin + select completion_time_in_mins + into item_stake_duration + from inventory_item + join store_item on inventory_item.store_item_id = store_item.id + where inventory_item.id = p_inventory_item_id; - 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; + select + inventory_item.id as inv_id, + staking_event.id as stake_id, + staking_event.created_at as stake_created_at + 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; - 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; + 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; - RETURN staking_event_id; -END; -$$ LANGUAGE plpgsql; + stake_end_time := stake_created_at + (item_stake_duration * interval '1 minute'); -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 + 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; + + select claim_amount + claim_boost + into stake_amount + 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 + and upgrade_item.tier = inventory_item.tier + where inventory_item.id = p_inventory_item_id; + + 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, 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 uuid, + "sourceId" uuid, + "wellId" uuid, + "inventoryItemId" uuid, + "resourceType" varchar, + "stakeAmount" integer, + "stakeTime" timestamp with time zone, + "durationInMins" integer, + unclaimed bool ) -AS $$ -BEGIN - RETURN QUERY - SELECT +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; + 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 +create or replace function claim(p_user_id uuid, p_stake_id uuid) +returns uuid +as $$ +declare + stake record; + claim_event_id uuid; + stake_end_time timestamp; + resource_supply integer; + final_supply integer; +begin + select staking_event.id, - resource.id AS res_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; + 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 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; + 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'); + 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; + 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; + 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; + 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_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; + 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; + 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; + return claim_event_id; +end; +$$ language plpgsql; diff --git a/sql/queries-psql.sql b/sql/queries-psql.sql deleted file mode 100644 index f9e6ed8..0000000 --- a/sql/queries-psql.sql +++ /dev/null @@ -1,89 +0,0 @@ -select * from users; - -select * from resource; - -select * from resource_account; - -select * from bank_account; - -select * from resource_account -join users on resource_account.user_id = users.id -join resource on resource.id = resource_account.resource_id -where users.name = 'Harry'; - -select * from bank_account where user_id = 'c40ef029-9c31-4bf8-8bb4-d6f63caeb351'; - -delete from users where id = 'c40ef029-9c31-4bf8-8bb4-d6f63caeb351'; - -select * from get_accounts( 'c40ef029-9c31-4bf8-8bb4-d6f63caeb351'); - -update bank_account set balance = 1200 from users where bank_account.user_id = users.id AND name = 'Joe'; - -select * from inventory_item; - -select * from upgrade_event; - -delete from upgrade_event; - -update inventory_item set tier = 0; - -select * from staking_event; - -update staking_event set created_at = '2023-03-30 05:05:39.696926+00'; - -select * from claim_event; - -delete from claim_event; - - - --- Grab a user's bank account plus their resource accounts -EXPLAIN ANALYZE -SELECT - bank_account.id as bank_account_id, - bank_account.balance as primary_balance, - json_agg(json_build_object('resourceType', resource.name, 'balance', resource_account.balance)) as resource_accounts -FROM bank_account -JOIN resource_account ON bank_account.user_id = resource_account.user_id -JOIN resource ON resource.id = resource_account.resource_id -JOIN users ON bank_account.user_id = users.id -WHERE users.name = 'Joe' -GROUP BY bank_account.id; - - --- Grab a user's bank account plus their resource accounts -EXPLAIN ANALYZE -SELECT - bank_account.id as bank_account_id, - bank_account.balance as primary_balance, - resname as resourceType, - resource_account.balance, - resource_account.id as resId -FROM bank_account -JOIN resource_account ON 1 = resource_account.user_id -WHERE bank_account.user_id = 1; - --- Grab a staking source with all its resource wells and active stakes -SELECT - staking_source.id as id, name, description, - json_agg( - json_build_object( - 'id', resource_well.id, 'resouceType', resource_well.resname, 'supply', supply )) as "resourceWells", - json_agg( - json_build_object( - 'id', staking_event.id, 'resouceType', resource_well.resname, 'startTime', staking_event.created_at)) as "activeStakes" -FROM staking_source -INNER JOIN resource_well ON resource_well.source_id = staking_source.id -INNER JOIN staking_event ON staking_event.well_id = resource_well.id -WHERE staking_source.user_id = 1 -GROUP BY staking_source.id; - -SELECT - inventory_item.id AS inv_id, - staking_event.id AS stake_id, - staking_event.created_at AS stake_created_at -FROM inventory_item -LEFT JOIN staking_event ON inventory_item_id = inventory_item.id -WHERE inventory_item.id = 1 AND inventory_item.user_id = 1 -ORDER BY stake_created_at DESC -LIMIT 1; diff --git a/sql/queries.sql b/sql/queries.sql index d8418ff..325e4c5 100644 --- a/sql/queries.sql +++ b/sql/queries.sql @@ -1,73 +1,66 @@ --- Give extra moon bucks +select * from users; -UPDATE bank_account SET balance = 100 WHERE user_id = 1; -SELECT * FROM bank_account WHERE user_id = 1; +select * from resource; --- -SELECT staking_event.id,well_id,staking_event.source_id, - inventory_item_id,staking_event.created_at,expiration_at -FROM staking_event -INNER JOIN resource_well ON resource_well.id = well_id -INNER JOIN staking_source on staking_event.source_id = staking_source.id -WHERE staking_event.source_id = ? AND staking_source.user_id = ?; +select * from resource_account; -SELECT name,init_supply -FROM resource_well -INNER JOIN resource ON resource.id = resource_well.resource_id -WHERE source_id = 1; +select * from bank_account; -SELECT inventory_item.id,store_item_id, COUNT(upgrade_event.id) as upgrades -FROM inventory_item -LEFT JOIN upgrade_event ON inventory_item.id = upgrade_event.inventory_item_id -WHERE inventory_item.user_id = 1 -GROUP BY inventory_item.id; +select * from resource_account +join users on resource_account.user_id = users.id +join resource on resource.id = resource_account.resource_id +where users.name = 'Harry'; -SELECT inventory_item.id,store_item_id -FROM inventory_item; +update bank_account +set balance = 2000 +from users +where bank_account.user_id = users.id and name = 'Joe'; -SELECT staking_event.id,well_id,staking_event.source_id, - inventory_item_id,staking_event.created_at,expiration_at -FROM staking_event -INNER JOIN staking_source on staking_event.source_id = staking_source.id -WHERE staking_event.source_id = 4 AND staking_source.user_id = 1; +select * from staking_source; +select * from resource_well; -SELECT staking_event.id, staking_event.well_id, staking_event.source_id, - staking_event.inventory_item_id, staking_event.duration_in_mins, - staking_event.created_at -FROM staking_event -LEFT JOIN claim_event ON staking_event.id = claim_event.staking_event_id -WHERE staking_event.source_id = 4 AND claim_event.staking_event_id IS NULL; +select * from inventory_item; -UPDATE staking_event SET created_at = '2023-03-16 09:39:37' WHERE id = 3; +select * from upgrade_event; -SELECT staking_event.id, staking_source.id as sourceId, resname as resourceType, - inventory_item_id, duration_in_mins, stake_amount, staking_event.created_at, - CASE WHEN claim_event.staking_event_id IS NULL THEN 1 ELSE 0 END AS unclaimed -FROM staking_event -INNER JOIN resource_well ON well_id = resource_well.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 = 1; +delete from upgrade_event; -SELECT resource_account.id, resource_id,resource.name,balance -FROM resource_account -INNER JOIN resource ON resource_id = resource.id -WHERE user_id = 1; +update inventory_item set tier = 0; -SELECT staking_source.id as sourceId,resource_well.id as wellId,resname,supply FROM resource_well -INNER JOIN staking_source ON staking_source.id = resource_well.source_id -WHERE staking_source.user_id = 1; +select * from staking_event; -SELECT inventory_item.id, tier, store_item_id, - CASE WHEN claim_event.staking_event_id IS NULL THEN 0 ELSE 1 END AS staking -FROM inventory_item -LEFT JOIN staking_event ON inventory_item_id = inventory_item.id -LEFT JOIN claim_event ON staking_event.id = claim_event.staking_event_id -WHERE inventory_item.id = 3; +update staking_event set created_at = '2023-03-30 05:05:39.696926+00' +where id = 'e53ef75e-fbb8-453f-a55c-758683bb0bb4'; + +select * from claim_event; + +delete from claim_event; + +alter table store_item alter column price type integer using price::integer; + +-- Import config from google sheets +drop table test_csv_import; + +create table test_csv_import ( + id integer, + name text, + description text, + image text, + claimAmount int, + completionTimeInMins int, + tier1price int, + tier1claimboost int, + tier2price int, + tier2claimboost int, + tier3price int, + tier3claimboost int, + tier4price int, + tier4claimboost int, + tier5price int, + tier5claimboost int +); + +\copy test_csv_import from '../storeitems.csv' delimiter ',' csv header; + +select * from test_csv_import; -SELECT inventory_item.id, tier, store_item_id, staking_event.id as stakeId, - staking_event.created_at as stakeTime, duration_in_mins, stake_amount -FROM inventory_item -LEFT JOIN staking_event ON inventory_item_id = inventory_item.id -WHERE inventory_item.store_item_id = 'item3' AND user_id = 1 -ORDER BY staking_event.created_at DESC; diff --git a/sql/tables-psql.sql b/sql/tables-psql.sql deleted file mode 100644 index 54410b1..0000000 --- a/sql/tables-psql.sql +++ /dev/null @@ -1,95 +0,0 @@ -CREATE TABLE users ( - id UUID PRIMARY KEY DEFAULT gen_random_uuid(), - wallet varchar(64), - name varchar(32) not null -); - -CREATE TABLE resource ( - id serial primary key, - name varchar(32) not null unique -); - -CREATE TABLE staking_source ( - id serial primary key, - name varchar not null, - description varchar not null, - user_id UUID not null, - address varchar(128) not null, - created_at timestamp with time zone default timezone('UTC', now()), - CONSTRAINT fk_user_staking_source FOREIGN KEY(user_id) - REFERENCES users(id) ON DELETE CASCADE -); - -CREATE TABLE resource_well ( - id serial primary key, - resource_id integer not null, - source_id integer not null, - supply integer not null, - CONSTRAINT fk_sid_resource_well FOREIGN KEY(source_id) - REFERENCES staking_source(id) ON DELETE CASCADE, - CONSTRAINT fk_rid_resource_well FOREIGN KEY(resource_id) - REFERENCES resource(id) -); - -CREATE TABLE inventory_item ( - id serial primary key, - user_id UUID not null, - tier integer not null default 0, - store_item_id varchar not null, - created_at timestamp with time zone default timezone('UTC', now()), - CONSTRAINT fk_user_inventory_item FOREIGN KEY(user_id) - REFERENCES users(id) ON DELETE CASCADE - CONSTRAINT uk_user_store_item UNIQUE (user_id, store_item_id) -); - -CREATE TABLE upgrade_event ( - id serial primary key, - inventory_item_id integer not null, - created_at timestamp with time zone default timezone('UTC', now()), - CONSTRAINT fk_iid_upgrade_event FOREIGN KEY(inventory_item_id) - REFERENCES inventory_item(id) -); - -CREATE TABLE staking_event ( - id serial primary key, - user_id UUID not null, - well_id integer not null, - inventory_item_id integer not null, - duration_in_mins integer not null, - stake_amount integer not null, - created_at timestamp with time zone default timezone('UTC', now()), - CONSTRAINT fk_user_staking_event FOREIGN KEY(user_id) - REFERENCES users(id) ON DELETE CASCADE, - CONSTRAINT fk_wid_staking_event FOREIGN KEY(well_id) - REFERENCES resource_well(id), - CONSTRAINT fk_iiid_staking_event FOREIGN KEY(inventory_item_id) - REFERENCES inventory_item(id) -); - -CREATE TABLE claim_event ( - id serial primary key, - staking_event_id integer not null, - claim_amount integer not null, - created_at timestamp with time zone default timezone('UTC', now()), - CONSTRAINT fk_se_claim_event FOREIGN KEY(staking_event_id) - REFERENCES staking_event(id) ON DELETE CASCADE -); - -CREATE TABLE bank_account ( - id serial primary key, - user_id UUID not null, - balance integer not null default 0 CHECK (balance >= 0), - CONSTRAINT fk_user_bank_account FOREIGN KEY(user_id) - REFERENCES users(id) ON DELETE CASCADE -); - -CREATE TABLE resource_account ( - id serial primary key, - resource_id integer not null, - user_id UUID not null, - balance integer not null default 0 CHECK (balance >= 0), - CONSTRAINT fk_user_resource_account FOREIGN KEY(user_id) - REFERENCES users(id) ON DELETE CASCADE, - CONSTRAINT fk_rid_resource_account FOREIGN KEY(resource_id) - REFERENCES resource(id) -); diff --git a/sql/tables-sqlite.sql b/sql/tables-sqlite.sql deleted file mode 100644 index 433483d..0000000 --- a/sql/tables-sqlite.sql +++ /dev/null @@ -1,88 +0,0 @@ -PRAGMA foreign_keys = ON; - -CREATE TABLE users ( - id integer primary key autoincrement, - wallet varchar, - name varchar(32) not null -); - -CREATE TABLE staking_source( - id integer primary key autoincrement, - name varchar not null, - description varchar not null, - user_id int not null, - address varchar(128) not null, - created_at timestamp DEFAULT (current_timestamp || 'Z'), - CONSTRAINT fk_user FOREIGN KEY(user_id) - REFERENCES users(id) -); - -CREATE TABLE resource_well( - id integer primary key autoincrement, - resname varchar not null, - source_id int not null, - supply int not null, - CONSTRAINT fk_sid FOREIGN KEY(source_id) - REFERENCES staking_source(id) - ON DELETE CASCADE -); - -CREATE TABLE inventory_item( - id integer primary key autoincrement, - user_id int not null, - tier int not null default 0, - store_item_id varchar not null unique, - created_at timestamp DEFAULT (current_timestamp || 'Z'), - CONSTRAINT fk_user FOREIGN KEY(user_id) - REFERENCES users(id) -); - -CREATE TABLE upgrade_event( - id integer primary key autoincrement, - inventory_item_id int not null, - created_at timestamp DEFAULT (current_timestamp || 'Z'), - CONSTRAINT fk_iid FOREIGN KEY(inventory_item_id) - REFERENCES inventory_item(id) -); - -CREATE TABLE staking_event( - id integer primary key autoincrement, - user_id int not null, - well_id int not null, - inventory_item_id int not null, - duration_in_mins int not null, - stake_amount int not null, - created_at timestamp DEFAULT (current_timestamp || 'Z'), - CONSTRAINT fk_user FOREIGN KEY(user_id) - REFERENCES users(id) - CONSTRAINT fk_wid FOREIGN KEY(well_id) - REFERENCES resource_well(id) - CONSTRAINT fk_iiid FOREIGN KEY(inventory_item_id) - REFERENCES inventory_item(id) -); - -CREATE TABLE claim_event( - id integer primary key autoincrement, - staking_event_id int not null, - claim_amount int not null, - created_at timestamp DEFAULT (current_timestamp || 'Z'), - CONSTRAINT fk_se_id FOREIGN KEY(staking_event_id) - REFERENCES staking_event(id) -); - -CREATE TABLE bank_account( - id integer primary key autoincrement, - user_id int not null, - balance int not null default 0 CHECK (balance >= 0), - CONSTRAINT fk_user FOREIGN KEY(user_id) - REFERENCES users(id) -); - -CREATE TABLE resource_account( - id integer primary key autoincrement, - resname varchar not null, - user_id int not null, - balance int not null default 0 CHECK (balance >= 0), - CONSTRAINT fk_user FOREIGN KEY(user_id) - REFERENCES users(id) -); diff --git a/sql/tables.sql b/sql/tables.sql new file mode 100644 index 0000000..4997edd --- /dev/null +++ b/sql/tables.sql @@ -0,0 +1,130 @@ +create table users ( + id uuid primary key default gen_random_uuid(), + wallet varchar(64), + name varchar(32) not null +); + +create table resource ( + id serial primary key, + name varchar(32) not null unique +); + +create table game_constants( + key text primary key, + value float4 not null +); + +create table store_item( + id integer primary key, + name text not null, + description text not null, + price integer not null, + image_name text not null, + claim_amount integer not null, + completion_time_in_mins integer not null +); + +create table upgrade_item( + tier integer not null, + store_item_id integer not null, + price text not null, + claim_boost integer not null, + constraint fk_store_item_upgrade_item foreign key(store_item_id) + references store_item(id) on delete cascade, + primary key (store_item_id, tier) +); + +create table staking_source_item ( + id integer primary key, + name text not null, + description text not null, + image_name text not null +); + +create table staking_source ( + id uuid primary key default gen_random_uuid(), + name varchar not null, + description varchar not null, + image_name text not null, + user_id uuid not null, + address varchar(128) not null, + created_at timestamp with time zone default timezone('utc', now()), + constraint fk_user_staking_source foreign key(user_id) + references users(id) on delete cascade +); + +create table resource_well ( + id uuid primary key default gen_random_uuid(), + resource_id integer not null, + source_id uuid not null, + supply integer not null, + constraint fk_sid_resource_well foreign key(source_id) + references staking_source(id) on delete cascade, + constraint fk_rid_resource_well foreign key(resource_id) + references resource(id) +); + +create table inventory_item ( + id uuid primary key default gen_random_uuid(), + user_id uuid not null, + tier integer not null default 0, + store_item_id int not null, + created_at timestamp with time zone default timezone('utc', now()), + constraint fk_user_inventory_item foreign key(user_id) + references users(id) on delete cascade, + constraint fk_store_item_inventory_item foreign key(store_item_id) + references store_item(id) on delete cascade, + constraint uk_user_store_item unique (user_id, store_item_id) +); + +create table upgrade_event ( + id uuid primary key default gen_random_uuid(), + inventory_item_id uuid not null, + created_at timestamp with time zone default timezone('utc', now()), + constraint fk_iid_upgrade_event foreign key(inventory_item_id) + references inventory_item(id) +); + +create table staking_event ( + id uuid primary key default gen_random_uuid(), + user_id uuid not null, + well_id uuid not null, + inventory_item_id uuid not null, + duration_in_mins integer not null, + stake_amount integer not null, + created_at timestamp with time zone default timezone('utc', now()), + constraint fk_user_staking_event foreign key(user_id) + references users(id) on delete cascade, + constraint fk_wid_staking_event foreign key(well_id) + references resource_well(id), + constraint fk_iiid_staking_event foreign key(inventory_item_id) + references inventory_item(id) +); + +create table claim_event ( + id uuid primary key default gen_random_uuid(), + staking_event_id uuid not null, + claim_amount integer not null, + created_at timestamp with time zone default timezone('utc', now()), + constraint fk_se_claim_event foreign key(staking_event_id) + references staking_event(id) on delete cascade +); + +create table bank_account ( + id uuid primary key default gen_random_uuid(), + user_id uuid not null, + balance integer not null default 0 check (balance >= 0), + constraint fk_user_bank_account foreign key(user_id) + references users(id) on delete cascade +); + +create table resource_account ( + id uuid primary key default gen_random_uuid(), + resource_id integer not null, + user_id uuid not null, + balance integer not null default 0 check (balance >= 0), + constraint fk_user_resource_account foreign key(user_id) + references users(id) on delete cascade, + constraint fk_rid_resource_account foreign key(resource_id) + references resource(id) +); diff --git a/src/app/Components/Accounts/Account.tsx b/src/app/Components/Accounts/Account.tsx index 5243733..fc2468e 100644 --- a/src/app/Components/Accounts/Account.tsx +++ b/src/app/Components/Accounts/Account.tsx @@ -22,7 +22,7 @@ const ResourceAccount = (props: { }; setConversionPair(updatedPair); }; - console.log(conversionPair); + return ( <> {showModal && ( diff --git a/src/pages/api/test.ts b/src/pages/api/import-config.ts similarity index 51% rename from src/pages/api/test.ts rename to src/pages/api/import-config.ts index 7c802c7..47fab94 100644 --- a/src/pages/api/test.ts +++ b/src/pages/api/import-config.ts @@ -6,11 +6,15 @@ export default async function handler( res: NextApiResponse ) { try { - if (req.method === "GET") { + if (req.method === "POST") { const db = postgresConnection; - const a = await db.query("SELECT * FROM users"); - console.log(a.rows); - res.status(200).json(a.rows); + const result = await db.query("select import_config();"); + + if (result.rowCount > 0) { + return res.status(200).json({ userId: result.rows[0].id}); + } else { + return res.status(404).json({ message: "User not found" }); + } } } catch (error) { res.status(500).json(error); diff --git a/src/pages/api/user/[userId]/inventory-items.ts b/src/pages/api/user/[userId]/inventory-items.ts index abea4ba..b1f15cc 100644 --- a/src/pages/api/user/[userId]/inventory-items.ts +++ b/src/pages/api/user/[userId]/inventory-items.ts @@ -26,15 +26,9 @@ export default async function handler( const { userId } = req.query; const { storeItemId } = req.body; - const storeItem = gameConfig.store.find((item) => item.id == storeItemId); - - if (storeItem == undefined) { - return res.status(400).json({ error: "Item does not exist" }); - } - const itemPrice = storeItem.price; // TODO: Split the try catch to report already owned item error try { - const result = await db.query("select purchase_item($1, $2, $3)", [userId, itemPrice, storeItemId]); + const result = await db.query("select purchase_item($1, $2)", [userId, storeItemId]); return res.status(200).json({ "newItemId": result.rows[0].purchase_item}); } catch (error) { // TODO: Need to add better error handling when the user dodn't have enough money @@ -45,30 +39,10 @@ export default async function handler( // Upgrade an existing item const { userId } = req.query; - // TODO: We cannot trust the client to provide us with this info - const { inventoryItemId, storeItemId } = req.body; - - const storeItem = gameConfig.store.find((item) => item.id == storeItemId); - - if (storeItem == undefined) { - return res.status(400).json({ error: "Item does not exist" }); - } - - // TODO: We don't have this data here - // const tier = storeItem.tier; - const tier = 1; - if (tier == undefined) { - return res.status(400).json({ error: "Item does not exist" }); - } - if (tier >= storeItem.upgrades.length) { - return res.status(400).json({ error: "Max upgrade reached" }); - } - - const upgradePrice = storeItem.upgrades[tier].price; + const { inventoryItemId } = req.body; try { - const result = await db.query("SELECT upgrade_item($1, $2, $3)", - [userId, inventoryItemId, upgradePrice]); + const result = await db.query("SELECT upgrade_item($1, $2)", [userId, inventoryItemId]); return res.status(200).json({ message: `Upgraded item ${inventoryItemId}`, upgradeEventId: result.rows[0].upgrade_item}); } catch (error) { diff --git a/src/pages/api/user/[userId]/stakes/start.ts b/src/pages/api/user/[userId]/stakes/start.ts index acf2032..f2bf540 100644 --- a/src/pages/api/user/[userId]/stakes/start.ts +++ b/src/pages/api/user/[userId]/stakes/start.ts @@ -15,25 +15,17 @@ export default async function handler( const { userId } = req.query; const { inventoryItemId, - storeItemId, wellId } = req.body; - console.log(`Start take: inventoryItemId: ${inventoryItemId} | wellId: ${wellId}`) + const db = postgresConnection; try { - const item = gameConfig.store.find((i) => i.id == storeItemId); - if (item == undefined) { - return res.status(400).json({ error: "A resource was not found" }); - } - const result = - await db.query("SELECT * FROM stake($1, $2, $3, $4, $5) AS stake", + await db.query("SELECT * FROM stake($1, $2, $3) AS stake", [ userId, wellId, - inventoryItemId, - item.completionTimeInMins, - item.claimAmount]); + inventoryItemId]); return res.status(200).json({stakingEventId: result.rows[0].stake}); diff --git a/src/pages/api/user/[userId]/staking-sources.ts b/src/pages/api/user/[userId]/staking-sources.ts index 8f75d75..485595e 100644 --- a/src/pages/api/user/[userId]/staking-sources.ts +++ b/src/pages/api/user/[userId]/staking-sources.ts @@ -24,8 +24,9 @@ export default async function handler( id: row[0], name: row[1], description: row[2], - resourceWells: row[3], - activeStakes: row[4] + image: row[3], + resourceWells: row[4], + activeStakes: row[5] }; }); return res.status(200).json({ "stakingSources": stakingSources }); @@ -34,22 +35,7 @@ export default async function handler( const { userId } = req.query; try { - const randomName = "Moon 1"; - const randomDesc = "This is a moon orbiting Selene's planet"; - const randomAddr = "0x" + generateRandomBase64String(16); - const resMax = gameConfig.moons.resourceMaxStartAmount; - const resMin = gameConfig.moons.resourceMinStartAmount; - const moonPrice = gameConfig.moons.price; - - const result = await db.query( - "SELECT * FROM create_staking_source($1, $2, $3, $4, $5, $6, $7)", - [ userId, - randomName, - randomDesc, - randomAddr, - moonPrice, - resMin, - resMax ]); + const result = await db.query("SELECT * FROM create_staking_source($1)", [ userId ]); if (result.rows.length > 0) { return res.status(200).json({"stakingSourceId": result.rows[0].create_staking_source}); diff --git a/test-endpoints.restclient b/test-endpoints.restclient index 278fbc0..a2d4c9d 100644 --- a/test-endpoints.restclient +++ b/test-endpoints.restclient @@ -3,10 +3,14 @@ Content-Type: application/json # :user_id = 595ab570-fa74-4c6c-980e-4c80d1064dd1 -# Get Inventory Items +# Seed the SQLite database (deprecated) GET http://localhost:3000/api/seed :headers +# Call the import_config() stored procedure +POST http://localhost:3000/api/import-config +:headers + # Get Inventory Items POST http://localhost:3000/api/user/login :headers @@ -31,12 +35,12 @@ GET http://localhost:3000/api/user/:user_id/inventory-items # Buy a new Item POST http://localhost:3000/api/user/:user_id/inventory-items/ :headers -{ "storeItemId" : "item1" } +{ "storeItemId" : 1 } # Upgrade an owned item PUT http://localhost:3000/api/user/:user_id/inventory-items/ :headers -{ "storeItemId" : "item3", "inventoryItemId": 3 } +{ "inventoryItemId": "26e4b397-2b01-4c73-a14e-4ea4ae3ec1a5" } # Get stakes GET http://localhost:3000/api/user/:user_id/stakes/ @@ -45,9 +49,10 @@ GET http://localhost:3000/api/user/:user_id/stakes/ # Start a stake POST http://localhost:3000/api/user/:user_id/stakes/start :headers -{ "inventoryItemId": 3, "storeItemId": "item3", "wellId": 1 } +{ "inventoryItemId": "26e4b397-2b01-4c73-a14e-4ea4ae3ec1a5" + , "wellId": "ea4ad43c-d153-4fd4-819d-3c0339102d1e" } # Claim a stake POST http://localhost:3000/api/user/:user_id/stakes/claim :headers -{ "stakingEventId" : 3 } \ No newline at end of file +{ "stakingEventId" : "e53ef75e-fbb8-453f-a55c-758683bb0bb4" } \ No newline at end of file diff --git a/typings.d.ts b/typings.d.ts index 7595872..993f0e9 100644 --- a/typings.d.ts +++ b/typings.d.ts @@ -55,7 +55,7 @@ export interface IUpgrade { } export interface IStoreItem { - id: string; + id: number; name: string; description: string; image: string, @@ -154,4 +154,4 @@ export interface IChart { label: string labels: string[] values: number[] -} \ No newline at end of file +}