schema: adjustments (#15)
Add emote.color for sorting by color. Add index on emote.uploader for querying emotes uploaded by a user. Add user_connection.platform_name for searching users. Include platform_id in user_connection unique index so a person who uses multiple Twitch accounts can use a single Ligmotes account to manage all of them. Rearrange list_editor from (list, user) to (user, list) since we can express every editor query we could want in terms of user as input. Various renamings & index adjustments. Reviewed-on: #15 Co-authored-by: Branden J Brown <zephyrtronium@gmail.com> Co-committed-by: Branden J Brown <zephyrtronium@gmail.com>
This commit is contained in:
parent
2c81978ea2
commit
0f1c354dfe
@ -20,7 +20,7 @@ CREATE TABLE user (
|
||||
-- Timestamp at which this user was soft-deleted, if ever.
|
||||
"deleted_at" INTEGER,
|
||||
-- Timestamp at which this user will be unbanned, if they are banned.
|
||||
-- Banning this way is weak: it disables all lists for anything other than
|
||||
-- Banning this way is weak: it disables all sets for anything other than
|
||||
-- export and prevents uploading and modifying emotes.
|
||||
-- Nanoseconds since UNIX epoch.
|
||||
"unban_at" INTEGER,
|
||||
@ -33,10 +33,15 @@ CREATE TABLE emote (
|
||||
-- Emote ID.
|
||||
-- UUIDv7 in binary format.
|
||||
"id" BLOB PRIMARY KEY NOT NULL,
|
||||
-- Suggested or default name for the emote when added to a list.
|
||||
-- Suggested or default name for the emote when added to a set.
|
||||
"name" TEXT NOT NULL,
|
||||
-- Emote color, for sorting.
|
||||
-- Either 0xRRGGBBFF (full alpha) for a processed image or 0 for unprocessed.
|
||||
-- The latter is because we can't compute color until we have the 4x scale image,
|
||||
-- and image encoding may happen async.
|
||||
"color" INTEGER NOT NULL,
|
||||
-- ID of the user who uploaded the emote.
|
||||
"uploader" BLOB NOT NULL REFERENCES user("id"),
|
||||
"uploader_id" BLOB NOT NULL REFERENCES user("id"),
|
||||
-- Timestamp of creation.
|
||||
-- Nanoseconds since UNIX epoch.
|
||||
"created_at" INTEGER NOT NULL,
|
||||
@ -64,7 +69,7 @@ CREATE TABLE emote (
|
||||
-- ON DELETE RESTRICT because we don't want reviews to disappear if a
|
||||
-- moderator is deleted; rather, the reviews should be re-attributed to an
|
||||
-- existing moderator first.
|
||||
"reviewer" BLOB REFERENCES user("id") ON DELETE RESTRICT,
|
||||
"reviewer_id" BLOB REFERENCES user("id") ON DELETE RESTRICT,
|
||||
-- Timestamp of public listing approval, or NULL if not approved.
|
||||
-- An emote with non-NULL reviewer but NULL approved_at is private.
|
||||
-- Nanoseconds since UNIX epoch.
|
||||
@ -72,22 +77,23 @@ CREATE TABLE emote (
|
||||
-- ID of a newer version, if one exists.
|
||||
-- ON DELETE SET NULL because we don't want deleting a new version to affect
|
||||
-- an old version.
|
||||
-- TODO(zephyr): Ideally we would use the deleted version's "replaced" instead.
|
||||
"replaced" BLOB REFERENCES emote("id") ON DELETE SET NULL,
|
||||
-- TODO(zephyr): Ideally we would use the deleted version's "replaced_by" instead.
|
||||
"replaced_by" BLOB REFERENCES emote("id") ON DELETE SET NULL,
|
||||
-- ID of an older version, if one exists.
|
||||
-- ON DELETE SET NULL for the same reason as "replaced".
|
||||
-- ON DELETE SET NULL for the same reason as "replaced_by".
|
||||
"replaces" BLOB REFERENCES emote("id") ON DELETE SET NULL
|
||||
) STRICT;
|
||||
CREATE INDEX "emote_uploaders" ON emote("uploader_id");
|
||||
|
||||
-- Emote list information.
|
||||
CREATE TABLE list (
|
||||
-- Emote list ID.
|
||||
-- Emote set information.
|
||||
CREATE TABLE emote_set (
|
||||
-- Emote set ID.
|
||||
-- UUIDv7 in binary format.
|
||||
"id" BLOB PRIMARY KEY NOT NULL,
|
||||
-- List owner's user ID.
|
||||
-- Set owner's user ID.
|
||||
-- ON DELETE CASCADE because we only hard-delete users if all their data is
|
||||
-- being obliterated.
|
||||
"owner" BLOB NOT NULL REFERENCES user("id") ON DELETE CASCADE,
|
||||
"owner_id" BLOB NOT NULL REFERENCES user("id") ON DELETE CASCADE,
|
||||
-- Display name.
|
||||
"name" TEXT NOT NULL,
|
||||
-- Timestamp of creation.
|
||||
@ -95,7 +101,7 @@ CREATE TABLE list (
|
||||
"created_at" INTEGER NOT NULL
|
||||
) STRICT;
|
||||
|
||||
-- User connections and active emote lists.
|
||||
-- User connections and active emote sets.
|
||||
CREATE TABLE user_connection (
|
||||
-- User ID.
|
||||
-- ON DELETE CASCADE because we don't need connections for a user that's deleted.
|
||||
@ -103,20 +109,26 @@ CREATE TABLE user_connection (
|
||||
-- Name of the connected platform, e.g. 'Twitch'.
|
||||
"platform" TEXT NOT NULL,
|
||||
-- User ID on the connected platform.
|
||||
"platform_id" TEXT UNIQUE NOT NULL,
|
||||
-- ID of the active emote list for this connection.
|
||||
-- NULL if there is no active list.
|
||||
"list" BLOB REFERENCES list("id") ON DELETE SET NULL,
|
||||
"connected_id" TEXT UNIQUE NOT NULL,
|
||||
-- Username on the connected platform.
|
||||
"connected_name" TEXT NOT NULL,
|
||||
-- ID of the active emote set for this connection.
|
||||
-- NULL if there is no active set.
|
||||
"emote_set_id" BLOB REFERENCES emote_set("id") ON DELETE SET NULL,
|
||||
|
||||
UNIQUE("id", "platform")
|
||||
-- We include connected_id in the unique constraint so that people who
|
||||
-- actually stream on multiple Twitch accounts can use a single Ligmotes
|
||||
-- account to manage all their connections.
|
||||
UNIQUE("id", "platform", "connected_id")
|
||||
) STRICT;
|
||||
CREATE INDEX "user_connection_active_list" ON user_connection ("platform", "platform_id", "list");
|
||||
CREATE INDEX "user_connection_platform_active_set" ON user_connection ("platform", "connected_id");
|
||||
CREATE INDEX "user_connection_set_connection" ON user_connection ("emote_set_id") WHERE "emote_set_id" IS NOT NULL;
|
||||
|
||||
-- Media links for emotes.
|
||||
CREATE TABLE emote_media (
|
||||
-- Emote for which this is a media link.
|
||||
-- NOTE(zephyr): ON DELETE RESTRICT because we want to be sure we remove
|
||||
-- media from the blob store before we remove the emote from the database.
|
||||
-- ON DELETE RESTRICT because we want to be sure we remove media from
|
||||
-- the blob store before we remove the emote from the database.
|
||||
-- In other words, we should always delete from here before there.
|
||||
"id" BLOB NOT NULL REFERENCES emote("id") ON DELETE RESTRICT,
|
||||
-- Media format: 'AVIF', 'WEBP', 'PNG', &c.
|
||||
@ -140,24 +152,24 @@ CREATE TABLE emote_media (
|
||||
CONSTRAINT "emote_media_valid_scale" CHECK ("scale" IN (1, 2, 4))
|
||||
) STRICT;
|
||||
|
||||
-- Emote list contents.
|
||||
CREATE TABLE list_emote (
|
||||
-- Emote list ID.
|
||||
-- ON DELETE CASCADE because if a list is deleted then we never care about
|
||||
-- Emote set contents.
|
||||
CREATE TABLE set_emote (
|
||||
-- Emote set ID.
|
||||
-- ON DELETE CASCADE because if a set is deleted then we never care about
|
||||
-- what emotes were in it.
|
||||
"list" BLOB NOT NULL REFERENCES list("id") ON DELETE CASCADE,
|
||||
"emote_set_id" BLOB NOT NULL REFERENCES emote_set("id") ON DELETE CASCADE,
|
||||
-- Emote ID.
|
||||
-- ON DELETE CASCADE because all the media links will already be gone anyway,
|
||||
-- since media links have to be deleted before emotes.
|
||||
"emote" BLOB NOT NULL REFERENCES emote("id") ON DELETE CASCADE,
|
||||
-- Name of the emote in the list.
|
||||
"emote_id" BLOB NOT NULL REFERENCES emote("id") ON DELETE CASCADE,
|
||||
-- Name of the emote in the set.
|
||||
-- This can be different from or the same as the emote's listed name.
|
||||
"name" TEXT NOT NULL,
|
||||
-- Timestamp at which this emote falls off the list.
|
||||
-- Timestamp at which this emote falls out of the set.
|
||||
-- The CDN updates this whenever an emote image is requested for a chat.
|
||||
-- Nanoseconds since the UNIX epoch.
|
||||
"expires_at" INTEGER NOT NULL,
|
||||
-- Timestamp at which this emote was manually removed from the list.
|
||||
-- Timestamp at which this emote was manually removed from the set.
|
||||
-- If it's added again, this should be set to NULL, and expires_at should
|
||||
-- only be updated if it's in the past.
|
||||
-- This prevents removing and re-adding an emote from circumventing the
|
||||
@ -165,16 +177,19 @@ CREATE TABLE list_emote (
|
||||
-- Nanoseconds since the UNIX epoch.
|
||||
"removed_at" INTEGER,
|
||||
|
||||
UNIQUE("list", "emote")
|
||||
-- Emotes are unique per name in a set rather than per ID.
|
||||
-- It's fine to have the same emote under multiple names.
|
||||
-- It's irreconcilable to have multiple emotes with the same name.
|
||||
UNIQUE("emote_set_id", "name")
|
||||
) STRICT;
|
||||
|
||||
-- List editors.
|
||||
-- A (list, user) pair must exist in this table for the user to make any edit
|
||||
-- to the list. Being the list owner is not sufficient.
|
||||
CREATE TABLE list_editor (
|
||||
"list" BLOB NOT NULL REFERENCES list("id"),
|
||||
"user" BLOB NOT NULL REFERENCES user("id"),
|
||||
PRIMARY KEY ("list", "user")
|
||||
-- Emote set editors.
|
||||
-- A (user, set) pair must exist in this table for the user to make any edit
|
||||
-- to the set. Being the set owner is not sufficient.
|
||||
CREATE TABLE emote_set_editor (
|
||||
"user_id" BLOB NOT NULL REFERENCES user("id"),
|
||||
"emote_set_id" BLOB NOT NULL REFERENCES emote_set("id"),
|
||||
PRIMARY KEY ("user_id", "emote_set_id")
|
||||
) STRICT;
|
||||
|
||||
COMMIT;
|
||||
|
Loading…
x
Reference in New Issue
Block a user