EchoForum/db/create.sql

676 lines
19 KiB
PL/PgSQL

---------------------------
---== TYPES ==-------------
CREATE TYPE doki8902.user_access_type AS ENUM (
'normal', 'elevated'
);
CREATE TYPE doki8902.user_action_type AS ENUM (
'post_create', 'post_edit', 'post_delete',
'comment_create', 'comment_edit', 'comment_delete',
'user_join', 'user_restrict'
);
---------------------------
---== TABLES ==------------
CREATE TABLE IF NOT EXISTS doki8902.user (
id SERIAL
NOT NULL
PRIMARY KEY,
username VARCHAR(32)
NOT NULL,
password VARCHAR(200)
NOT NULL,
join_time TIMESTAMP WITH TIME ZONE
NOT NULL
DEFAULT CURRENT_TIMESTAMP,
about VARCHAR(256)
NOT NULL
DEFAULT 'Hey! I''m new here!',
access doki8902.user_access_type
NOT NULL
DEFAULT 'normal',
CONSTRAINT username_valid_symbols CHECK (username ~ '^[a-zA-Z0-9]*$'),
CONSTRAINT username_length_min CHECK (char_length(username) >= 3)
);
CREATE TABLE IF NOT EXISTS doki8902.user_session (
user_id INT
NOT NULL
REFERENCES doki8902.user(id)
ON UPDATE CASCADE
ON DELETE CASCADE,
token CHAR(32)
NOT NULL
PRIMARY KEY
DEFAULT md5(random()::text),
expiry TIMESTAMP
NOT NULL
DEFAULT CURRENT_TIMESTAMP + INTERVAL '1 WEEK'
);
CREATE TABLE IF NOT EXISTS doki8902.user_action_log (
id SERIAL
NOT NULL
PRIMARY KEY,
user_id INT
REFERENCES doki8902.user(id)
ON DELETE CASCADE
ON UPDATE CASCADE,
type doki8902.user_action_type
NOT NULL,
details VARCHAR(100),
timestamp TIMESTAMP WITH TIME ZONE
NOT NULL
DEFAULT CURRENT_TIMESTAMP
);
CREATE TABLE IF NOT EXISTS doki8902.message (
id SERIAL
NOT NULL
PRIMARY KEY,
author_id INT
REFERENCES doki8902.user(id)
ON DELETE SET NULL
ON UPDATE CASCADE,
created_date TIMESTAMP WITH TIME ZONE
NOT NULL
DEFAULT CURRENT_TIMESTAMP,
soft_delete BOOLEAN
NOT NULL
DEFAULT FALSE
);
CREATE TABLE IF NOT EXISTS doki8902.message_vote (
message_id INT
NOT NULL
REFERENCES doki8902.message(id)
ON UPDATE CASCADE
ON DELETE CASCADE,
user_id INT
NOT NULL
REFERENCES doki8902.user(id)
ON UPDATE CASCADE
ON DELETE CASCADE,
vote SMALLINT
NOT NULL,
CONSTRAINT message_user_id_pkey PRIMARY KEY (message_id, user_id),
CONSTRAINT vote_value CHECK (vote = 1 OR vote = -1)
);
CREATE TABLE IF NOT EXISTS doki8902.message_content (
id SERIAL
NOT NULL
PRIMARY KEY,
message_id INT
NOT NULL
REFERENCES doki8902.message(id)
ON DELETE CASCADE
ON UPDATE CASCADE,
compose_date TIMESTAMP WITH TIME ZONE
NOT NULL
DEFAULT CURRENT_TIMESTAMP,
content VARCHAR(4096)
NOT NULL,
approved BOOLEAN
NOT NULL
DEFAULT FALSE,
CONSTRAINT content_min_length CHECK (LENGTH(content) >= 2)
);
CREATE TABLE IF NOT EXISTS doki8902.message_initial (
message_id INT
NOT NULL
PRIMARY KEY
REFERENCES doki8902.message(id)
ON DELETE CASCADE
ON UPDATE CASCADE,
content_id INT
NOT NULL
REFERENCES doki8902.message_content(id)
ON DELETE CASCADE
ON UPDATE CASCADE
);
CREATE TABLE IF NOT EXISTS doki8902.post_category (
id SERIAL
NOT NULL
PRIMARY KEY,
name VARCHAR(100)
NOT NULL,
CONSTRAINT name_min_length CHECK (LENGTH(name) >= 2)
);
CREATE TABLE IF NOT EXISTS doki8902.post (
message_id INT
NOT NULL
PRIMARY KEY
REFERENCES doki8902.message(id)
ON DELETE CASCADE
ON UPDATE CASCADE,
name VARCHAR(255)
NOT NULL,
category_id INT
NOT NULL
REFERENCES doki8902.post_category(id)
ON DELETE RESTRICT
ON UPDATE CASCADE,
CONSTRAINT name_min_length CHECK (LENGTH(name) >= 2)
);
CREATE TABLE IF NOT EXISTS doki8902.comment (
message_id INT
NOT NULL
PRIMARY KEY
REFERENCES doki8902.message(id),
parent_comment_id INT
REFERENCES doki8902.comment(message_id)
ON DELETE SET NULL
ON UPDATE CASCADE,
post_id INT
NOT NULL
REFERENCES doki8902.post(message_id)
ON DELETE CASCADE
ON UPDATE CASCADE
);
---------------------------
---== VIEWS ==-------------
CREATE OR REPLACE VIEW doki8902.message_votes AS (
SELECT
v.message_id,
SUM(CASE WHEN vote > 0 THEN 1 ELSE 0 END) AS "likes",
SUM(CASE WHEN vote < 0 THEN 1 ELSE 0 END) AS "dislikes",
SUM(vote) AS "score"
FROM
doki8902.message_vote v
GROUP BY v.message_id
);
CREATE MATERIALIZED VIEW IF NOT EXISTS doki8902.message_content_latest AS (
WITH "content_edits" AS (
SELECT
m.message_id,
MAX(m.id) AS "latest_id",
COUNT(*) AS "edit_count"
FROM
doki8902.message_content m
WHERE
m.approved
GROUP BY m.message_id
)
SELECT
e.*,
CASE
WHEN e.edit_count = 1 THEN TRUE
ELSE FALSE
END AS "original",
i.content AS "latest_content",
i.compose_date AS "latest_content_date"
FROM
doki8902.message_content i
JOIN
content_edits e
ON e.message_id = i.message_id
WHERE
i.id = e.latest_id
);
CREATE OR REPLACE VIEW doki8902.post_comment_metrics AS (
SELECT
post_id,
COUNT(c.*) AS "comment_count",
COUNT(DISTINCT m.author_id) AS "user_count",
MAX(m.created_date) AS "latest_activity",
SUM(v.likes) AS "likes",
SUM(v.dislikes) AS "dislikes",
SUM(v.score) AS "score",
EXTRACT(DAY FROM AGE(MAX(m.created_date))) AS "age"
FROM
doki8902.comment c
JOIN
doki8902.message AS m
ON m.id = c.message_id
JOIN
doki8902.message_votes AS v
ON v.message_id = c.message_id
GROUP BY c.post_id
);
CREATE OR REPLACE VIEW doki8902.message_post AS (
WITH "post_metrics" AS (
SELECT
m.id,
m.author_id,
m.created_date,
m.soft_delete,
p.name,
p.category_id,
v.likes,
v.dislikes,
v.score,
COALESCE(s.comment_count, 0) AS "comment_count",
COALESCE(s.user_count, 0) AS "user_count",
COALESCE(s.latest_activity, m.created_date) AS "latest_activity",
COALESCE(s.likes, 0) + COALESCE(s.dislikes, 0) + v.likes + v.dislikes + COALESCE(s.comment_count, 0) + COALESCE(s.user_count, 0) AS "engagement",
COALESCE(s.age, EXTRACT(DAY FROM AGE(m.created_date))) AS "age"
FROM
doki8902.post p
JOIN
doki8902.message AS m
ON p.message_id = m.id
JOIN
doki8902.message_votes AS v
ON v.message_id = m.id
LEFT OUTER JOIN
doki8902.post_comment_metrics AS s
ON s.post_id = p.message_id
)
SELECT
p.*,
(p.engagement + p.user_count + p.comment_count) / (p.age + 1) AS "relevancy",
l.edit_count,
l.original,
CASE
WHEN l.original IS NOT NULL THEN True
ELSE False
END AS "reviewed",
COALESCE(l.latest_content, (
SELECT c1.content
FROM doki8902.message_initial i1
JOIN doki8902.message_content c1 ON c1.id = i1.content_id
WHERE i1.message_id = p.id
)) AS "latest_content",
l.latest_content_date
FROM
post_metrics p
LEFT OUTER JOIN
doki8902.message_content_latest AS l
ON l.message_id = p.id
LEFT OUTER JOIN
doki8902.post_comment_metrics AS s
ON s.post_id = p.id
);
CREATE OR REPLACE VIEW doki8902.message_comment AS (
SELECT
m.*,
c.post_id,
c.parent_comment_id,
l.edit_count,
l.original,
l.latest_content_date,
v.likes,
v.dislikes,
v.score,
CASE
WHEN l.original IS NOT NULL THEN True
ELSE False
END AS "reviewed",
COALESCE(l.latest_content, (
SELECT c1.content
FROM doki8902.message_initial i1
JOIN doki8902.message_content c1 ON c1.id = i1.content_id
WHERE i1.message_id = m.id
)) AS "latest_content"
FROM
doki8902.message m
JOIN
doki8902.comment c
ON c.message_id = m.id
LEFT OUTER JOIN
doki8902.message_content_latest l
ON l.message_id = m.id
JOIN
doki8902.message_votes v
ON v.message_id = m.id
);
---------------------------
---== INDICES ==-----------
CREATE UNIQUE INDEX idx_user_username
ON doki8902.user(username);
CREATE INDEX IF NOT EXISTS idx_user
ON doki8902.user_session
USING HASH (user_id);
CREATE INDEX IF NOT EXISTS idx_message_author
ON doki8902.message
USING HASH (author_id);
CREATE INDEX IF NOT EXISTS idx_message_content_message
ON doki8902.message_content(message_id, compose_date); /* TODO */
CREATE INDEX IF NOT EXISTS idx_message_vote_message
ON doki8902.message_vote
USING HASH (message_id);
CREATE INDEX IF NOT EXISTS idx_post_category
ON doki8902.post
USING HASH (category_id);
CREATE UNIQUE INDEX idx_post_category_name
ON doki8902.post_category(name);
CREATE INDEX IF NOT EXISTS idx_comment_post
ON doki8902.comment
USING HASH (post_id);
CREATE INDEX IF NOT EXISTS idx_comment_parent
ON doki8902.comment
USING HASH (parent_comment_id);
CREATE UNIQUE INDEX idx_message_id
ON doki8902.message_content_latest(message_id);
---------------------------
---== FUNCTIONS ==---------
CREATE OR REPLACE FUNCTION doki8902.func_log_action(
user_id INT,
type doki8902.user_action_type,
details TEXT
) RETURNS VOID AS $$
BEGIN
INSERT INTO doki8902.user_action_log (user_id, type, details) VALUES (
user_id, type, details
);
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION doki8902.func_log_message_trigger() RETURNS TRIGGER AS $$
BEGIN
PERFORM doki8902.func_log_action(
(SELECT author_id FROM doki8902.message WHERE id = NEW.message_id),
CAST(TG_ARGV[0] AS doki8902.user_action_type),
CAST(NEW.message_id AS TEXT)
);
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION doki8902.func_log_user_trigger() RETURNS TRIGGER AS $$
BEGIN
PERFORM doki8902.func_log_action(
NEW.id,
CAST(TG_ARGV[0] AS doki8902.user_action_type),
TG_ARGV[1]
);
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION doki8902.func_log_user_restrict(
user_id INT,
reason TEXT
) RETURNS VOID AS $$
BEGIN
PERFORM doki8902.func_log_action(user_id, 'user_restrict', reason);
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION doki8902.func_update_message_contents_trigger() RETURNS TRIGGER AS $$
BEGIN
REFRESH MATERIALIZED VIEW CONCURRENTLY doki8902.message_content_latest;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION doki8902.func_approve_all_pending_content() RETURNS VOID AS $$
BEGIN
UPDATE doki8902.message_content
SET approved = TRUE;
END;
$$ LANGUAGE plpgsql;
---------------------------
---== TRIGGERS ==----------
--- USERS
CREATE TRIGGER message_user_join_log
AFTER INSERT
ON doki8902.user
FOR EACH ROW
EXECUTE FUNCTION doki8902.func_log_user_trigger('user_join', '');
---
CREATE OR REPLACE FUNCTION doki8902.func_remove_sessions_password_trigger() RETURNS TRIGGER AS $$
BEGIN
DELETE FROM doki8902.user_session WHERE user_id = NEW.id;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER user_password_change
AFTER UPDATE OF password
ON doki8902.user
FOR EACH ROW
EXECUTE FUNCTION doki8902.func_remove_sessions_password_trigger();
--- MESSAGE CONTENT
CREATE TRIGGER message_content_update_refresh
AFTER UPDATE OF approved
ON doki8902.message_content
FOR EACH STATEMENT
EXECUTE FUNCTION doki8902.func_update_message_contents_trigger();
--- MESSAGES
CREATE OR REPLACE FUNCTION doki8902.func_vote_own_created_message_trigger() RETURNS TRIGGER AS $$
BEGIN
INSERT INTO doki8902.message_vote (message_id, user_id, vote) VALUES (
NEW.id, NEW.author_id, 1
);
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER message_create_vote_auto
AFTER INSERT
ON doki8902.message
FOR EACH ROW
EXECUTE FUNCTION doki8902.func_vote_own_created_message_trigger();
---
CREATE OR REPLACE FUNCTION doki8902.func_log_message_delete_trigger() RETURNS TRIGGER AS $$
BEGIN
IF OLD.soft_delete = FALSE AND NEW.soft_delete = TRUE THEN
IF EXISTS(SELECT * FROM doki8902.post WHERE NEW.id = message_id) THEN
PERFORM doki8902.func_log_action(
(SELECT author_id FROM doki8902.message WHERE id = NEW.message_id),
'post_delete',
CAST(NEW.message_id AS TEXT)
);
ELSIF EXISTS(SELECT * FROM doki8902.comment WHERE NEW.id = message_id) THEN
PERFORM doki8902.func_log_action(
(SELECT author_id FROM doki8902.message WHERE id = NEW.message_id),
'comment_delete',
CAST(NEW.message_id AS TEXT)
);
END IF;
END IF;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER message_delete_log
AFTER UPDATE
ON doki8902.message
FOR EACH ROW
EXECUTE FUNCTION doki8902.func_log_message_delete_trigger();
---
CREATE OR REPLACE FUNCTION doki8902.func_require_user_trigger() RETURNS TRIGGER AS $$
BEGIN
IF NOT(EXISTS(SELECT * FROM doki8902.user WHERE id = NEW.author_id))
THEN
RAISE EXCEPTION 'Newly created Message must have a valid user %', NEW.author_id USING CONSTRAINT = 'message_require_user';
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER message_require_user
BEFORE INSERT
ON doki8902.message
FOR EACH ROW
EXECUTE FUNCTION doki8902.func_require_user_trigger();
--- POSTS
CREATE TRIGGER message_post_create_log
AFTER INSERT
ON doki8902.post
FOR EACH ROW
EXECUTE FUNCTION doki8902.func_log_message_trigger('post_create');
---
CREATE OR REPLACE FUNCTION doki8902.func_create_message_post_trigger() RETURNS trigger AS $$
DECLARE
message_id INTEGER;
content_id INTEGER;
BEGIN
INSERT INTO doki8902.message(author_id)
VALUES (NEW.author_id)
RETURNING id INTO message_id;
INSERT INTO doki8902.post(message_id, name, category_id)
VALUES (message_id, NEW.name, NEW.category_id);
IF (NEW.reviewed = TRUE) THEN
INSERT INTO doki8902.message_content(message_id, content, approved)
VALUES (message_id, NEW.latest_content, TRUE)
RETURNING id INTO content_id;
ELSE
INSERT INTO doki8902.message_content(message_id, content)
VALUES (message_id, NEW.latest_content)
RETURNING id INTO content_id;
END IF;
INSERT INTO doki8902.message_initial(message_id, content_id)
VALUES (message_id, content_id);
NEW.id := message_id;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER message_post_insert
INSTEAD OF INSERT
ON doki8902.message_post
FOR EACH ROW
EXECUTE FUNCTION doki8902.func_create_message_post_trigger();
---
CREATE OR REPLACE FUNCTION doki8902.func_update_message_post_content_trigger() RETURNS TRIGGER AS $$
BEGIN
IF (OLD.latest_content IS DISTINCT FROM NEW.latest_content) THEN
INSERT INTO doki8902.message_content(message_id, content) VALUES (NEW.id, NEW.latest_content);
END IF;
IF (OLD.category_id IS DISTINCT FROM NEW.category_id) THEN
UPDATE doki8902.post
SET category_id = NEW.category_id
WHERE message_id = NEW.id;
END IF;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER message_post_update_content
INSTEAD OF UPDATE
ON doki8902.message_post
FOR EACH ROW
EXECUTE FUNCTION doki8902.func_update_message_post_content_trigger();
--- COMMENTS
CREATE TRIGGER message_post_comment_log
AFTER INSERT
ON doki8902.comment
FOR EACH ROW
EXECUTE FUNCTION doki8902.func_log_message_trigger('comment_create');
---
CREATE OR REPLACE FUNCTION doki8902.func_create_message_comment_trigger() RETURNS TRIGGER AS $$
DECLARE
message_id INTEGER;
content_id INTEGER;
BEGIN
IF (NEW.parent_comment_id <> NULL AND NOT(
EXISTS(
SELECT
c.*
FROM
doki8902.comment c
WHERE
c.post_id = NEW.post_id
AND c.message_id = NEW.parent_comment_id
)
)) THEN
RAISE EXCEPTION 'Parent Comment ID % does NOT exist for the Post %', NEW.parent_comment_id, NEW.post_id;
END IF;
INSERT INTO doki8902.message(author_id)
VALUES (NEW.author_id)
RETURNING id INTO message_id;
INSERT INTO doki8902.comment(message_id, post_id, parent_comment_id)
VALUES (message_id, NEW.post_id, NEW.parent_comment_id);
IF (NEW.reviewed = TRUE) THEN
INSERT INTO doki8902.message_content(message_id, content, approved)
VALUES (message_id, NEW.latest_content, TRUE)
RETURNING id INTO content_id;
ELSE
INSERT INTO doki8902.message_content(message_id, content)
VALUES (message_id, NEW.latest_content)
RETURNING id INTO content_id;
END IF;
INSERT INTO doki8902.message_initial(message_id, content_id)
VALUES (message_id, content_id);
NEW.id := message_id;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER message_comment_insert
INSTEAD OF INSERT
ON doki8902.message_comment
FOR EACH ROW
EXECUTE FUNCTION doki8902.func_create_message_comment_trigger();
---
CREATE OR REPLACE FUNCTION doki8902.func_update_message_comment_content_trigger() RETURNS TRIGGER AS $$
BEGIN
IF (OLD.latest_content IS DISTINCT FROM NEW.latest_content)
THEN
INSERT INTO doki8902.message_content(message_id, content) VALUES (NEW.id, NEW.latest_content);
END IF;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER message_comment_update_content
INSTEAD OF UPDATE
ON doki8902.message_comment
FOR EACH ROW
EXECUTE FUNCTION doki8902.func_update_message_comment_content_trigger();