dragon_fire/docker_dev/mysql_schema.sql

107 lines
No EOL
2.4 KiB
SQL

CREATE DATABASE dragon_fire;
USE dragon_fire;
-- DROP TABLE posts;
-- DROP TABLE path_access_counts;
-- DROP TABLE path_errcodes;
-- DROP TABLE feed_cache;
CREATE TABLE dev_posts (
post_id INTEGER AUTO_INCREMENT,
post_path VARCHAR(255) NOT NULL,
post_path_depth INTEGER NOT NULL DEFAULT 0,
post_created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
post_updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
post_view_count INTEGER DEFAULT 0,
post_title VARCHAR(1024),
post_tags VARCHAR(1024),
post_brief TEXT(2048),
post_metadata JSON DEFAULT NULL,
post_settings_cache JSON DEFAULT NULL,
post_counters JSON DEFAULT NULL,
PRIMARY KEY(post_id),
CONSTRAINT unique_post UNIQUE (post_path),
INDEX(post_path),
INDEX(post_path_depth, post_path),
INDEX(post_created_at),
INDEX(post_updated_at),
FULLTEXT(post_path),
FULLTEXT(post_tags),
FULLTEXT(post_title),
FULLTEXT(post_brief)
);
CREATE TABLE dev_post_markdown (
post_id INTEGER,
post_markdown TEXT,
PRIMARY KEY(post_id),
FOREIGN KEY(post_id) REFERENCES dev_posts(post_id)
ON DELETE CASCADE,
FULLTEXT(post_markdown)
);
CREATE TABLE dev_feeds (
post_id INTEGER NOT NULL,
feed_key VARCHAR(32),
feed_id VARCHAR(40) NOT NULL,
feed_created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
feed_metadata JSON DEFAULT NULL,
feed_text TEXT,
-- Primary key as true ID to allow for deterministic saving/recreating
CONSTRAINT PK_FEED PRIMARY KEY(post_id, feed_key, feed_id),
FOREIGN KEY(post_id) REFERENCES dev_posts(post_id)
ON DELETE CASCADE,
-- Make it possible to look up changes from e.g. a commit hash inexpensively
INDEX(feed_id),
-- Make it possible to look up specific post feeds efficiently (e.g. changelog)
INDEX(post_id, feed_key, feed_created_at),
-- Make it possible to globally look up specific feeds efficiently
INDEX(feed_key, feed_created_at),
-- And just in general, make searching feeds in a timeframe efficient
INDEX(feed_created_at),
FULLTEXT(feed_text)
);
CREATE TABLE analytics_summations (
time_bucket DATETIME NOT NULL,
metric VARCHAR(16) NOT NULL,
tags JSON NOT NULL,
metric_value DOUBLE PRECISION DEFAULT 0,
tags_md5 CHAR(32) AS (MD5(tags)),
INDEX(time_bucket, metric),
CONSTRAINT unique_analytic UNIQUE(time_bucket, metric, tags_md5)
);
CREATE TABLE analytics_events (
event_time DATETIME NOT NULL,
metric VARCHAR(64) NOT NULL DEFAULT 'error_msg',
tags JSON NOT NULL,
event_text TEXT,
INDEX(event_time)
);