You cannot select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

263 lines
12 KiB
SQL

create type sos."delivery_type_enum" as enum ('hand_shipped', 'easypost', 'hand_delivered');
create type sos."transaction_state_enum" as enum ('started', 'completed', 'cancelled', 'expired');
create type sos."payment_type_enum" as enum ('ks_reward', 'stripe', 'paypal', 'account_credit');
create type sos."stockchange_type_enum" as enum ('purchase', 'shipment', 'admin');
create type sos."stock_change_dir_enum" as enum ('added', 'subtracted');
create table sos."user" (
user_uuid uuid primary key default uuid_generate_v4(),
user_email citext unique not null,
user_email_confirmed boolean not null default false,
user_password_hash varchar(60),
user_time_registered timestamptz not null default now(),
user_time_email_confirmed timestamptz,
user_is_admin bool not null default false
);
create table sos."login_link" (
login_link_uuid uuid primary key default uuid_generate_v4(),
login_link_user_uuid uuid not null references sos."user" (user_uuid),
login_link_time_created timestamptz not null default now(),
login_link_timeout_length interval not null,
login_link_login_hash varchar(60) not null
);
create table sos."cart" (
cart_uuid uuid primary key default uuid_generate_v4()
);
create table sos."session" (
session_uuid uuid primary key default uuid_generate_v4(),
session_time_created timestamptz not null default now(),
session_time_last_active timestamptz not null default now(),
session_time_logged_out timestamptz null,
session_timeout_length interval not null,
session_ip_address varchar(50) not null,
session_user_agent varchar(500) not null,
session_referer varchar(500) not null,
session_user_uuid uuid references sos."user" (user_uuid),
session_originating_link uuid references sos."login_link" (login_link_uuid),
session_cart uuid references sos."cart" (cart_uuid)
);
create table sos."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_published boolean not null default true
);
create table sos."cart_item" (
cart_item_uuid uuid primary key default uuid_generate_v4(),
cart_item_item_uuid uuid not null references sos."item" (item_uuid),
cart_item_cart_uuid uuid not null references sos."cart" (cart_uuid),
cart_item_count integer not null default 1 check (cart_item_count > 0),
cart_item_time_added timestamptz not null default now()
);
create table sos."image" (
image_uuid uuid primary key default uuid_generate_v4(),
image_featured boolean not null default false,
image_item_uuid uuid not null references sos."item" (item_uuid),
image_large_file bytea not null,
image_thumb_file bytea not null,
image_mime_type varchar not null,
image_uploader_uuid uuid not null references sos."user" (user_uuid),
image_date_uploaded timestamptz not null default now()
);
create unique index only_one_primary_key on sos."image" (image_item_uuid, image_featured)
where image_featured = true;
create table sos."category" (
category_uuid uuid primary key default uuid_generate_v4(),
category_name text not null,
category_description text not null,
category_urlslug citext unique not null
);
create table sos."category_item" (
category_item_uuid uuid primary key default uuid_generate_v4(),
category_item_item_uuid uuid not null references sos."item" (item_uuid),
category_item_category_uuid uuid not null references sos."category" (category_uuid)
);
create table sos."category_category" (
category_category_uuid uuid primary key default uuid_generate_v4(),
category_category_parent_uuid uuid not null references sos."category" (category_uuid),
category_category_child_uuid uuid not null references sos."category" (category_uuid)
);
create table sos."address" (
address_uuid uuid primary key default uuid_generate_v4(),
address_name text not null,
address_company text,
address_street1 text not null,
address_street2 text,
address_city text not null,
address_state text not null,
address_zip text not null,
address_country text not null,
address_phone text,
address_easypost_id text
);
create table sos."delivery" (
delivery_uuid uuid primary key default uuid_generate_v4(),
delivery_type sos.delivery_type_enum not null,
unique (delivery_uuid, delivery_type)
);
create table sos."delivery_hand_shipped" (
delivery_uuid uuid not null,
delivery_type sos.delivery_type_enum check (delivery_type = 'hand_shipped'),
foreign key (delivery_uuid, delivery_type) references sos."delivery" (delivery_uuid, delivery_type),
delivery_tracking_number text not null,
delivery_date_shipped timestamptz not null
);
create table sos."delivery_easypost" (
delivery_uuid uuid not null,
delivery_type sos.delivery_type_enum check (delivery_type = 'easypost'),
foreign key (delivery_uuid, delivery_type) references sos."delivery" (delivery_uuid, delivery_type),
delivery_tracking_number text not null,
delivery_date_shipped timestamptz not null,
delivery_easypost_id text not null
);
create table sos."delivery_hand_delivered" (
delivery_uuid uuid not null,
delivery_type sos.delivery_type_enum check (delivery_type = 'hand_delivered'),
foreign key (delivery_uuid, delivery_type) references sos."delivery" (delivery_uuid, delivery_type),
delivery_description text not null,
delivery_date_delivered timestamptz not null
);
create table sos."order" (
order_uuid uuid primary key default uuid_generate_v4(),
order_number serial not null unique,
order_start_time timestamptz not null default now(),
order_user_uuid uuid references sos."user" (user_uuid),
order_address_uuid uuid references sos."address" (address_uuid),
order_delivery_uuid uuid references sos."delivery" (delivery_uuid)
);
create table sos."coupon" (
coupon_uuid uuid primary key default uuid_generate_v4(),
coupon_code varchar(50) unique not null,
coupon_valid_until timestamptz not null,
coupon_free_shipping boolean not null default false,
coupon_number_allowed_uses integer not null default 1 check (coupon_number_allowed_uses > 0),
coupon_flat_discount_cents integer not null default 0 check (coupon_flat_discount_cents >= 0),
coupon_percent_discount integer not null default 0 check (coupon_percent_discount >= 0 and coupon_percent_discount <= 100),
coupon_per_sock_discount_cents integer not null default 0 check (coupon_per_sock_discount_cents >= 0),
coupon_number_of_socks_free integer not null default 0 check (coupon_number_of_socks_free >= 0),
constraint only_one_coupon_discount check (
(
case when coupon_flat_discount_cents = 0 then 0 else 1 end
+ case when coupon_percent_discount = 0 then 0 else 1 end
+ case when coupon_per_sock_discount_cents = 0 then 0 else 1 end
+ case when coupon_number_of_socks_free = 0 then 0 else 1 end
) < 2
)
);
create table sos."transaction" (
transaction_uuid uuid primary key default uuid_generate_v4(),
transaction_order_uuid uuid references sos."order" (order_uuid),
transaction_cart_uuid uuid references sos."cart" (cart_uuid),
transaction_coupon_uuid uuid references sos."coupon" (coupon_uuid),
transaction_start_time timestamptz not null default now(),
transaction_completion_time timestamptz,
transaction_payment_state sos.transaction_state_enum not null default 'started',
transaction_item_total_price integer not null,
transaction_coupon_effective_discount integer not null default 0,
transaction_shipping_price integer,
transaction_tax_price integer,
constraint transaction_cannot_complete_without_shipping check (transaction_payment_state != 'completed' or transaction_shipping_price is not null),
constraint transaction_no_discount_without_coupon check (transaction_coupon_effective_discount = 0 or transaction_coupon_uuid is not null)
-- TODO: Partial index on cart_uuid to disallow two "started" transactions with the same cart
-- TODO: Partial index on order_uuid to disallow two "started" transactions with the same order
);
create table sos."payment" (
payment_uuid uuid primary key default uuid_generate_v4(),
payment_type sos.payment_type_enum not null,
payment_time timestamptz not null default now(),
payment_value_cents integer not null,
payment_transaction_uuid uuid references sos."transaction" (transaction_uuid),
unique (payment_uuid, payment_type)
);
create table sos."payment_ks_reward" (
payment_uuid uuid primary key default uuid_generate_v4(),
payment_type sos.payment_type_enum check (payment_type = 'ks_reward'),
foreign key (payment_uuid, payment_type) references sos."payment" (payment_uuid, payment_type)
-- Kickstarter data?
-- TODO: Figure out how this should work
);
create table sos."payment_stripe" (
payment_uuid uuid primary key default uuid_generate_v4(),
payment_type sos.payment_type_enum check (payment_type = 'stripe'),
foreign key (payment_uuid, payment_type) references sos."payment" (payment_uuid, payment_type),
stripe_payment_intent_id text unique not null,
stripe_reciept_email citext not null
);
create table sos."shipment" (
shipment_uuid uuid primary key default uuid_generate_v4(),
shipment_date timestamptz not null default now(),
shipment_description text not null
);
create table sos."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 sos."item_stockchange" (
stockchange_uuid uuid primary key default uuid_generate_v4(),
stockchange_type sos.stockchange_type_enum not null,
unique (stockchange_uuid, stockchange_type),
stockchange_item_uuid uuid references sos."item" (item_uuid),
stockchange_change integer not null check (stockchange_change > 0),
stockchange_direction sos.stock_change_dir_enum not null
);
create table sos."item_stockchange_purchase" (
stockchange_uuid uuid primary key default uuid_generate_v4(),
stockchange_type sos.stockchange_type_enum check (stockchange_type = 'purchase'),
foreign key (stockchange_uuid, stockchange_type) references sos."item_stockchange" (stockchange_uuid, stockchange_type),
stockchange_transaction_uuid uuid references sos."transaction" (transaction_uuid)
);
create table sos."item_stockchange_shipment" (
stockchange_uuid uuid primary key default uuid_generate_v4(),
stockchange_type sos.stockchange_type_enum check (stockchange_type = 'shipment'),
foreign key (stockchange_uuid, stockchange_type) references sos."item_stockchange" (stockchange_uuid, stockchange_type),
stockchange_shipment_uuid uuid references sos."shipment" (shipment_uuid)
);
create table sos."item_stockchange_admin" (
stockchange_uuid uuid primary key default uuid_generate_v4(),
stockchange_type sos.stockchange_type_enum check (stockchange_type = 'admin'),
foreign key (stockchange_uuid, stockchange_type) references sos."item_stockchange" (stockchange_uuid, stockchange_type),
stockchange_withdrawal_uuid uuid references sos."admin_withdrawal" (withdrawal_uuid)
);