146 lines
6.5 KiB
PL/PgSQL
146 lines
6.5 KiB
PL/PgSQL
-- +goose Up
|
|
CREATE TABLE "users"
|
|
(
|
|
"id" TEXT PRIMARY KEY
|
|
);
|
|
COMMENT ON COLUMN "users"."id"
|
|
IS 'ID of the user. It is came from external system, so we can save it as a text field only';
|
|
|
|
|
|
CREATE TYPE FEED_PROVIDER AS ENUM ('rss');
|
|
|
|
|
|
CREATE TABLE "feeds"
|
|
(
|
|
"id" UUID NOT NULL PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
"title" TEXT NOT NULL DEFAULT '',
|
|
"provider" FEED_PROVIDER NOT NULL,
|
|
"source" TEXT NOT NULL,
|
|
"last_fetched_at" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
"fetch_interval" INTERVAL NOT NULL DEFAULT '1 hour'::INTERVAL,
|
|
"next_fetch_at" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
"last_error" TEXT DEFAULT NULL,
|
|
"errors_count" INTEGER NOT NULL DEFAULT 0
|
|
);
|
|
CREATE UNIQUE INDEX "u_feeds__source" ON "feeds" ("source");
|
|
CREATE INDEX "i_feeds__next_fetch_at" ON "feeds" ("next_fetch_at");
|
|
COMMENT ON COLUMN "feeds"."id" IS 'Feed ID';
|
|
COMMENT ON COLUMN "feeds"."title" IS 'Title';
|
|
COMMENT ON COLUMN "feeds"."provider"
|
|
IS 'Data provider, such as RSS or some another supported source type';
|
|
COMMENT ON COLUMN "feeds"."source" IS 'Address of feed data';
|
|
COMMENT ON COLUMN "feeds"."last_fetched_at" IS 'Date of last fetch of current feed';
|
|
COMMENT ON COLUMN "feeds"."fetch_interval"
|
|
IS 'Period of fetching new data. Will be shorten for active feeds with lots of updates, and longen for inactive or errored feeds';
|
|
COMMENT ON COLUMN "feeds"."next_fetch_at" IS 'Computed field used only for speed-up queries. DO NOT EDIT!';
|
|
COMMENT ON COLUMN "feeds"."last_error" IS 'Text description of last fetching error';
|
|
COMMENT ON COLUMN "feeds"."errors_count"
|
|
IS 'Number of fetching errors. Will increase for every time fetch was failed. Will be reseted if fetch was successful';
|
|
|
|
-- +goose StatementBegin
|
|
CREATE FUNCTION feeds_set_next_fetch_at() RETURNS trigger AS
|
|
$feeds_set_next_fetch_at$
|
|
BEGIN
|
|
NEW."next_fetch_at" := NEW."last_fetched_at" + NEW."fetch_interval";
|
|
RETURN NEW;
|
|
END;
|
|
$feeds_set_next_fetch_at$ LANGUAGE plpgsql;
|
|
-- +goose StatementEnd
|
|
|
|
CREATE TRIGGER "feeds_set_next_fetch_at"
|
|
BEFORE INSERT OR UPDATE
|
|
ON "feeds"
|
|
FOR EACH ROW
|
|
EXECUTE FUNCTION feeds_set_next_fetch_at();
|
|
|
|
|
|
CREATE TABLE "feed_icons"
|
|
(
|
|
"feed_id" UUID NOT NULL PRIMARY KEY REFERENCES "feeds" ("id") ON DELETE CASCADE,
|
|
"mimetype" TEXT NOT NULL,
|
|
"icon" BYTEA DEFAULT NULL
|
|
);
|
|
COMMENT ON COLUMN "feed_icons"."feed_id" IS 'ID of feed';
|
|
COMMENT ON COLUMN "feed_icons"."mimetype" IS 'Mimetype of the icon';
|
|
COMMENT ON COLUMN "feed_icons"."icon" IS 'Icon of the feed (favicon)';
|
|
|
|
|
|
CREATE TABLE "subscriptions"
|
|
(
|
|
"user_id" TEXT NOT NULL REFERENCES "users" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
|
"feed_id" UUID NOT NULL REFERENCES "feeds" ("id") ON DELETE RESTRICT,
|
|
"title" TEXT DEFAULT NULL
|
|
);
|
|
CREATE UNIQUE INDEX "u_subscription__user_feed" ON "subscriptions" ("user_id", "feed_id");
|
|
CREATE INDEX "i_subscription__user" ON "subscriptions" ("user_id");
|
|
COMMENT ON COLUMN "subscriptions"."user_id" IS 'ID of user';
|
|
COMMENT ON COLUMN "subscriptions"."feed_id" IS 'ID of feed';
|
|
COMMENT ON COLUMN "subscriptions"."title" IS 'User-defined name of the feed';
|
|
|
|
|
|
CREATE TABLE "feed_items"
|
|
(
|
|
"id" UUID NOT NULL PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
"feed_id" UUID NOT NULL REFERENCES "feeds" ("id") ON DELETE CASCADE,
|
|
"created_at" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
"fetched_at" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
|
"uid" TEXT NOT NULL,
|
|
"title" TEXT NOT NULL,
|
|
"content" TEXT NOT NULL DEFAULT '',
|
|
"link" TEXT NOT NULL DEFAULT '',
|
|
"author" TEXT NOT NULL DEFAULT '',
|
|
"tags" TEXT[] NOT NULL DEFAULT '{}'
|
|
);
|
|
CREATE INDEX "i_feed_items__feed" ON "feed_items" ("feed_id");
|
|
CREATE UNIQUE INDEX "u_feed_items__feed_uid" ON "feed_items" ("feed_id", "uid");
|
|
CREATE INDEX "i_feed_items__fetched" ON "feed_items" ("fetched_at" DESC);
|
|
COMMENT ON COLUMN "feed_items"."id" IS 'Item ID';
|
|
COMMENT ON COLUMN "feed_items"."feed_id" IS 'Feed ID';
|
|
COMMENT ON COLUMN "feed_items"."created_at" IS 'Item creation time (taken from feed info)';
|
|
COMMENT ON COLUMN "feed_items"."fetched_at"
|
|
IS 'Time when item was fetched and saved into database. This field will be used for cursor-based pagination';
|
|
COMMENT ON COLUMN "feed_items"."uid" IS 'Unique ID of item in feed';
|
|
COMMENT ON COLUMN "feed_items"."title" IS 'Title';
|
|
COMMENT ON COLUMN "feed_items"."content"
|
|
IS 'Sanitized HTML content: stripped danger tags, links modified to open in new tab and to strip referrer';
|
|
COMMENT ON COLUMN "feed_items"."link" IS 'Link to full article content';
|
|
COMMENT ON COLUMN "feed_items"."author" IS 'Name of the author of article (taken from feed info)';
|
|
COMMENT ON COLUMN "feed_items"."tags" IS 'List of normalized (lowercased, trimmed) tags (taken from feed info)';
|
|
|
|
|
|
CREATE TABLE "feed_item_attachments"
|
|
(
|
|
"id" BIGINT NOT NULL GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
|
|
"item_id" UUID NOT NULL REFERENCES "feed_items" ("id") ON DELETE CASCADE,
|
|
"mimetype" TEXT NOT NULL,
|
|
"url" TEXT NOT NULL,
|
|
"size" BIGINT NOT NULL DEFAULT 0
|
|
);
|
|
|
|
|
|
CREATE TABLE "subscription_items"
|
|
(
|
|
"user_id" TEXT NOT NULL REFERENCES "users" ("id") ON DELETE CASCADE ON UPDATE CASCADE,
|
|
"feed_id" UUID NOT NULL REFERENCES "feeds" ("id") ON DELETE CASCADE,
|
|
"item_id" UUID NOT NULL REFERENCES "feed_items" ("id") ON DELETE CASCADE,
|
|
"is_readed" BOOLEAN NOT NULL DEFAULT TRUE
|
|
);
|
|
CREATE UNIQUE INDEX "u_subscription_item__user_feed_item" ON "subscription_items" ("user_id", "feed_id", "item_id");
|
|
COMMENT ON COLUMN "subscription_items"."user_id" IS 'ID of subscribed user (used in subscription composite key)';
|
|
COMMENT ON COLUMN "subscription_items"."feed_id" IS 'ID of related feed (used in subscription composite key)';
|
|
COMMENT ON COLUMN "subscription_items"."item_id" IS 'ID of specific feed item';
|
|
COMMENT ON COLUMN "subscription_items"."is_readed"
|
|
IS 'This flag means item is marked as read and should not appear in feed (except special query). This flag MUST be treated as FALSE if row does not exists';
|
|
|
|
|
|
-- +goose Down
|
|
DROP TABLE "subscription_items";
|
|
DROP TABLE "feed_item_attachments";
|
|
DROP TABLE "feed_items";
|
|
DROP TABLE "subscriptions";
|
|
DROP TABLE "feed_icons";
|
|
DROP TABLE "feeds";
|
|
DROP FUNCTION "feeds_set_next_fetch_at";
|
|
DROP TYPE FEED_PROVIDER;
|
|
DROP TABLE "users";
|