Update README #1

Merged
bloodwiing merged 6 commits from readme-update into main 2025-05-11 19:20:52 +00:00
8 changed files with 975 additions and 0 deletions
Showing only changes of commit c45b7dd5b0 - Show all commits

16
db/clear.sql Normal file
View File

@ -0,0 +1,16 @@
DELETE FROM doki8902.message_content;
DELETE FROM doki8902.comment;
DELETE FROM doki8902.post;
DELETE FROM doki8902.message_initial;
DELETE FROM doki8902.message_vote;
DELETE FROM doki8902.message;
DELETE FROM doki8902.post_category;
DELETE FROM doki8902.user_session;
DELETE FROM doki8902.user;
DELETE FROM doki8902.user_action_log;
ALTER SEQUENCE doki8902.user_id_seq RESTART;
ALTER SEQUENCE doki8902.user_action_log_id_seq RESTART;
ALTER SEQUENCE doki8902.message_id_seq RESTART;
ALTER SEQUENCE doki8902.message_content_id_seq RESTART;
ALTER SEQUENCE doki8902.post_category_id_seq RESTART;

675
db/create.sql Normal file
View File

@ -0,0 +1,675 @@
---------------------------
---== 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();

31
db/drop.sql Normal file
View File

@ -0,0 +1,31 @@
DROP TABLE IF EXISTS doki8902.comment CASCADE;
DROP TABLE IF EXISTS doki8902.post CASCADE;
DROP TABLE IF EXISTS doki8902.post_category CASCADE;
DROP TABLE IF EXISTS doki8902.message_initial CASCADE;
DROP TABLE IF EXISTS doki8902.message_content CASCADE;
DROP TABLE IF EXISTS doki8902.message_vote CASCADE;
DROP TABLE IF EXISTS doki8902.message CASCADE;
DROP TABLE IF EXISTS doki8902.user_action_log CASCADE;
DROP TABLE IF EXISTS doki8902.user_session CASCADE;
DROP TABLE IF EXISTS doki8902.user CASCADE;
DROP FUNCTION IF EXISTS doki8902.func_update_message_comment_content_trigger;
DROP FUNCTION IF EXISTS doki8902.func_create_message_comment_trigger;
DROP FUNCTION IF EXISTS doki8902.func_update_message_post_content_trigger;
DROP FUNCTION IF EXISTS doki8902.func_create_message_post_trigger;
DROP FUNCTION IF EXISTS doki8902.func_require_user_trigger;
DROP FUNCTION IF EXISTS doki8902.func_log_message_delete_trigger;
DROP FUNCTION IF EXISTS doki8902.func_vote_own_created_message_trigger;
DROP FUNCTION IF EXISTS doki8902.func_approve_all_pending_content;
DROP FUNCTION IF EXISTS doki8902.func_remove_sessions_password_trigger;
DROP FUNCTION IF EXISTS doki8902.func_update_message_contents_trigger;
DROP FUNCTION IF EXISTS doki8902.func_log_user_restrict;
DROP FUNCTION IF EXISTS doki8902.func_log_user_trigger;
DROP FUNCTION IF EXISTS doki8902.func_log_message_trigger;
DROP FUNCTION IF EXISTS doki8902.func_log_action;
DROP TYPE IF EXISTS doki8902.user_access_type;
DROP TYPE IF EXISTS doki8902.user_action_type;

124
db/insert.sql Normal file
View File

