Skip to content

Commit

Permalink
major schema updates
Browse files Browse the repository at this point in the history
  • Loading branch information
Bienvenido Benoit Ranque committed Feb 23, 2019
1 parent cf94839 commit 607d712
Show file tree
Hide file tree
Showing 2 changed files with 138 additions and 51 deletions.
3 changes: 2 additions & 1 deletion .gitignore
Original file line number Diff line number Diff line change
@@ -1 +1,2 @@
.env
.env
.env.production
186 changes: 136 additions & 50 deletions postgres/schema.psql
Original file line number Diff line number Diff line change
Expand Up @@ -18,7 +18,7 @@ CREATE OR REPLACE FUNCTION set_updated_at()
RETURNS TRIGGER AS $$
BEGIN
IF row(NEW.*) IS DISTINCT FROM row(OLD.*) THEN
NEW.updated_at = now();
NEW.updated_at = now();
RETURN NEW;
ELSE
RETURN OLD;
Expand All @@ -30,6 +30,10 @@ $$ language 'plpgsql';
-- CREATE TRIGGER auth_account_set_updated_at BEFORE UPDATE ON auth.account
-- FOR EACH ROW EXECUTE FUNCTION set_updated_at();


drop schema if exists auth cascade;
create schema auth;

-- Password Hashing trigger Function
CREATE EXTENSION IF NOT EXISTS pgcrypto;
CREATE OR REPLACE FUNCTION auth.hash_password()
Expand All @@ -42,9 +46,6 @@ BEGIN
END;
$$ language 'plpgsql';

drop schema if exists auth cascade;
create schema auth;

