UNPKG

aisdk5-news-package

Version:

A comprehensive RSS news aggregation package for chat applications

119 lines (106 loc) 4.7 kB
import { sql } from 'drizzle-orm'; import type { PostgresJsDatabase } from 'drizzle-orm/postgres-js'; export async function up(db: PostgresJsDatabase) { // Create RSS Feeds table await db.execute(sql` CREATE TABLE IF NOT EXISTS "news_rss_feeds" ( "id" UUID PRIMARY KEY DEFAULT gen_random_uuid(), "name" VARCHAR(255) NOT NULL, "url" TEXT NOT NULL UNIQUE, "category" VARCHAR(100) NOT NULL, "is_active" BOOLEAN NOT NULL DEFAULT true, "last_fetched_at" TIMESTAMP, "fetch_interval" INTEGER NOT NULL DEFAULT 30, "error_count" INTEGER NOT NULL DEFAULT 0, "created_at" TIMESTAMP NOT NULL DEFAULT NOW(), "updated_at" TIMESTAMP NOT NULL DEFAULT NOW() ) `); // Create Articles table await db.execute(sql` CREATE TABLE IF NOT EXISTS "news_articles" ( "id" UUID PRIMARY KEY DEFAULT gen_random_uuid(), "title" TEXT NOT NULL, "description" TEXT, "content" TEXT, "url" TEXT NOT NULL UNIQUE, "image_url" TEXT, "published_at" TIMESTAMP NOT NULL, "fetched_at" TIMESTAMP NOT NULL DEFAULT NOW(), "feed_id" UUID NOT NULL, "category" VARCHAR(100) NOT NULL, "tags" JSONB NOT NULL DEFAULT '[]', "is_active" BOOLEAN NOT NULL DEFAULT true, "media_elements" JSONB NOT NULL DEFAULT '[]', "has_audio" BOOLEAN NOT NULL DEFAULT false, "has_video" BOOLEAN NOT NULL DEFAULT false, "media_extracted_at" TIMESTAMP, "media_extraction_error" TEXT, "created_at" TIMESTAMP NOT NULL DEFAULT NOW(), "updated_at" TIMESTAMP NOT NULL DEFAULT NOW(), CONSTRAINT "fk_articles_feed" FOREIGN KEY ("feed_id") REFERENCES "news_rss_feeds" ("id") ON DELETE CASCADE ) `); // Create Saved Articles table await db.execute(sql` CREATE TABLE IF NOT EXISTS "news_saved_articles" ( "user_id" UUID NOT NULL, "article_id" UUID NOT NULL, "saved_at" TIMESTAMP NOT NULL DEFAULT NOW(), PRIMARY KEY ("user_id", "article_id"), CONSTRAINT "fk_saved_articles_article" FOREIGN KEY ("article_id") REFERENCES "news_articles" ("id") ON DELETE CASCADE ) `); // Create indexes await db.execute(sql`CREATE INDEX IF NOT EXISTS "idx_articles_published_at" ON "news_articles" ("published_at")`); await db.execute(sql`CREATE INDEX IF NOT EXISTS "idx_articles_category" ON "news_articles" ("category")`); await db.execute(sql`CREATE INDEX IF NOT EXISTS "idx_articles_feed_id" ON "news_articles" ("feed_id")`); await db.execute(sql`CREATE INDEX IF NOT EXISTS "idx_articles_is_active" ON "news_articles" ("is_active")`); await db.execute(sql`CREATE INDEX IF NOT EXISTS "idx_articles_category_active" ON "news_articles" ("category", "is_active")`); await db.execute(sql`CREATE INDEX IF NOT EXISTS "idx_feeds_is_active" ON "news_rss_feeds" ("is_active")`); await db.execute(sql`CREATE INDEX IF NOT EXISTS "idx_saved_articles_user" ON "news_saved_articles" ("user_id")`); // Create full-text search index await db.execute(sql` CREATE INDEX IF NOT EXISTS "idx_articles_fulltext" ON "news_articles" USING GIN (to_tsvector('english', title || ' ' || COALESCE(description, '') || ' ' || COALESCE(content, ''))) `); // Create update trigger function await db.execute(sql` CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ language 'plpgsql' `); // Create triggers await db.execute(sql` CREATE TRIGGER update_news_rss_feeds_updated_at BEFORE UPDATE ON "news_rss_feeds" FOR EACH ROW EXECUTE FUNCTION update_updated_at_column() `); await db.execute(sql` CREATE TRIGGER update_news_articles_updated_at BEFORE UPDATE ON "news_articles" FOR EACH ROW EXECUTE FUNCTION update_updated_at_column() `); // Insert sample RSS feeds await db.execute(sql` INSERT INTO "news_rss_feeds" ("name", "url", "category", "fetch_interval") VALUES ('TechCrunch', 'https://techcrunch.com/feed/', 'technology', 30), ('BBC News', 'http://feeds.bbci.co.uk/news/rss.xml', 'world-news', 30), ('Reuters Business', 'https://www.reuters.com/business/feed/', 'business', 30) ON CONFLICT (url) DO NOTHING `); } export async function down(db: PostgresJsDatabase) { // Drop tables in reverse order await db.execute(sql`DROP TABLE IF EXISTS "news_saved_articles"`); await db.execute(sql`DROP TABLE IF EXISTS "news_articles"`); await db.execute(sql`DROP TABLE IF EXISTS "news_rss_feeds"`); // Drop trigger function await db.execute(sql`DROP FUNCTION IF EXISTS update_updated_at_column()`); }