@ -0,0 +1,124 @@
-- CREATE SETUP
BEGIN;
INSERT INTO doki8902.post_category(name) VALUES
('Technology'),
('Food'),
('Games'),
('Reading'),
('Movies'),
('Sports'),
('Travel');
COMMIT;
-- CREATE USERS
BEGIN;
INSERT INTO doki8902.user(username, password) VALUES
('Alice', 'pass123'),
('Bob', 'qwerty'),
('Charlie', 'abc456'),
('David', 'secret'),
('Eve', 'p@ssw0rd'),
('Frank', 'admin123'),
('Grace', 'letmein'),
('Henry', 'changeme'),
('Isabel', 'ilovecats'),
('Jack', 'welcome'),
('BotAccount', 'qwertyasdf');
INSERT INTO doki8902.user(username, password, access) VALUES ('admin', '$argon2id$v=19$m=65536,t=4,p=1$QNRzi0vaVyjR/AszHyJF9Q$+2rRyTHHMIYjYCRSZEpjRGWLjWWl1Jval8JH/l2ArymxEbSjctGWMT4X0neqVeN9yC32LO9utmH9WHr0gJXpQQ', 'elevated');
INSERT INTO doki8902.user_session(user_id) VALUES (1), (2), (3), (5), (5), (6), (7), (8), (9), (11);
COMMIT;
-- NORMAL USE
BEGIN;
SELECT doki8902.func_log_user_restrict(4, 'Excessive spamming');
SELECT doki8902.func_log_user_restrict(5, 'Inappropriate content');
INSERT INTO doki8902.message_post(author_id, category_id, name, latest_content) VALUES
(4, 1, 'Best practices for data security', 'It''s crucial to keep your software updated to avoid security breaches.'),
(1, 2, 'Grilling tips for beginners', 'Always preheat your grill for at least 15 minutes.'),
(7, 3, 'Upcoming RPG games 2024', 'Anyone excited about the new Dragon Quest release?'),
(2, 4, 'Book recommendations for historical fiction', 'I just finished "The Nightingale" and loved it!'),
(10, 5, 'Which director makes the best thrillers?', 'I think Christopher Nolan does a great job with complex narratives.'),
(3, 6, 'Is tennis the most physically demanding sport?', 'The agility and stamina required are intense.'),
(5, 7, 'Budget-friendly European destinations', 'Portugal is quite affordable and beautiful.'),
(6, 1, 'The future of quantum computing', 'Quantum computers could revolutionize how we process data.'),
(8, 2, 'What''s your favorite type of cheese?', 'I can never get enough of Gouda!'),
(9, 5, 'Horror movies that are actually scary', 'The Conjuring series still gives me chills.');
INSERT INTO doki8902.message_comment(author_id, post_id, latest_content, parent_comment_id) VALUES
(9, 1, 'Absolutely! Regular updates are a must.', NULL),
(8, 2, 'Thanks for the tip! Any specific grills you recommend?', NULL),
(2, 2, 'Charcoal grills give the best flavor in my opinion.', NULL),
(7, 3, 'I heard it''s coming out next fall.', NULL),
(3, 3, 'Can''t wait for it, it sounds amazing!', NULL),
(8, 4, 'I love historical fiction too, any other suggestions?', NULL),
(1, 5, 'Agreed, Nolan is a mastermind.', NULL),
(3, 5, 'What about Alfred Hitchcock?', NULL),
(5, 6, 'I think boxing might compete for that title.', NULL),
(7, 7, 'Don''t forget about Greece, especially during off-peak seasons!', NULL),
(1, 8, 'How soon do you think we''ll see practical applications?', NULL),
(7, 9, 'Cheddar is great for cooking but nothing beats Brie for snacking.', NULL),
(9, 9, 'Gouda is indeed delicious!', NULL),
(4, 10, 'Those films are great, have you seen "Insidious" as well?', NULL);
INSERT INTO doki8902.message_comment(author_id, post_id, latest_content, parent_comment_id) VALUES
(4, 1, 'That''s a good point. Do you recommend any specific antivirus software?', 11),
(9, 2, 'I''ve been looking at Weber grills, heard they''re good.', 12),
(3, 2, 'Yes, but I think gas grills are easier for beginners.', 13),
(7, 3, 'I hope they add more customization options.', 15),
(2, 4, 'You should check out "Pillars of the Earth" by Ken Follett.', 16),
(6, 5, 'True, but don''t forget about M. Night Shyamalan.', 18),
(2, 6, 'Agree on boxing, but MMA seems tougher.', 19),
(6, 7, 'Also Bulgaria in the autumn is surprisingly beautiful.', 20),
(8, 9, 'Totally agree on Brie, especially with a good wine.', 22),
(9, 10, 'Insidious was good but it doesn''t top The Conjuring for me.', 24);
INSERT INTO doki8902.message_vote(message_id, user_id, vote) VALUES
(1, 5, 1),
(2, 4, 1),
(3, 6, -1),
(4, 3, 1),
(5, 8, 1),
(8, 2, 1),
(11, 1, 1),
(12, 10, -1),
(14, 6, 1),
(15, 4, 1),
(17, 4, 1),
(19, 2, 1),
(20, 1, 1),
(22, 3, 1),
(23, 5, 1),
(25, 7, 1),
(28, 8, 1),
(31, 6, -1),
(32, 9, 1),
(34, 10, 1),
-- Adding 5 dislikes to message 10
(10, 2, -1),
(10, 6, -1),
(10, 7, -1),
(10, 8, -1),
(10, 10, -1),
-- Adding 5 dislikes to message 11
(11, 2, -1),
(11, 6, -1),
(11, 7, -1),
(11, 8, -1),
(11, 3, -1);
COMMIT;
-- ACCEPT ALL CURRENT CONTENT
SELECT doki8902.func_approve_all_pending_content();

41
db/insert_old.sql Normal file
View File

@ -0,0 +1,41 @@
-- CREATE SETUP
BEGIN;
INSERT INTO doki8902.post_category(name) VALUES
('Technology'),
('Food'),
('Games'),
('Reading'),
('Movies'),
('Sports');
COMMIT;
-- CREATE USERS
BEGIN;
INSERT INTO doki8902.user(username, password) VALUES
('Alice', 'pass123'),
('Bob', 'qwerty'),
('Charlie', 'abc456'),
('BotAccount', 'qwertyasdf');
INSERT INTO doki8902.user_permission(user_id, permission, state) VALUES
(1, 'delete', TRUE),
(1, 'edit', TRUE),
(2, 'admin', TRUE),
(4, 'post', FALSE);
COMMIT;
-- NORMAL USE
SELECT doki8902.func_log_user_restrict(2, 'Spam and botting');
INSERT INTO message_post(author_id, category_id, name, latest_content) VALUES
(3, 2, 'What''s your favorite dessert?', 'Personally, I like Ice Cream');
INSERT INTO message_comment (author_id, post_id, latest_content, parent_comment_id) VALUES
(2, 1, 'Chocolate Mousse', NULL);

