From aa35a1f4a65ded2c997f4066d001074b76709b94 Mon Sep 17 00:00:00 2001 From: Ashelyn Dawn Date: Sat, 15 Feb 2020 18:50:21 -0700 Subject: [PATCH] Completed tables, validated constraints --- db/sql/0-setup.sql | 1 + db/sql/1-tables.sql | 120 ++++++++++++++++++++++++++++++++++++++------ 2 files changed, 106 insertions(+), 15 deletions(-) diff --git a/db/sql/0-setup.sql b/db/sql/0-setup.sql index 167055c..91f4da5 100644 --- a/db/sql/0-setup.sql +++ b/db/sql/0-setup.sql @@ -1,6 +1,7 @@ CREATE database sos; create user sos with encrypted password 'password'; grant all privileges on database sos to sos; +GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO sos; create extension if not exists "uuid-ossp"; CREATE EXTENSION IF NOT EXISTS citext; diff --git a/db/sql/1-tables.sql b/db/sql/1-tables.sql index 4f15aab..998abc3 100644 --- a/db/sql/1-tables.sql +++ b/db/sql/1-tables.sql @@ -1,6 +1,8 @@ create type "delivery_type_enum" as enum ('hand_shipped', 'easypost', 'hand_delivered'); create type "transaction_state_enum" as enum ('started', 'completed', 'cancelled', 'expired'); -create type "payment_state_enum" as enum ('ks_reward', 'stripe', 'paypal', 'account_credit'); +create type "payment_type_enum" as enum ('ks_reward', 'stripe', 'paypal', 'account_credit'); +create type "stockchange_type_enum" as enum ('purchase', 'shipment', 'admin'); +create type "stock_change_dir_enum" as enum ('added', 'subtracted'); create table "user" ( user_uuid uuid primary key default uuid_generate_v4(), @@ -39,8 +41,10 @@ create table "session" ( create table "item" ( item_uuid uuid primary key default uuid_generate_v4(), item_name text not null, + item_description text not null, item_urlslug citext unique not null, - item_price_cents integer not null + item_price_cents integer not null, + item_published boolean not null default true ); create table "cart_item" ( @@ -51,6 +55,24 @@ create table "cart_item" ( cart_item_time_added timestamptz not null default now() ); +create table "category" ( + category_uuid uuid primary key default uuid_generate_v4(), + category_name text not null, + category_urlslug citext unique not null +); + +create table "category_item" ( + category_item_uuid uuid primary key default uuid_generate_v4(), + category_item_item_uuid uuid not null references "item" (item_uuid), + category_item_category_uuid uuid not null references "category" (category_uuid) +); + +create table "category_category" ( + category_category_uuid uuid primary key default uuid_generate_v4(), + category_category_parent_uuid uuid not null references "category" (category_uuid), + category_category_child_uuid uuid not null references "category" (category_uuid) +); + create table "address" ( address_uuid uuid primary key default uuid_generate_v4(), address_name text not null, @@ -73,7 +95,7 @@ create table "delivery" ( create table "delivery_hand_shipped" ( delivery_uuid uuid not null, - delivery_type delivery_type_enum not null, + delivery_type delivery_type_enum check (delivery_type = 'hand_shipped'), foreign key (delivery_uuid, delivery_type) references "delivery" (delivery_uuid, delivery_type), delivery_tracking_number text not null, @@ -82,7 +104,7 @@ create table "delivery_hand_shipped" ( create table "delivery_easypost" ( delivery_uuid uuid not null, - delivery_type delivery_type_enum not null, + delivery_type delivery_type_enum check (delivery_type = 'easypost'), foreign key (delivery_uuid, delivery_type) references "delivery" (delivery_uuid, delivery_type), delivery_tracking_number text not null, @@ -92,7 +114,7 @@ create table "delivery_easypost" ( create table "delivery_hand_delivered" ( delivery_uuid uuid not null, - delivery_type delivery_type_enum not null, + delivery_type delivery_type_enum check (delivery_type = 'hand_delivered'), foreign key (delivery_uuid, delivery_type) references "delivery" (delivery_uuid, delivery_type), delivery_description text not null, @@ -103,9 +125,9 @@ create table "order" ( order_uuid uuid primary key default uuid_generate_v4(), order_number int not null, order_start_time timestamptz not null default now(), - order_user_uuid uuid foreign key references "user" (user_uuid), - order_address_uuid uuid foreign key references "address" (address_uuid), - order_delivery_uuid uuid foreign key references "delivery" (delivery_uuid) + order_user_uuid uuid references "user" (user_uuid), + order_address_uuid uuid references "address" (address_uuid), + order_delivery_uuid uuid references "delivery" (delivery_uuid) ); create table "coupon" ( @@ -122,18 +144,86 @@ create table "coupon" ( create table "transaction" ( transaction_uuid uuid primary key default uuid_generate_v4(), - transaction_order_uuid uuid foreign key references "order" (order_uuid), - transaction_cart_uuid uuid foreign key references "cart" (cart_uuid), - transaction_coupon_uuid uuid foreign key references "transaction" (transaction_uuid), + transaction_order_uuid uuid references "order" (order_uuid), + transaction_cart_uuid uuid references "cart" (cart_uuid), + transaction_coupon_uuid uuid references "coupon" (coupon_uuid), transaction_start_time timestamptz not null default now(), transaction_completion_time timestamptz, - transaction_payment_state transaction_state_enum, not null default 'started', + transaction_payment_state transaction_state_enum not null default 'started', transaction_item_total_price integer not null, transaction_coupon_effective_discount integer not null, transaction_shipping_price integer not null ); create table "payment" ( - payment_uuid uuid primary key default uuid_generate_v4(), - payment_type payment_type_enum -) + payment_uuid uuid primary key default uuid_generate_v4(), + payment_type payment_type_enum not null, + payment_time timestamptz not null default now(), + payment_value_cents integer not null, + + unique (payment_uuid, payment_type) +); + +create table "payment_ks_reward" ( + payment_uuid uuid primary key default uuid_generate_v4(), + payment_type payment_type_enum check (payment_type = 'ks_reward'), + foreign key (payment_uuid, payment_type) references "payment" (payment_uuid, payment_type) + + -- Kickstarter data? + -- TODO: Figure out how this should work +); + +create table "payment_stripe" ( + payment_uuid uuid primary key default uuid_generate_v4(), + payment_type payment_type_enum check (payment_type = 'stripe'), + foreign key (payment_uuid, payment_type) references "payment" (payment_uuid, payment_type), + + stripe_transaction_id text not null, + stripe_reciept_email citext not null +); + +create table "shipment" ( + shipment_uuid uuid primary key default uuid_generate_v4(), + shipment_date timestamptz not null default now(), + shipment_description text not null +); + +create table "admin_withdrawal" ( + withdrawal_uuid uuid primary key default uuid_generate_v4(), + withdrawal_date timestamptz not null default now(), + withdrawal_description text not null +); + +create table "item_stockchange" ( + stockchange_uuid uuid primary key default uuid_generate_v4(), + stockchange_type stockchange_type_enum not null, + unique (stockchange_uuid, stockchange_type), + + stockchange_item_uuid uuid references "item" (item_uuid), + stockchange_change integer not null check (stockchange_change > 0), + stockchange_direction stock_change_dir_enum not null +); + +create table "item_stockchange_purchase" ( + stockchange_uuid uuid primary key default uuid_generate_v4(), + stockchange_type stockchange_type_enum check (stockchange_type = 'purchase'), + foreign key (stockchange_uuid, stockchange_type) references "item_stockchange" (stockchange_uuid, stockchange_type), + + stockchange_transaction_uuid uuid references "transaction" (transaction_uuid) +); + +create table "item_stockchange_shipment" ( + stockchange_uuid uuid primary key default uuid_generate_v4(), + stockchange_type stockchange_type_enum check (stockchange_type = 'shipment'), + foreign key (stockchange_uuid, stockchange_type) references "item_stockchange" (stockchange_uuid, stockchange_type), + + stockchange_shipment_uuid uuid references "shipment" (shipment_uuid) +); + +create table "item_stockchange_admin" ( + stockchange_uuid uuid primary key default uuid_generate_v4(), + stockchange_type stockchange_type_enum check (stockchange_type = 'admin'), + foreign key (stockchange_uuid, stockchange_type) references "item_stockchange" (stockchange_uuid, stockchange_type), + + stockchange_withdrawal_uuid uuid references "admin_withdrawal" (withdrawal_uuid) +); \ No newline at end of file