diff --git a/README.md b/README.md index 722b361..d762742 100644 --- a/README.md +++ b/README.md @@ -15,7 +15,7 @@ following: e.g. for Python3.6, you would install `python36-dev`. You're smart enough to figure the rest out from here ;) 3. (Optional) Reverse Proxy software to handle a public-facing API. We recommend Caddy, though there is an `nginx.conf` file under `config`. - 4. Patience (Strongly recommended but often neglected) + 5. Patience (Strongly recommended but often neglected) ## Installation diff --git a/src/schema/comments_ddl.sql b/src/schema/comments_ddl.sql new file mode 100644 index 0000000..c7c5d15 --- /dev/null +++ b/src/schema/comments_ddl.sql @@ -0,0 +1,64 @@ + +PRAGMA FOREIGN_KEYS = ON; + +-- tables +-- DROP TABLE IF EXISTS COMMENT; +-- DROP TABLE IF EXISTS CHANNEL; + +-- DROP TABLE IF EXISTS COMMENT; +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, + 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 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 +); + + +-- indexes +-- DROP INDEX IF EXISTS COMMENT_CLAIM_INDEX; +CREATE INDEX IF NOT EXISTS CLAIM_COMMENT_INDEX ON COMMENT (LbryClaimId, CommentId); + +CREATE INDEX IF NOT EXISTS CHANNEL_COMMENT_INDEX ON COMMENT(ChannelId, CommentId); + +-- VIEWS +DROP VIEW IF EXISTS COMMENTS_ON_CLAIMS; +CREATE VIEW IF NOT EXISTS COMMENTS_ON_CLAIMS (comment_id, claim_id, timestamp, channel_name, channel_id, channel_url, signature, signing_ts, parent_id, comment) AS + SELECT C.CommentId, C.LbryClaimId, C.Timestamp, CHAN.Name, CHAN.ClaimId, 'lbry://' || CHAN.Name || '#' || CHAN.ClaimId, C.Signature, C.SigningTs, C.ParentId, C.Body + 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'); diff --git a/src/schema/db_helpers.py b/src/schema/db_helpers.py new file mode 100644 index 0000000..24ce26e --- /dev/null +++ b/src/schema/db_helpers.py @@ -0,0 +1,28 @@ +import logging +import sqlite3 + +logger = logging.getLogger(__name__) + + +def setup_database(db_path, schema_path): + logger.info(f'Creating db schema from {schema_path} in {db_path}') + with sqlite3.connect(db_path) as conn: + with open(schema_path, 'r') as ddl: + with conn: + conn.executescript(ddl.read()) + + +def teardown_database(db_path): + logger.info('Dropping all tables from %s', db_path) + with sqlite3.connect(db_path) as conn: + conn.executescript(""" + DROP VIEW IF EXISTS COMMENTS_ON_CLAIMS; + DROP VIEW IF EXISTS COMMENT_REPLIES; + DROP TABLE IF EXISTS COMMENT; + DROP TABLE IF EXISTS CHANNEL; + """) + + +def backup_database(conn: sqlite3.Connection, back_fp): + with sqlite3.connect(back_fp) as back: + conn.backup(back)