24
db/insertp2.sql Normal file
View File

@ -0,0 +1,24 @@
-- EDITS
UPDATE doki8902.message_comment SET latest_content = 'I heard it''s coming out next fall. Does anyone know if there will be VR support?' WHERE id = 14;
UPDATE doki8902.message_comment SET latest_content = 'I love historical fiction too. Could anyone recommend other novels similar to "The Nightingale"?' WHERE id = 16;
UPDATE doki8902.message_comment SET latest_content = 'Agreed, Christopher Nolan''s storytelling is brilliant, especially in movies like ''Inception''.' WHERE id = 17;
UPDATE doki8902.message_comment SET latest_content = 'Actually, I''ve come to think that marathon running might top them all in terms of endurance and physical demand.' WHERE id = 19;
UPDATE doki8902.message_comment SET latest_content = 'I''ve started to really enjoy Manchego lately, especially with a slice of quince paste. It pairs well with both cooking and snacking!' WHERE id = 22;
-- ACCEPT ALL NEW CONTENT
SELECT doki8902.func_approve_all_pending_content();
-- DELETE A USER
DELETE FROM doki8902.user WHERE id = 4;
-- DELETE MESSAGES SOFT
UPDATE doki8902.message_comment SET soft_delete = TRUE WHERE id IN (18, 19, 20);
-- DELETE POST HARD
DELETE FROM doki8902.post WHERE message_id = 2;

1
db/schema.sql Normal file
View File

@ -0,0 +1 @@
CREATE SCHEMA IF NOT EXISTS doki8092;

63
db/tests.sql Normal file
View File

@ -0,0 +1,63 @@
-- CANT HAVE SAME USERNAME
INSERT INTO doki8902.user(username, password) VALUES ('Frank', 'admin123');
-- CANT HAVE INVALID USERNAME
INSERT INTO doki8902.user(username, password) VALUES ('Frank@', 'admin123');
INSERT INTO doki8902.user(username, password) VALUES ('1', 'admin123');
INSERT INTO doki8902.user(username, password) VALUES ('ABCDEABCDE1234512345ABCDEABCDE1234512345', 'admin123');
-- CANT HAVE REPEATING CATEGORIES
INSERT INTO doki8902.post_category(name) VALUES ('Technology');
-- CANT POST WITH INVALID AUTHOR
INSERT INTO message_post(author_id, category_id, name, latest_content) VALUES
(100, 1, 'Best practices for data security', 'It''s crucial to keep your software updated to avoid security breaches.');
-- CANT POST FOR NON EXISTENT CATEGORY
INSERT INTO message_post(author_id, category_id, name, latest_content) VALUES
(2, 100, 'Best practices for data security', 'It''s crucial to keep your software updated to avoid security breaches.');
-- CANT COMMENT WITH INVALID AUTHOR
INSERT INTO message_comment(author_id, post_id, latest_content, parent_comment_id) VALUES
(100, 1, 'Absolutely! Regular updates are a must.', NULL);
-- CANT COMMENT FOR INVALID POST
INSERT INTO message_comment(author_id, post_id, latest_content, parent_comment_id) VALUES
(1, 100, 'Absolutely! Regular updates are a must.', NULL);
-- CANT VOTE TWICE
INSERT INTO doki8902.message_vote(message_id, user_id, vote) VALUES
(1, 4, 1);
-- CANT VOTE NOT SUPPORTED VALUES
INSERT INTO doki8902.message_vote(message_id, user_id, vote) VALUES
(1, 5, 5);
-- CANT VOTE WITH INVALID IDS
INSERT INTO doki8902.message_vote(message_id, user_id, vote) VALUES (100, 5, 1);
INSERT INTO doki8902.message_vote(message_id, user_id, vote) VALUES (1, 100, 1);
-- CANT REPLY TO COMMENT THAT DOES NOT EXISTS IN POST
INSERT INTO doki8902.message_comment(author_id, post_id, latest_content, parent_comment_id) VALUES
(11, 3, 'test', 20);
-- CANT POST EMPTY MESSAGES
INSERT INTO message_post(author_id, category_id, name, latest_content) VALUES (2, 1, '', 'Content');
INSERT INTO message_post(author_id, category_id, name, latest_content) VALUES (2, 1, 'Name', '');
INSERT INTO doki8902.message_comment(author_id, post_id, latest_content, parent_comment_id) VALUES (11, 1, '', NULL);
-- CANT POST WITHOUT AN EXISTING USER
INSERT INTO message_post(author_id, category_id, name, latest_content) VALUES (NULL, 1, 'Name', 'Content');