MoonMiners/sql/tables-psql.sql
Joseph Ferano 9b753cf103 Porting database from SQLite to PostgreSQL
- New Postgres table schemas
- Using Stored Procedures with transactions that validate business logic
- User Ids now use UUID
- Updated and simplified all endpoints to call the stored procedures

Notes: There are still a few things missing that broke because of the migration,
in particular, because we moved a lot of the business logic into the database,
we now require that certain data that lived in the game-config.json to be
present in the database as well, to prevent cheating and truly have a single
source of truth.
2023-03-30 14:13:30 +07:00

96 lines
3.1 KiB
SQL

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)
);