Blasta/blasta.sql
Schimon Jehudah, Adv. d03a76db23 SQLite: Add an SQL script to generate the SQLite database;
CSS   : Remove property height from element ID 'related-tags'.
2024-11-17 16:24:16 +02:00

310 lines
6.7 KiB
SQL

-- Blasta SQLite database script.
CREATE TABLE IF NOT EXISTS main_entries (
id INTEGER NOT NULL,
url_hash TEXT NOT NULL UNIQUE,
url TEXT NOT NULL UNIQUE,
title TEXT NOT NULL,
summary TEXT,
jid_id TEXT NOT NULL,
date_first TEXT NOT NULL,
date_last TEXT NOT NULL,
instances INTEGER NOT NULL DEFAULT 1,
PRIMARY KEY ("id")
);
CREATE TABLE IF NOT EXISTS main_jids (
id INTEGER NOT NULL,
jid TEXT NOT NULL UNIQUE,
opt_in INTEGER NOT NULL DEFAULT 0,
PRIMARY KEY ("id")
);
CREATE TABLE IF NOT EXISTS main_tags (
id INTEGER NOT NULL,
tag TEXT NOT NULL UNIQUE,
instances INTEGER NOT NULL DEFAULT 1,
PRIMARY KEY ("id")
);
CREATE TABLE IF NOT EXISTS main_statistics (
id INTEGER NOT NULL,
type TEXT NOT NULL UNIQUE,
count INTEGER NOT NULL DEFAULT 0,
PRIMARY KEY ("id")
);
INSERT
INTO main_statistics(
type)
VALUES ('entries'),
('jids'),
('tags');
CREATE TABLE IF NOT EXISTS combination_entries_tags_jids (
id INTEGER NOT NULL,
entry_id INTEGER NOT NULL,
tag_id INTEGER NOT NULL,
jid_id INTEGER NOT NULL,
FOREIGN KEY ("entry_id") REFERENCES "main_entries" ("id")
ON UPDATE CASCADE
ON DELETE CASCADE,
FOREIGN KEY ("tag_id") REFERENCES "main_tags" ("id")
ON UPDATE CASCADE
ON DELETE CASCADE,
FOREIGN KEY ("jid_id") REFERENCES "main_jids" ("id")
ON UPDATE CASCADE
ON DELETE CASCADE,
PRIMARY KEY ("id")
);
-- NOTE Digit for JID which is authorized;
-- Zero (0) for private;
-- Empty (no row) for public.
CREATE TABLE IF NOT EXISTS authorization_entries_jids (
id INTEGER NOT NULL,
entry_id INTEGER NOT NULL,
jid_id INTEGER NOT NULL,
authorization INTEGER NOT NULL,
FOREIGN KEY ("entry_id") REFERENCES "main_entries" ("id")
ON UPDATE CASCADE
ON DELETE CASCADE,
FOREIGN KEY ("jid_id") REFERENCES "main_jids" ("id")
ON UPDATE CASCADE
ON DELETE CASCADE,
PRIMARY KEY ("id")
);
CREATE TABLE IF NOT EXISTS report_entries (
id INTEGER NOT NULL,
url_hash_subject TEXT NOT NULL,
jid_reporter TEXT NOT NULL,
type TEXT,
comment TEXT,
PRIMARY KEY ("id")
);
CREATE TABLE IF NOT EXISTS report_jids (
id INTEGER NOT NULL,
jid_subject TEXT NOT NULL,
jid_reporter TEXT NOT NULL,
type TEXT,
comment TEXT,
PRIMARY KEY ("id")
);
CREATE TRIGGER instances_entry_decrease
AFTER DELETE ON combination_entries_tags_jids
FOR EACH ROW
BEGIN
UPDATE main_entries
SET instances = (
SELECT COUNT(DISTINCT jid_id)
FROM combination_entries_tags_jids
WHERE entry_id = OLD.entry_id
)
WHERE id = OLD.entry_id;
END;
CREATE TRIGGER instances_entry_increase
AFTER INSERT ON combination_entries_tags_jids
FOR EACH ROW
BEGIN
UPDATE main_entries
SET instances = (
SELECT COUNT(DISTINCT jid_id)
FROM combination_entries_tags_jids
WHERE entry_id = NEW.entry_id
)
WHERE id = NEW.entry_id;
END;
CREATE TRIGGER instances_entry_update
AFTER UPDATE ON combination_entries_tags_jids
FOR EACH ROW
BEGIN
-- Decrease instances for the old tag_id
UPDATE main_entries
SET instances = (
SELECT COUNT(DISTINCT jid_id)
FROM combination_entries_tags_jids
WHERE entry_id = OLD.entry_id
)
WHERE id = OLD.entry_id;
-- Increase instances for the new tag_id
UPDATE main_entries
SET instances = (
SELECT COUNT(DISTINCT jid_id)
FROM combination_entries_tags_jids
WHERE entry_id = NEW.entry_id
)
WHERE id = NEW.entry_id;
END;
CREATE TRIGGER instances_tag_decrease
AFTER DELETE ON combination_entries_tags_jids
FOR EACH ROW
BEGIN
UPDATE main_tags
SET instances = (
SELECT COUNT(*)
FROM combination_entries_tags_jids
WHERE tag_id = OLD.tag_id
)
WHERE id = OLD.tag_id;
END;
CREATE TRIGGER instances_tag_increase
AFTER INSERT ON combination_entries_tags_jids
FOR EACH ROW
BEGIN
UPDATE main_tags
SET instances = (
SELECT COUNT(*)
FROM combination_entries_tags_jids
WHERE tag_id = NEW.tag_id
)
WHERE id = NEW.tag_id;
END;
CREATE TRIGGER instances_tag_update
AFTER UPDATE ON combination_entries_tags_jids
FOR EACH ROW
BEGIN
-- Decrease instances for the old tag_id
UPDATE main_tags
SET instances = (
SELECT COUNT(*)
FROM combination_entries_tags_jids
WHERE tag_id = OLD.tag_id
)
WHERE id = OLD.tag_id;
-- Increase instances for the new tag_id
UPDATE main_tags
SET instances = (
SELECT COUNT(*)
FROM combination_entries_tags_jids
WHERE tag_id = NEW.tag_id
)
WHERE id = NEW.tag_id;
END;
CREATE TRIGGER entry_count_increase
AFTER INSERT ON main_entries
BEGIN
UPDATE main_statistics
SET count = (
SELECT COUNT(*)
FROM main_entries
)
WHERE type = 'entries';
END;
CREATE TRIGGER entry_count_decrease
AFTER DELETE ON main_entries
BEGIN
UPDATE main_statistics
SET count = (
SELECT COUNT(*)
FROM main_entries
)
WHERE type = 'entries';
END;
CREATE TRIGGER entry_count_update
AFTER UPDATE ON main_entries
BEGIN
UPDATE main_statistics
SET count = (
SELECT COUNT(*)
FROM main_entries
)
WHERE type = 'entries';
END;
CREATE TRIGGER entry_remove
AFTER UPDATE ON main_entries
FOR EACH ROW
WHEN NEW.instances < 1
BEGIN
DELETE FROM main_entries WHERE id = OLD.id;
END;
CREATE TRIGGER jid_count_increase
AFTER INSERT ON main_jids
BEGIN
UPDATE main_statistics
SET count = (
SELECT COUNT(*)
FROM main_jids
)
WHERE type = 'jids';
END;
CREATE TRIGGER jid_count_decrease
AFTER DELETE ON main_jids
BEGIN
UPDATE main_statistics
SET count = (
SELECT COUNT(*)
FROM main_jids
)
WHERE type = 'jids';
END;
CREATE TRIGGER jid_count_update
AFTER UPDATE ON main_jids
BEGIN
UPDATE main_statistics
SET count = (
SELECT COUNT(*)
FROM main_jids
)
WHERE type = 'jids';
END;
CREATE TRIGGER tag_count_increase
AFTER INSERT ON main_tags
BEGIN
UPDATE main_statistics
SET count = (
SELECT COUNT(*)
FROM main_tags
)
WHERE type = 'tags';
END;
CREATE TRIGGER tag_count_decrease
AFTER DELETE ON main_tags
BEGIN
UPDATE main_statistics
SET count = (
SELECT COUNT(*)
FROM main_tags
)
WHERE type = 'tags';
END;
CREATE TRIGGER tag_count_update
AFTER UPDATE ON main_tags
BEGIN
UPDATE main_statistics
SET count = (
SELECT COUNT(*)
FROM main_tags
)
WHERE type = 'tags';
END;
CREATE TRIGGER tag_remove
AFTER UPDATE ON main_tags
FOR EACH ROW
WHEN NEW.instances < 1
BEGIN
DELETE FROM main_tags WHERE id = OLD.id;
END;