create table auth.account (
account_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
username TEXT UNIQUE NOT NULL,
Expand Down Expand Up @@ -174,7 +175,7 @@ create table support.ticket_entry (

CREATE TRIGGER support_ticket_entry_set_created_at BEFORE INSERT ON support.ticket_entry
FOR EACH ROW EXECUTE FUNCTION set_created_at();
CREATE TRIGGER support_ticket_entry_updated_at BEFORE UPDATE ON support.ticket_entry
CREATE TRIGGER support_ticket_entry_set_updated_at BEFORE UPDATE ON support.ticket_entry
FOR EACH ROW EXECUTE FUNCTION set_updated_at();

-- update ticket status, priority, category
Expand All @@ -200,93 +201,178 @@ $$ language 'plpgsql';
CREATE TRIGGER support_ticket_entry_update_ticket BEFORE INSERT ON support.ticket_entry
FOR EACH ROW EXECUTE FUNCTION support.ticket_entry_update_ticket();

drop schema if exists bracelet cascade;
create schema bracelet;
drop schema if exists admittance cascade;
create schema admittance;

CREATE TABLE bracelet.bracelet (
bracelet_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
bracelet_name TEXT UNIQUE NOT NULL,
CREATE TABLE admittance.series (
series_name TEXT PRIMARY KEY,
description TEXT NOT NULL,
color TEXT NOT NULL,
owner_id UUID NOT NULL REFERENCES auth.account (account_id)
ON UPDATE CASCADE
ON DELETE RESTRICT,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now()
);

CREATE TRIGGER bracelet_bracelet_set_created_at BEFORE INSERT ON bracelet.bracelet
CREATE TRIGGER admittance_series_set_created_at BEFORE INSERT ON admittance.series
FOR EACH ROW EXECUTE FUNCTION set_created_at();
CREATE TRIGGER bracelet_bracelet_updated_at BEFORE UPDATE ON bracelet.bracelet
CREATE TRIGGER admittance_series_set_updated_at BEFORE UPDATE ON admittance.series
FOR EACH ROW EXECUTE FUNCTION set_updated_at();

CREATE TABLE bracelet.checkpoint (
CREATE TABLE admittance.bracelet (
bracelet_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
series_name TEXT REFERENCES admittance.series (series_name)
ON UPDATE RESTRICT
ON DELETE RESTRICT,
serial BIGINT NOT NULL CHECK (serial > 0),
owner_id UUID NOT NULL REFERENCES auth.account (account_id)
ON UPDATE CASCADE
ON DELETE RESTRICT,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
UNIQUE (series_name, serial)
);

CREATE TRIGGER admittance_admittance_set_created_at BEFORE INSERT ON admittance.bracelet
FOR EACH ROW EXECUTE FUNCTION set_created_at();
CREATE TRIGGER admittance_admittance_set_updated_at BEFORE UPDATE ON admittance.bracelet
FOR EACH ROW EXECUTE FUNCTION set_updated_at();

CREATE TABLE admittance.checkpoint (
checkpoint_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
checkpoint_name TEXT UNIQUE NOT NULL,
description TEXT
);
CREATE TABLE bracelet.group (
group_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
group_name TEXT UNIQUE NOT NULL
);
CREATE TABLE bracelet.product (

CREATE TABLE admittance.product (
product_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
product_name TEXT UNIQUE NOT NULL,
description TEXT,
checkpoint_id UUID NOT NULL REFERENCES bracelet.checkpoint (checkpoint_id)
owner_id UUID NOT NULL REFERENCES auth.account (account_id)
ON UPDATE CASCADE
ON DELETE RESTRICT
);
CREATE TABLE bracelet.activation (
activation_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
ON DELETE RESTRICT,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now()
);

CREATE TRIGGER bracelet_activation_set_created_at BEFORE INSERT ON bracelet.activation
CREATE TRIGGER admittance_product_set_created_at BEFORE INSERT ON admittance.product
FOR EACH ROW EXECUTE FUNCTION set_created_at();
CREATE TRIGGER bracelet_activation_updated_at BEFORE UPDATE ON bracelet.activation
CREATE TRIGGER admittance_product_set_updated_at BEFORE UPDATE ON admittance.product
FOR EACH ROW EXECUTE FUNCTION set_updated_at();

CREATE TABLE bracelet.bracelet_group (
bracelet_id UUID NOT NULL REFERENCES bracelet.bracelet (bracelet_id)
CREATE TABLE admittance.product_checkpoint (
product_id UUID NOT NULL REFERENCES admittance.product (product_id)
ON UPDATE CASCADE
ON DELETE CASCADE,
checkpoint_id UUID NOT NULL REFERENCES admittance.checkpoint (checkpoint_id)
ON UPDATE CASCADE
ON DELETE RESTRICT,
group_id UUID NOT NULL REFERENCES bracelet.group (group_id)
PRIMARY KEY (product_id, checkpoint_id)
);

CREATE TABLE admittance.assignation (
assignation_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
bracelet_id UUID NOT NULL REFERENCES admittance.bracelet (bracelet_id)
ON UPDATE CASCADE
ON DELETE CASCADE,
PRIMARY KEY (bracelet_id, group_id)
ON DELETE RESTRICT,
valid_from TIMESTAMP WITH TIME ZONE NOT NULL,
valid_to TIMESTAMP WITH TIME ZONE NOT NULL,
owner_id UUID NOT NULL REFERENCES auth.account (account_id)
ON UPDATE CASCADE
ON DELETE RESTRICT,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
CHECK (valid_from < valid_to)
);
CREATE TABLE bracelet.bracelet_activation (
bracelet_id UUID NOT NULL REFERENCES bracelet.bracelet (bracelet_id)

CREATE TRIGGER admittance_assignation_set_created_at BEFORE INSERT ON admittance.assignation
FOR EACH ROW EXECUTE FUNCTION set_created_at();
CREATE TRIGGER admittance_assignation_set_updated_at BEFORE UPDATE ON admittance.assignation
FOR EACH ROW EXECUTE FUNCTION set_updated_at();

CREATE TABLE admittance.assignation_cancelation (
assignation_cancelation_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
assignation_id UUID NOT NULL REFERENCES admittance.assignation (assignation_id)
ON UPDATE CASCADE
ON DELETE RESTRICT,
activation_id UUID NOT NULL REFERENCES bracelet.activation (activation_id)
description TEXT,
owner_id UUID NOT NULL REFERENCES auth.account (account_id)
ON UPDATE CASCADE
ON DELETE CASCADE,
PRIMARY KEY (bracelet_id, activation_id)
ON DELETE RESTRICT,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now()
);
CREATE TABLE bracelet.activation_product (
activation_id UUID NOT NULL REFERENCES bracelet.activation (activation_id)

CREATE TABLE admittance.assignation_product (
assignation_id UUID NOT NULL REFERENCES admittance.assignation (assignation_id)
ON UPDATE CASCADE
ON DELETE CASCADE,
product_id UUID NOT NULL REFERENCES bracelet.product (product_id)
product_id UUID NOT NULL REFERENCES admittance.product (product_id)
ON UPDATE CASCADE
ON DELETE RESTRICT,
PRIMARY KEY (activation_id, product_id)
PRIMARY KEY (assignation_id, product_id)
);
-- TODO
-- RESTRICT CHECK CREATION BY FOLOWING CONDITIONS
-- MUST BE ACTIVATED FOR PRODUCT WITH CHECKPOINT
-- MUST NOT HAVE CHECKS BELONGINGS TO ANOTHER DATE
CREATE TABLE bracelet.check (
check_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
bracelet_id UUID NOT NULL REFERENCES bracelet.bracelet (bracelet_id)

CREATE TABLE admittance.activation (
activation_id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
bracelet_id UUID NOT NULL REFERENCES admittance.bracelet (bracelet_id)
ON UPDATE CASCADE
ON DELETE RESTRICT,
checkpoint_id UUID NOT NULL REFERENCES bracelet.checkpoint (checkpoint_id)
checkpoint_id UUID NOT NULL REFERENCES admittance.checkpoint (checkpoint_id)
ON UPDATE CASCADE
ON DELETE RESTRICT,
datetime TIMESTAMP WITH TIME ZONE NOT NULL,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now(),
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT now()
);

CREATE TRIGGER bracelet_check_set_created_at BEFORE INSERT ON bracelet.check
CREATE TRIGGER admittance_activation_set_created_at BEFORE INSERT ON admittance.activation
FOR EACH ROW EXECUTE FUNCTION set_created_at();
CREATE TRIGGER bracelet_check_updated_at BEFORE UPDATE ON bracelet.check
FOR EACH ROW EXECUTE FUNCTION set_updated_at();
CREATE TRIGGER admittance_activation_set_updated_at BEFORE UPDATE ON admittance.activation
FOR EACH ROW EXECUTE FUNCTION set_updated_at();


CREATE OR REPLACE FUNCTION admittance.activation_validation()
RETURNS TRIGGER AS $$
BEGIN
NEW.datetime = NOW();
-- check if activations from other dates exist
IF EXISTS (
SELECT 1 FROM admittance.activation
WHERE bracelet_id = NEW.bracelet_id
AND NOT datetime <= CURRENT_DATE
AND NOT datetime >= (CURRENT_DATE + INTERVAL '1 day')
) THEN
RAISE EXCEPTION 'This bracelet has already been activated on a diferent date';
END IF;
-- Join assignation to checkpoint using product
-- match bracelet and checkpoint
-- match valid_from and valid_to
-- check if assignation not cancelled
IF NOT EXISTS (
SELECT 1 FROM admittance.assignation
LEFT JOIN admittance.assignation_product
ON admittance.assignation_product.assignation_id = admittance.assignation.assignation_id
LEFT JOIN admittance.product_checkpoint
ON admittance.assignation_product.product_id = admittance.product_checkpoint.product_id
WHERE
admittance.assignation.bracelet_id = NEW.bracelet_id
AND admittance.product_checkpoint.checkpoint_id = NEW.checkpoint_id
AND admittance.assignation.valid_from <= NOW()
AND admittance.assignation.valid_to >= NOW()
AND NOT EXISTS (SELECT 1 FROM admittance.assignation_cancelation WHERE assignation_id = assignation.assignation_id)
) THEN
RAISE EXCEPTION 'This bracelet is either invalid, expired or unassigned';
END IF;
RETURN NEW;
END;
$$ language 'plpgsql';
CREATE TRIGGER admittance_verify_activation_validation BEFORE INSERT ON admittance.activation
FOR EACH ROW EXECUTE FUNCTION admittance.activation_validation();
-- DO $$
-- BEGIN
-- FOR counter IN 1..500 LOOP
-- INSERT INTO admittance.bracelet (series, serial) VALUES ('110', counter);
-- END LOOP;
-- END; $$

0 comments on commit 607d712

Please sign in to comment.