Modifies the schema a whole lot
This commit is contained in:
parent
e2591b7d42
commit
aee2c3e5aa
1 changed files with 56 additions and 17 deletions
|
@ -1,34 +1,73 @@
|
|||
-- ATTACH DATABASE 'comments.db' AS Comments;
|
||||
|
||||
PRAGMA FOREIGN_KEYS = ON;
|
||||
|
||||
|
||||
-- tables
|
||||
DROP TABLE IF EXISTS COMMENT;
|
||||
DROP TABLE IF EXISTS CHANNEL;
|
||||
CREATE TABLE IF NOT EXISTS CHANNEL(
|
||||
ClaimId TEXT NOT NULL,
|
||||
Name TEXT NOT NULL,
|
||||
Timestamp INTEGER DEFAULT NULL,
|
||||
CONSTRAINT CHANNEL_PK PRIMARY KEY (ClaimId)
|
||||
ON CONFLICT IGNORE,
|
||||
CONSTRAINT CHANNEL_NAME_LEN
|
||||
CHECK ( 0 < length(Name) AND length(Name) <= 120)
|
||||
ON CONFLICT IGNORE
|
||||
);
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
DROP TABLE IF EXISTS COMMENT;
|
||||
CREATE TABLE IF NOT EXISTS COMMENT (
|
||||
CommentId INTEGER NOT NULL,
|
||||
CommentId TEXT NOT NULL,
|
||||
LbryClaimId TEXT NOT NULL,
|
||||
ChannelId TEXT NOT NULL,
|
||||
ChannelId TEXT DEFAULT NULL,
|
||||
Body TEXT NOT NULL,
|
||||
ParentId INTEGER DEFAULT NULL,
|
||||
Timestamp DATETIME,
|
||||
CONSTRAINT COMMENT_ID_PK PRIMARY KEY (CommentId)
|
||||
ON CONFLICT ABORT,
|
||||
ParentId TEXT DEFAULT NULL,
|
||||
Signature TEXT DEFAULT NULL,
|
||||
Timestamp INTEGER NOT NULL,
|
||||
CONSTRAINT COMMENT_PRIMARY_KEY PRIMARY KEY (CommentId) ON CONFLICT IGNORE,
|
||||
CONSTRAINT COMMENT_SIGNATURE_SK UNIQUE (Signature) ON CONFLICT ABORT,
|
||||
CONSTRAINT COMMENT_CHANNEL_FK FOREIGN KEY (ChannelId) REFERENCES CHANNEL(ClaimId)
|
||||
ON DELETE NO ACTION ON UPDATE NO ACTION,
|
||||
CONSTRAINT COMMENT_PARENT_FK FOREIGN KEY (ParentId) REFERENCES COMMENT(CommentId)
|
||||
ON UPDATE CASCADE ON DELETE NO ACTION, -- setting null implies comment is top level
|
||||
CONSTRAINT COMMENT_BODY_LEN CHECK(1 < length(Body) AND length(Body) <= 2000)
|
||||
ON UPDATE CASCADE ON DELETE NO ACTION -- setting null implies comment is top level
|
||||
);
|
||||
|
||||
-- indexes
|
||||
DROP INDEX IF EXISTS COMMENT_CLAIM_INDEX;
|
||||
CREATE INDEX COMMENT_CLAIM_INDEX ON COMMENT (LbryClaimId);
|
||||
|
||||
-- triggers
|
||||
DROP TRIGGER IF EXISTS CHANNEL_INSERT_VALIDATE;
|
||||
CREATE TRIGGER CHANNEL_INSERT_VALIDATE
|
||||
BEFORE INSERT ON CHANNEL
|
||||
WHEN NOT (0 < LENGTH(NEW.Name AND LENGTH(NEW.Name) < 256))
|
||||
BEGIN
|
||||
SELECT RAISE(FAIL, 'EITHER CHANNEL_ID OR CHANNEL_NAME ARE INVALID LENGTH');
|
||||
END;
|
||||
|
||||
-- todo: remove this shit
|
||||
DROP TRIGGER IF EXISTS COMMENT_INSERT_VALIDATE;
|
||||
CREATE TRIGGER COMMENT_INSERT_VALIDATE
|
||||
BEFORE INSERT ON COMMENT
|
||||
WHEN NOT (0 < LENGTH(NEW.Body) AND LENGTH(NEW.Body) <= 2000)
|
||||
BEGIN
|
||||
SELECT RAISE(FAIL, 'INVALID COMMENT BODY LENGTH');
|
||||
end;
|
||||
|
||||
-- VIEWS
|
||||
DROP VIEW IF EXISTS COMMENTS_ON_CLAIMS;
|
||||
CREATE VIEW COMMENTS_ON_CLAIMS (comment_id, claim_id, timestamp, channel_name, channel_id, channel_uri, comment, parent_id) AS
|
||||
SELECT C.CommentId, C.LbryClaimId, C.Timestamp, CHAN.Name, CHAN.ClaimId, 'lbry://' || '@' || CHAN.Name || '#' || CHAN.ClaimId, C.Body, C.ParentId
|
||||
FROM CHANNEL AS CHAN
|
||||
INNER JOIN COMMENT C on CHAN.ClaimId = C.ChannelId
|
||||
ORDER BY C.Timestamp;
|
||||
|
||||
|
||||
|
||||
DROP VIEW IF EXISTS COMMENT_REPLIES;
|
||||
CREATE VIEW COMMENT_REPLIES (Author, CommentBody, ParentAuthor, ParentCommentBody) AS
|
||||
SELECT AUTHOR.Name, OG.Body, PCHAN.Name, PARENT.Body FROM COMMENT AS OG
|
||||
JOIN COMMENT AS PARENT
|
||||
ON OG.ParentId = PARENT.CommentId
|
||||
JOIN CHANNEL AS PCHAN ON PARENT.ChannelId = PCHAN.ClaimId
|
||||
JOIN CHANNEL AS AUTHOR ON OG.ChannelId = AUTHOR.ClaimId
|
||||
ORDER BY OG.Timestamp;
|
||||
|
||||
|
||||
|
|
Loading…
Reference in a new issue