Bluemage/schemas/migrations/20240808143100_create_images_table.sql

90 lines
3.1 KiB
SQL

-- +goose Up
-- +goose StatementBegin
CREATE TABLE images(
id INTEGER PRIMARY KEY AUTOINCREMENT,
subreddit VARCHAR(255) NOT NULL COLLATE NOCASE,
device VARCHAR(250) NOT NULL COLLATE NOCASE,
post_title VARCHAR(255) NOT NULL,
post_name VARCHAR(255) NOT NULL,
post_url VARCHAR(255) NOT NULL,
post_created BIGINT NOT NULL DEFAULT CURRENT_TIMESTAMP,
post_author VARCHAR(50) NOT NULL,
post_author_url VARCHAR(255) NOT NULL,
image_relative_path VARCHAR(255) NOT NULL,
image_original_url VARCHAR(255) NOT NULL,
image_height INTEGER NOT NULL DEFAULT 0,
image_width INTEGER NOT NULL DEFAULT 0,
image_size BIGINT NOT NULL DEFAULT 0,
thumbnail_relative_path VARCHAR(255) NOT NULL DEFAULT '',
nsfw TINYINT NOT NULL DEFAULT 0,
blacklisted TINYINT NOT NULL DEFAULT 0,
created_at BIGINT NOT NULL DEFAULT (strftime('%s', 'now')),
updated_at BIGINT NOT NULL DEFAULT (strftime('%s', 'now')),
CONSTRAINT fk_image_subreddit
FOREIGN KEY (subreddit)
REFERENCES subreddits(name)
ON DELETE CASCADE,
CONSTRAINT fk_image_devices_slug
FOREIGN KEY (device)
REFERENCES devices(slug)
ON DELETE CASCADE,
CONSTRAINT fk_image_subreddit_cover
FOREIGN KEY (id)
REFERENCES subreddits(cover_image_id)
);
CREATE VIRTUAL TABLE images_fts5 USING fts5(
post_author,
post_title,
post_name,
image_relative_path,
post_url,
post_author_url,
content='images',
content_rowid='id'
);
CREATE INDEX idx_subreddit_images_blacklisted ON images(subreddit, blacklisted);
CREATE INDEX idx_subreddit_device_images_blacklisted ON images(device, subreddit, blacklisted);
CREATE INDEX idx_images_nsfw_blacklisted ON images(nsfw, blacklisted);
CREATE INDEX idx_images_created_at_nsfw_blacklisted ON images(created_at DESC, nsfw, blacklisted);
CREATE INDEX idx_images_blacklisted ON images(blacklisted);
CREATE UNIQUE INDEX idx_unique_images_per_device ON images(device, post_name);
CREATE TRIGGER images_update_timestamp AFTER UPDATE ON images FOR EACH ROW
BEGIN
UPDATE images SET updated_at = strftime('%s', 'now') WHERE id = old.id;
END;
CREATE TRIGGER images_update_subreddit_cover_on_insert AFTER INSERT ON images FOR EACH ROW
BEGIN
UPDATE subreddits SET cover_image_id = new.id WHERE name = new.subreddit AND cover_image_id IS NULL;
END;
CREATE TRIGGER images_update_subreddit_cover_on_delete AFTER DELETE ON images FOR EACH ROW
BEGIN
UPDATE subreddits SET cover_image_id = NULL WHERE cover_image_id = old.id;
END;
CREATE TRIGGER images_update_fts_insert AFTER INSERT ON images FOR EACH ROW
BEGIN
INSERT INTO images_fts5(
rowid, post_author, post_title, post_name, image_relative_path, post_url, post_author_url
) VALUES(
new.id, new.post_author, new.post_title, new.post_name, new.image_relative_path, new.post_url, new.post_author_url
);
END;
CREATE TRIGGER images_update_fts_delete AFTER DELETE ON images FOR EACH ROW
BEGIN
DELETE FROM images_fts5 WHERE rowid = old.id;
END;
-- +goose StatementEnd
-- +goose Down
-- +goose StatementBegin
DROP TABLE images_fts5;
DROP TABLE images;
-- +goose StatementEnd