Moves schema from SQLite3 to MySQL

This commit is contained in:
Oleg Silkin 2020-04-07 16:16:15 -04:00
parent 0817b70083
commit 3b91279cc7
3 changed files with 44 additions and 201 deletions

View file

@ -1,55 +0,0 @@
USE `social`;
ALTER DATABASE `social`
DEFAULT CHARACTER SET utf8mb4
DEFAULT COLLATE utf8mb4_unicode_ci;
DROP TABLE IF EXISTS `CHANNEL`;
CREATE TABLE `CHANNEL` (
`claimid` VARCHAR(40) NOT NULL,
`name` CHAR(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL,
CONSTRAINT `channel_pk` PRIMARY KEY (`claimid`)
)
CHARACTER SET utf8mb4
COLLATE utf8mb4_unicode_ci;
DROP TABLE IF EXISTS `COMMENT`;
CREATE TABLE `COMMENT` (
-- should be changed to CHAR(64)
`commentid` CHAR(64) NOT NULL,
-- should be changed to CHAR(40)
`lbryclaimid` CHAR(40) NOT NULL,
-- can be null, so idk if this should be char(40)
`channelid` CHAR(40) DEFAULT NULL,
`body` TEXT
CHARACTER SET utf8mb4
COLLATE utf8mb4_unicode_ci
NOT NULL,
`parentid` CHAR(64) DEFAULT NULL,
`signature` CHAR(128) DEFAULT NULL,
-- 22 chars long is prolly enough
`signingts` VARCHAR(22) DEFAULT NULL,
`timestamp` INTEGER NOT NULL,
-- there's no way that the timestamp will ever reach 22 characters
`ishidden` BOOLEAN DEFAULT FALSE,
CONSTRAINT `COMMENT_PRIMARY_KEY` PRIMARY KEY (`commentid`)
-- setting null implies comment is top level
)
CHARACTER SET utf8mb4
COLLATE utf8mb4_unicode_ci;
ALTER TABLE COMMENT
ADD CONSTRAINT `comment_channel_fk` FOREIGN KEY (`channelid`) REFERENCES `CHANNEL` (`claimid`)
ON DELETE CASCADE ON UPDATE CASCADE,
ADD CONSTRAINT `comment_parent_fk` FOREIGN KEY (`parentid`) REFERENCES `COMMENT` (`commentid`)
ON UPDATE CASCADE ON DELETE CASCADE
;
CREATE INDEX `claim_comment_index` ON `COMMENT` (`lbryclaimid`, `commentid`);
CREATE INDEX `channel_comment_index` ON `COMMENT` (`channelid`, `commentid`);
ALTER TABLE COMMENT ADD CONSTRAINT UNIQUE (`signature`, `channelid`);

View file

@ -1,76 +1,50 @@
PRAGMA FOREIGN_KEYS = ON;
USE `social`;
ALTER DATABASE `social`
DEFAULT CHARACTER SET utf8mb4
DEFAULT COLLATE utf8mb4_unicode_ci;
-- Although I know this file is unnecessary, I like keeping it around.
DROP TABLE IF EXISTS `CHANNEL`;
CREATE TABLE `CHANNEL` (
`claimid` VARCHAR(40) NOT NULL,
`name` CHAR(255) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL,
CONSTRAINT `channel_pk` PRIMARY KEY (`claimid`)
)
CHARACTER SET utf8mb4
COLLATE utf8mb4_unicode_ci;
-- I'm not gonna remove it.
DROP TABLE IF EXISTS `COMMENT`;
CREATE TABLE `COMMENT` (
-- should be changed to CHAR(64)
`commentid` CHAR(64) NOT NULL,
-- should be changed to CHAR(40)
`lbryclaimid` CHAR(40) NOT NULL,
-- can be null, so idk if this should be char(40)
`channelid` CHAR(40) DEFAULT NULL,
`body` TEXT
CHARACTER SET utf8mb4
COLLATE utf8mb4_unicode_ci
NOT NULL,
`parentid` CHAR(64) DEFAULT NULL,
`signature` CHAR(128) DEFAULT NULL,
-- 22 chars long is prolly enough
`signingts` VARCHAR(22) DEFAULT NULL,
-- tables
CREATE TABLE IF NOT EXISTS COMMENT
(
CommentId TEXT NOT NULL,
LbryClaimId TEXT NOT NULL,
ChannelId TEXT DEFAULT NULL,
Body TEXT NOT NULL,
ParentId TEXT DEFAULT NULL,
Signature TEXT DEFAULT NULL,
Timestamp INTEGER NOT NULL,
SigningTs TEXT DEFAULT NULL,
IsHidden BOOLEAN NOT NULL DEFAULT FALSE,
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
);
-- ALTER TABLE COMMENT ADD COLUMN IsHidden BOOLEAN DEFAULT (FALSE);
-- ALTER TABLE COMMENT ADD COLUMN SigningTs TEXT DEFAULT NULL;
-- DROP TABLE IF EXISTS CHANNEL;
CREATE TABLE IF NOT EXISTS CHANNEL
(
ClaimId TEXT NOT NULL,
Name TEXT NOT NULL,
CONSTRAINT CHANNEL_PK PRIMARY KEY (ClaimId)
ON CONFLICT IGNORE
);
`timestamp` INTEGER NOT NULL,
-- there's no way that the timestamp will ever reach 22 characters
`ishidden` BOOLEAN DEFAULT FALSE,
CONSTRAINT `COMMENT_PRIMARY_KEY` PRIMARY KEY (`commentid`)
-- setting null implies comment is top level
)
CHARACTER SET utf8mb4
COLLATE utf8mb4_unicode_ci;
-- indexes
-- DROP INDEX IF EXISTS COMMENT_CLAIM_INDEX;
-- CREATE INDEX IF NOT EXISTS CLAIM_COMMENT_INDEX ON COMMENT (LbryClaimId, CommentId);
ALTER TABLE COMMENT
ADD CONSTRAINT `comment_channel_fk` FOREIGN KEY (`channelid`) REFERENCES `CHANNEL` (`claimid`)
ON DELETE CASCADE ON UPDATE CASCADE,
ADD CONSTRAINT `comment_parent_fk` FOREIGN KEY (`parentid`) REFERENCES `COMMENT` (`commentid`)
ON UPDATE CASCADE ON DELETE CASCADE
;
-- CREATE INDEX IF NOT EXISTS CHANNEL_COMMENT_INDEX ON COMMENT (ChannelId, CommentId);
-- VIEWS
CREATE VIEW IF NOT EXISTS COMMENTS_ON_CLAIMS AS
SELECT C.CommentId AS comment_id,
C.Body AS comment,
C.LbryClaimId AS claim_id,
C.Timestamp AS timestamp,
CHAN.Name AS channel_name,
CHAN.ClaimId AS channel_id,
('lbry://' || CHAN.Name || '#' || CHAN.ClaimId) AS channel_url,
C.Signature AS signature,
C.SigningTs AS signing_ts,
C.ParentId AS parent_id,
C.IsHidden AS is_hidden
FROM COMMENT AS C
LEFT OUTER JOIN CHANNEL CHAN ON C.ChannelId = CHAN.ClaimId
ORDER BY C.Timestamp DESC;
DROP VIEW IF EXISTS COMMENT_REPLIES;
CREATE VIEW IF NOT EXISTS 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;
-- this is the default channel for anyone who wants to publish anonymously
-- INSERT INTO CHANNEL
-- VALUES ('9cb713f01bf247a0e03170b5ed00d5161340c486', '@Anonymous');
CREATE INDEX `claim_comment_index` ON `COMMENT` (`lbryclaimid`, `commentid`);
CREATE INDEX `channel_comment_index` ON `COMMENT` (`channelid`, `commentid`);

View file

@ -1,76 +0,0 @@
PRAGMAS = """
PRAGMA FOREIGN_KEYS = ON;
"""
CREATE_COMMENT_TABLE = """
CREATE TABLE IF NOT EXISTS COMMENT (
CommentId TEXT NOT NULL,
LbryClaimId TEXT NOT NULL,
ChannelId TEXT DEFAULT NULL,
Body TEXT NOT NULL,
ParentId TEXT DEFAULT NULL,
Signature TEXT DEFAULT NULL,
Timestamp INTEGER NOT NULL,
SigningTs TEXT DEFAULT NULL,
IsHidden BOOLEAN NOT NULL DEFAULT 0,
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
);
"""
CREATE_COMMENT_INDEXES = """
CREATE INDEX IF NOT EXISTS CLAIM_COMMENT_INDEX ON COMMENT (LbryClaimId, CommentId);
CREATE INDEX IF NOT EXISTS CHANNEL_COMMENT_INDEX ON COMMENT (ChannelId, CommentId);
"""
CREATE_CHANNEL_TABLE = """
CREATE TABLE IF NOT EXISTS CHANNEL (
ClaimId TEXT NOT NULL,
Name TEXT NOT NULL,
CONSTRAINT CHANNEL_PK PRIMARY KEY (ClaimId)
ON CONFLICT IGNORE
);
"""
CREATE_COMMENTS_ON_CLAIMS_VIEW = """
CREATE VIEW IF NOT EXISTS COMMENTS_ON_CLAIMS AS SELECT
C.CommentId AS comment_id,
C.Body AS comment,
C.LbryClaimId AS claim_id,
C.Timestamp AS timestamp,
CHAN.Name AS channel_name,
CHAN.ClaimId AS channel_id,
('lbry://' || CHAN.Name || '#' || CHAN.ClaimId) AS channel_url,
C.Signature AS signature,
C.SigningTs AS signing_ts,
C.ParentId AS parent_id,
C.IsHidden AS is_hidden
FROM COMMENT AS C
LEFT OUTER JOIN CHANNEL CHAN ON C.ChannelId = CHAN.ClaimId
ORDER BY C.Timestamp DESC;
"""
# not being used right now but should be kept around when Tom finally asks for replies
CREATE_COMMENT_REPLIES_VIEW = """
CREATE VIEW IF NOT EXISTS 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;
"""
CREATE_TABLES_QUERY = (
PRAGMAS +
CREATE_COMMENT_TABLE +
CREATE_COMMENT_INDEXES +
CREATE_CHANNEL_TABLE +
CREATE_COMMENTS_ON_CLAIMS_VIEW +
CREATE_COMMENT_REPLIES_VIEW
)