diff --git a/.gitignore b/.gitignore index 2c4db88..3771aea 100644 --- a/.gitignore +++ b/.gitignore @@ -6,9 +6,11 @@ truffle.log .vscode/terminals.json -config/podverse-api-local.env -config/podverse-db-local.env -config/podverse-web-local.env +config/podverse-amqp.env +config/podverse-api.env +config/podverse-db.env +config/podverse-web.env +config/podverse-workers.env config/podverse-db-sandbox.env diff --git a/.vscode/terminals.json.example b/.vscode/terminals.json.example index b17d7a3..8862c99 100644 --- a/.vscode/terminals.json.example +++ b/.vscode/terminals.json.example @@ -5,13 +5,15 @@ "name": "Podverse API", "description": "podverse-api", "cwd": "~/repos/podverse-api", - "open": true + "open": true, + "command": "npm run dev:watch" }, { "name": "Podverse External Services", "description": "podverse-external-services", "cwd": "~/repos/podverse-external-services", - "open": true + "open": true, + "command": "npm run build:watch" }, { "name": "Podverse F-Droid", @@ -19,6 +21,13 @@ "cwd": "~/repos/podverse-fdroid", "open": true }, + { + "name": "Podverse Helpers", + "description": "podverse-helpers", + "cwd": "~/repos/podverse-helpers", + "open": true, + "command": "npm run build:watch" + }, { "name": "Podverse Ops", "description": "podverse-ops", @@ -29,13 +38,22 @@ "name": "Podverse ORM", "description": "podverse-orm", "cwd": "~/repos/podverse-orm", - "open": true + "open": true, + "command": "npm run build:watch" }, { "name": "Podverse Parser", "description": "podverse-parser", "cwd": "~/repos/podverse-parser", - "open": true + "open": true, + "command": "npm run build:watch" + }, + { + "name": "Podverse Queue", + "description": "podverse-queue", + "cwd": "~/repos/podverse-queue", + "open": true, + "command": "npm run build:watch" }, { "name": "Podverse RN", @@ -43,18 +61,6 @@ "cwd": "~/repos/podverse-rn", "open": true }, - { - "name": "Podverse Serverless", - "description": "podverse-serverless", - "cwd": "~/repos/podverse-serverless", - "open": true - }, - { - "name": "Podverse Shared", - "description": "podverse-shared", - "cwd": "~/repos/podverse-shared", - "open": true - }, { "name": "Podverse Web", "description": "podverse-web", diff --git a/Makefile b/Makefile index 8f7deca..68a320d 100644 --- a/Makefile +++ b/Makefile @@ -14,21 +14,21 @@ endif say_hello: @echo "Hello Podverse" -.PHONY: local_validate_init -local_validate_init: config/podverse-api-local.env config/podverse-db-local.env +.PHONY: validate_init +validate_init: config/podverse-api.env config/podverse-db.env -config/podverse-api-local.env: +config/podverse-api.env: @echo "Missing: $@" @echo "Copying from example file" cp ./$@.example ./$@ -config/podverse-db-local.env: +config/podverse-db.env: @echo "Missing: $@" @echo "Copying from example file" cp ./$@.example ./$@ -.PHONY: local_nginx_proxy -local_nginx_proxy: +.PHONY: nginx_proxy +nginx_proxy: @echo 'Generate new cert' test -d proxy/local/certs || mkdir -p proxy/local/certs cd proxy/local/certs && openssl genrsa -out podverse-server.key 4096 @@ -36,12 +36,17 @@ local_nginx_proxy: cd proxy/local/certs && openssl req -new -sha256 -key podverse-server.key -subj "/C=US/ST=Jefferson/L=Grand/O=EXA/OU=MPL/CN=podverse.local" -reqexts SAN -config <(cat /etc/ssl/openssl.cnf <(printf "[SAN]\nsubjectAltName=DNS:podverse.local,DNS:www.podverse.local,DNS:api.podverse.local")) -out podverse-server.csr cd proxy/local/certs && openssl x509 -req -days 365 -in podverse-server.csr -signkey podverse-server.key -out podverse-server.crt -.PHONY: local_up_db -local_up_db: +.PHONY: up_db +up_db: docker-compose -f docker-compose/local/docker-compose.yml up podverse_db -d -.PHONY: local_down -local_down: +.PHONY: up_all +up_all: + docker-compose -f docker-compose/local/docker-compose.yml up podverse_db -d + docker-compose -f docker-compose/local/docker-compose.yml up podverse_amqp -d + +.PHONY: down +down: docker-compose -f docker-compose/local/docker-compose.yml down proxy/local/certs: @@ -59,6 +64,6 @@ proxy/local/certs/podverse-server.csr: proxy/local/certs/podverse-server.key proxy/local/certs/podverse-server.crt: proxy/local/certs/podverse-server.csr openssl x509 -req -days 365 -in $< -signkey proxy/local/certs/podverse-server.key -out $@ -.PHONY: local_nginx_proxy_cert -local_nginx_proxy_cert: proxy/local/certs proxy/local/certs/podverse-server.key proxy/local/certs/podverse-server.key.insecure proxy/local/certs/podverse-server.csr proxy/local/certs/podverse-server.crt +.PHONY: nginx_proxy_cert +nginx_proxy_cert: proxy/local/certs proxy/local/certs/podverse-server.key proxy/local/certs/podverse-server.key.insecure proxy/local/certs/podverse-server.csr proxy/local/certs/podverse-server.crt @echo 'Generate new cert' diff --git a/config/podverse-amqp.env.example b/config/podverse-amqp.env.example new file mode 100644 index 0000000..507eb70 --- /dev/null +++ b/config/podverse-amqp.env.example @@ -0,0 +1,5 @@ +RABBITMQ_HOST=podverse_amqp +RABBITMQ_PORT=5672 +RABBITMQ_DEFAULT_USER= +RABBITMQ_DEFAULT_PASS= +RABBITMQ_VHOST=/ diff --git a/config/podverse-db-local.env.example b/config/podverse-db.env.example similarity index 80% rename from config/podverse-db-local.env.example rename to config/podverse-db.env.example index bcebe0b..001c4f8 100644 --- a/config/podverse-db-local.env.example +++ b/config/podverse-db.env.example @@ -1,4 +1,4 @@ POSTGRES_USER=user POSTGRES_PASSWORD=mysecretpw -POSTGRES_DB=db +POSTGRES_DB=postgres PGDATA=/var/lib/postgresql/data/pgdata diff --git a/config/podverse-workers.env.example b/config/podverse-workers.env.example new file mode 100644 index 0000000..1778d0f --- /dev/null +++ b/config/podverse-workers.env.example @@ -0,0 +1,28 @@ +NODE_ENV=production + +RABBITMQ_HOST=podverse_queue +RABBITMQ_PORT=5672 +RABBITMQ_USERNAME=user +RABBITMQ_PASSWORD=mysecretpw +RABBITMQ_VHOST=/ + +RABBITMQ_QUEUE_NAMES=rss-slow,rss-fast,rss-live + +##### +##### Postgres +##### + +# LOCAL +DB_HOST=podverse_db +DB_PORT=5432 +DB_USERNAME=user +DB_PASSWORD=mysecretpw +DB_DATABASE=postgres +DB_SSL_CONNECTION= + +LOG_LEVEL=info +LOG_TIMER= + +PODCAST_INDEX_BASE_URL=https://api.podcastindex.org/api/1.0 +PODCAST_INDEX_AUTH_KEY= +PODCAST_INDEX_SECRET_KEY= diff --git a/database/combined/init_database.sql b/database/combined/init_database.sql new file mode 100644 index 0000000..ebf1323 --- /dev/null +++ b/database/combined/init_database.sql @@ -0,0 +1,1363 @@ +-- 0000 migration + +-- Helpers + +-- In the previous version of the app, short_id was 7-14 characters long. +-- To make migration to v2 easier, we will use a 15 character long short_id, +-- so we can easily distinguish between v1 and v2 short_ids. +CREATE DOMAIN short_id_v2 AS VARCHAR(15); + +CREATE DOMAIN varchar_short AS VARCHAR(50); +CREATE DOMAIN varchar_normal AS VARCHAR(255); +CREATE DOMAIN varchar_long AS VARCHAR(2500); + +CREATE DOMAIN varchar_email AS VARCHAR(255) CHECK (VALUE ~ '^.+@.+\..+$'); +CREATE DOMAIN varchar_fcm_token AS VARCHAR(255); +CREATE DOMAIN varchar_fqdn AS VARCHAR(253); +CREATE DOMAIN varchar_guid AS VARCHAR(36); +CREATE DOMAIN varchar_md5 AS VARCHAR(32); +CREATE DOMAIN varchar_password AS VARCHAR(36); +CREATE DOMAIN varchar_slug AS VARCHAR(100); +CREATE DOMAIN varchar_uri AS VARCHAR(2083); +CREATE DOMAIN varchar_url AS VARCHAR(2083) CHECK (VALUE ~ '^https?://|^http?://'); + +CREATE DOMAIN server_time AS TIMESTAMP; +CREATE DOMAIN server_time_with_default AS TIMESTAMP DEFAULT NOW(); + +CREATE DOMAIN media_player_time AS NUMERIC(10, 2); +CREATE DOMAIN list_position AS NUMERIC(22, 21); +CREATE DOMAIN numeric_20_11 AS NUMERIC(20, 11); + +-- Function to set updated_at +CREATE OR REPLACE FUNCTION set_updated_at_field() +RETURNS TRIGGER AS $$ +BEGIN + NEW.updated_at := NOW(); + RETURN NEW; +END; +$$ LANGUAGE plpgsql; + +-- 0001 migration + +/* + +PODCASTING 2.0 DATABASE SCHEMA + +- The `id` column is a SERIAL column that is used as the primary key for every table. + +- The `id_text` column is only intended for tables where the data is available as urls. + For example, https://podverse.fm/podcast/abc123def456, the `id_text` column would be `abc123def456`. + +- The `slug` column is not required, but functions as an alternative for `id_text`. + For example, https://podverse.fm/podcast/podcasting-20 would have a `slug` column with the value `podcasting-20`. + +- The `podcast_index_id` ensures that our database only contains feed data that is available in the Podcast Index API. + +*/ + +----------** GLOBAL REFERENCE TABLES **---------- +-- These tables are referenced across many tables, and must be created first. + +--** CATEGORY + +-- Allowed category values align with the standard categories and subcategories +-- supported by Apple iTunes through the tag. +-- +CREATE TABLE category ( + id SERIAL PRIMARY KEY, + node_text varchar_normal NOT NULL, -- + display_name varchar_normal NOT NULL, -- our own display name for the category + slug varchar_normal NOT NULL -- our own slug for the category +); + +--** MEDIUM VALUE + +-- +CREATE TABLE medium ( + id SERIAL PRIMARY KEY, + value TEXT UNIQUE CHECK (VALUE IN ( + 'publisher', + 'podcast', 'music', 'video', 'film', 'audiobook', 'newsletter', 'blog', 'publisher', 'course', + 'mixed', 'podcastL', 'musicL', 'videoL', 'filmL', 'audiobookL', 'newsletterL', 'blogL', 'publisherL', 'courseL' + )) +); + +INSERT INTO medium (value) VALUES + ('publisher'), + ('podcast'), ('music'), ('video'), ('film'), ('audiobook'), ('newsletter'), ('blog'), ('course'), + ('mixed'), ('podcastL'), ('musicL'), ('videoL'), ('filmL'), ('audiobookL'), ('newsletterL'), ('blogL'), ('publisherL'), ('courseL') +; + +----------** TABLES **---------- + +--** FEED > FLAG STATUS + +-- used internally for identifying and handling spam and other special flag statuses. +CREATE TABLE feed_flag_status ( + id SERIAL PRIMARY KEY, + status TEXT UNIQUE CHECK (status IN ('none', 'spam', 'takedown', 'other', 'always-allow')), + created_at server_time_with_default, + updated_at server_time_with_default +); + +CREATE TRIGGER set_updated_at_feed_flag_status +BEFORE UPDATE ON feed_flag_status +FOR EACH ROW +EXECUTE FUNCTION set_updated_at_field(); + +INSERT INTO feed_flag_status (status) VALUES ('none'), ('spam'), ('takedown'), ('other'), ('always-allow'); + +--** FEED + +-- The top-level table for storing feed data, and internal parsing data. +CREATE TABLE feed ( + id SERIAL PRIMARY KEY, + url varchar_url UNIQUE NOT NULL, + + -- feed flag + feed_flag_status_id INTEGER NOT NULL REFERENCES feed_flag_status(id), + + -- internal + + -- Used to prevent another thread from parsing the same feed. + -- Set to current time at beginning of parsing, and NULL at end of parsing. + -- This is to prevent multiple threads from parsing the same feed. + -- If is_parsing is over X minutes old, assume last parsing failed and proceed to parse. + is_parsing server_time, + + -- 0 will only be parsed when PI API reports an update. + -- higher parsing_priority will be parsed more frequently on a schedule. + parsing_priority INTEGER DEFAULT 0 CHECK (parsing_priority BETWEEN 0 AND 5), + + -- the hash of the last parsed feed file. + -- used for comparison to determine if full re-parsing is needed. + last_parsed_file_hash varchar_md5, + + -- the run-time environment container id + container_id VARCHAR(12), + + created_at server_time_with_default, + updated_at server_time_with_default +); + +CREATE INDEX idx_feed_feed_flag_status_id ON feed(feed_flag_status_id); + +CREATE TRIGGER set_updated_at_feed +BEFORE UPDATE ON feed +FOR EACH ROW +EXECUTE FUNCTION set_updated_at_field(); + +CREATE TABLE feed_log ( + id SERIAL PRIMARY KEY, + feed_id INTEGER NOT NULL UNIQUE REFERENCES feed(id) ON DELETE CASCADE, + last_http_status INTEGER, + last_good_http_status_time server_time, + last_finished_parse_time server_time, + parse_errors INTEGER DEFAULT 0 +); + +CREATE INDEX idx_feed_log_feed_id ON feed_log(feed_id); + +--** CHANNEL + +-- +CREATE TABLE channel ( + id SERIAL PRIMARY KEY, + id_text short_id_v2 UNIQUE NOT NULL, + slug varchar_slug, + feed_id INTEGER NOT NULL UNIQUE REFERENCES feed(id) ON DELETE CASCADE, + podcast_index_id INTEGER UNIQUE NOT NULL, + podcast_guid UUID UNIQUE, -- + title varchar_normal, + sortable_title varchar_short, -- all lowercase, ignores articles at beginning of title + medium_id INTEGER REFERENCES medium(id), + + -- channels that have a PI value tag require special handling to request value data + -- from the Podcast Index API. + has_podcast_index_value BOOLEAN DEFAULT FALSE, + + -- this column is used for optimization purposes to determine if all of the items + -- for a channel need to have their value time split remote items parsed. + has_value_time_splits BOOLEAN DEFAULT FALSE, + + -- hidden items are no longer available in the rss feed, but are still in the database. + hidden BOOLEAN DEFAULT FALSE, + -- markedForDeletion items are no longer available in the rss feed, and may be able to be deleted. + marked_for_deletion BOOLEAN DEFAULT FALSE +); + +CREATE UNIQUE INDEX channel_podcast_guid_unique ON channel(podcast_guid) WHERE podcast_guid IS NOT NULL; +CREATE UNIQUE INDEX channel_slug ON channel(slug) WHERE slug IS NOT NULL; +CREATE INDEX idx_channel_feed_id ON channel(feed_id); +CREATE INDEX idx_channel_medium_id ON channel(medium_id); + +--** CHANNEL > ABOUT > ITUNES TYPE + +-- -> +CREATE TABLE channel_itunes_type ( + id SERIAL PRIMARY KEY, + itunes_type TEXT UNIQUE CHECK (itunes_type IN ('episodic', 'serial')) +); + +INSERT INTO channel_itunes_type (itunes_type) VALUES ('episodic'), ('serial'); + +--** CHANNEL > ABOUT + +-- various child data from multiple tags +CREATE TABLE channel_about ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL UNIQUE REFERENCES channel(id) ON DELETE CASCADE, + author varchar_normal, -- and + episode_count INTEGER, -- aggregated count for convenience + explicit BOOLEAN, -- + itunes_type_id INTEGER REFERENCES channel_itunes_type(id), + language varchar_short, -- + last_pub_date server_time_with_default, -- + website_link_url varchar_url -- +); + +CREATE INDEX idx_channel_about_channel_id ON channel_about(channel_id); +CREATE INDEX idx_channel_about_itunes_type_id ON channel_about(itunes_type_id); + +--** CHANNEL > CATEGORY + +CREATE TABLE channel_category ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + parent_id INTEGER REFERENCES channel_category(id) ON DELETE CASCADE +); + +CREATE INDEX idx_channel_category_channel_id ON channel_category(channel_id); +CREATE INDEX idx_channel_category_parent_id ON channel_category(parent_id); + +--** CHANNEL > CHAT + +-- -> +CREATE TABLE channel_chat ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL UNIQUE REFERENCES channel(id) ON DELETE CASCADE, + server varchar_fqdn NOT NULL, + protocol varchar_short NOT NULL, + account_id varchar_normal, + space varchar_normal +); + +CREATE INDEX idx_channel_chat_channel_id ON channel_chat(channel_id); + +--** CHANNEL > DESCRIPTION + +-- -> AND possibly other tags that contain a description +CREATE TABLE channel_description ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL UNIQUE REFERENCES channel(id) ON DELETE CASCADE, + value varchar_long NOT NULL +); + +CREATE INDEX idx_channel_description_channel_id ON channel_description(channel_id); + +--** CHANNEL > FUNDING + +-- -> +CREATE TABLE channel_funding ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + url varchar_url NOT NULL, + title varchar_normal +); + +CREATE INDEX idx_channel_funding_channel_id ON channel_funding(channel_id); + +--** CHANNEL > IMAGE + +-- -> AND all other image tags in the rss feed +CREATE TABLE channel_image ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + url varchar_url NOT NULL, + image_width_size INTEGER, -- must have a width specified, but older image tags will not, so allow null. + + -- If true, then the image is hosted by us in a service like S3. + -- When is_resized images are deleted, the corresponding image in S3 + -- should also be deleted. + is_resized BOOLEAN DEFAULT FALSE +); + +CREATE INDEX idx_channel_image_channel_id ON channel_image(channel_id); + +--** CHANNEL > INTERNAL SETTINGS + +CREATE TABLE channel_internal_settings ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + -- needed to approve which web domains can override the player with query params. + -- this prevents malicious parties from misrepresenting the podcast contents on another website. + embed_approved_media_url_paths TEXT +); + +CREATE INDEX idx_channel_internal_settings_channel_id ON channel_internal_settings(channel_id); + +--** CHANNEL > LICENSE + +-- -> +CREATE TABLE channel_license ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL UNIQUE REFERENCES channel(id) ON DELETE CASCADE, + identifier varchar_normal NOT NULL, + url varchar_url +); + +CREATE INDEX idx_channel_license_channel_id ON channel_license(channel_id); + +--** CHANNEL > LOCATION + +-- -> +CREATE TABLE channel_location ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL UNIQUE REFERENCES channel(id) ON DELETE CASCADE, + geo varchar_normal, + osm varchar_normal, + CHECK (geo IS NOT NULL OR osm IS NOT NULL), + name varchar_normal +); + +CREATE INDEX idx_channel_location_channel_id ON channel_location(channel_id); + +--** CHANNEL > PERSON + +-- -> +CREATE TABLE channel_person ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + name varchar_normal NOT NULL, + role varchar_normal, + person_group varchar_normal DEFAULT 'cast', -- group is a reserved keyword in sql + img varchar_url, + href varchar_url +); + +CREATE INDEX idx_channel_person_channel_id ON channel_person(channel_id); + +--** CHANNEL > PODROLL + +-- -> +CREATE TABLE channel_podroll ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL UNIQUE REFERENCES channel(id) ON DELETE CASCADE +); + +CREATE INDEX idx_channel_podroll_channel_id ON channel_podroll(channel_id); + +--** CHANNEL > PODROLL > REMOTE ITEM + +-- -> --> +CREATE TABLE channel_podroll_remote_item ( + id SERIAL PRIMARY KEY, + channel_podroll_id INTEGER NOT NULL REFERENCES channel_podroll(id) ON DELETE CASCADE, + feed_guid UUID NOT NULL, + feed_url varchar_url, + item_guid varchar_uri, + title varchar_normal, + medium_id INTEGER REFERENCES medium(id) +); + +CREATE INDEX idx_channel_podroll_remote_item_channel_podroll_id ON channel_podroll_remote_item(channel_podroll_id); +CREATE INDEX idx_channel_podroll_remote_item_medium_id ON channel_podroll_remote_item(medium_id); +CREATE INDEX idx_channel_podroll_remote_item_feed_guid ON channel_podroll_remote_item(feed_guid); +CREATE INDEX idx_channel_podroll_remote_item_feed_url ON channel_podroll_remote_item(feed_url); +CREATE INDEX idx_channel_podroll_remote_item_item_guid ON channel_podroll_remote_item(item_guid); + +--** CHANNEL > PUBLISHER + +-- -> +CREATE TABLE channel_publisher ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL UNIQUE REFERENCES channel(id) ON DELETE CASCADE +); + +CREATE INDEX idx_channel_publisher_channel_id ON channel_publisher(channel_id); + +--** CHANNEL > PUBLISHER > REMOTE ITEM + +-- -> -> +CREATE TABLE channel_publisher_remote_item ( + id SERIAL PRIMARY KEY, + channel_publisher_id INTEGER NOT NULL UNIQUE REFERENCES channel_publisher(id) ON DELETE CASCADE, + feed_guid UUID NOT NULL, + feed_url varchar_url, + item_guid varchar_uri, + title varchar_normal, + medium_id INTEGER REFERENCES medium(id) +); + +CREATE INDEX idx_channel_publisher_remote_item_channel_publisher_id ON channel_publisher_remote_item(channel_publisher_id); +CREATE INDEX idx_channel_publisher_remote_item_medium_id ON channel_publisher_remote_item(medium_id); +CREATE INDEX idx_channel_publisher_remote_item_feed_guid ON channel_publisher_remote_item(feed_guid); +CREATE INDEX idx_channel_publisher_remote_item_feed_url ON channel_publisher_remote_item(feed_url); +CREATE INDEX idx_channel_publisher_remote_item_item_guid ON channel_publisher_remote_item(item_guid); + +--** CHANNEL > REMOTE ITEM + +-- Remote items at the channel level are only used when the for the channel +-- is set to 'mixed' or another list medium like 'podcastL'. + +-- -> +CREATE TABLE channel_remote_item ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + feed_guid UUID NOT NULL, + feed_url varchar_url, + item_guid varchar_uri, + title varchar_normal, + medium_id INTEGER REFERENCES medium(id) +); + +CREATE INDEX idx_channel_remote_item_channel_id ON channel_remote_item(channel_id); +CREATE INDEX idx_channel_remote_item_medium_id ON channel_remote_item(medium_id); +CREATE INDEX idx_channel_remote_item_feed_guid ON channel_remote_item(feed_guid); +CREATE INDEX idx_channel_remote_item_feed_url ON channel_remote_item(feed_url); +CREATE INDEX idx_channel_remote_item_item_guid ON channel_remote_item(item_guid); + +--** CHANNEL > SEASON + +-- channels with seasons need to be rendered in client apps differently. +-- you can only determine if a channel is in a "season" format is by finding +-- the tag in an item in that channel. + +-- NOTE: A channel season does not exist in the Podcasting 2.0 spec, +-- but it is useful for organizing seasons at the channel level, +-- and could be in the P2.0 spec someday. + +CREATE TABLE channel_season ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + number INTEGER NOT NULL, + UNIQUE (channel_id, number), + name varchar_normal +); + +CREATE INDEX idx_channel_season_channel_id ON channel_season(channel_id); + +--** CHANNEL > SOCIAL INTERACT + +-- -> +CREATE TABLE channel_social_interact ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + protocol varchar_short NOT NULL, + uri varchar_uri NOT NULL, + account_id varchar_normal, + account_url varchar_url, + priority INTEGER +); + +CREATE INDEX idx_channel_social_interact_channel_id ON channel_social_interact(channel_id); + +--** CHANNEL > TRAILER + +-- -> +CREATE TABLE channel_trailer ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + url varchar_url NOT NULL, + title varchar_normal, + pubdate TIMESTAMPTZ NOT NULL, + length INTEGER, + type varchar_short, + channel_season_id INTEGER REFERENCES channel_season(id), + UNIQUE (channel_id, url) +); + +CREATE INDEX idx_channel_trailer_channel_id ON channel_trailer(channel_id); +CREATE INDEX idx_channel_trailer_channel_season_id ON channel_trailer(channel_season_id); + +--** CHANNEL > TXT + +-- -> +CREATE TABLE channel_txt ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + purpose varchar_normal, + value varchar_long NOT NULL +); + +CREATE INDEX idx_channel_txt_channel_id ON channel_txt(channel_id); + +--** CHANNEL > VALUE + +-- -> +CREATE TABLE channel_value ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + type varchar_short NOT NULL, + method varchar_short NOT NULL, + suggested FLOAT +); + +CREATE INDEX idx_channel_value_channel_id ON channel_value(channel_id); + +--** CHANNEL > VALUE > RECEIPIENT + +-- -> -> +CREATE TABLE channel_value_recipient ( + id SERIAL PRIMARY KEY, + channel_value_id INTEGER NOT NULL REFERENCES channel_value(id) ON DELETE CASCADE, + type varchar_short NOT NULL, + address varchar_long NOT NULL, + split FLOAT NOT NULL, + name varchar_normal, + custom_key varchar_long, + custom_value varchar_long, + fee BOOLEAN DEFAULT FALSE +); + +CREATE INDEX idx_channel_value_recipient_channel_value_id ON channel_value_recipient(channel_value_id); + +--** ITEM + +-- Technically the item table could be named channel_item, but it seems easier to understand as item. + +-- -> +CREATE TABLE item ( + id SERIAL PRIMARY KEY, + id_text short_id_v2 UNIQUE NOT NULL, + slug varchar_slug, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + guid varchar_uri, -- + guid_enclosure_url varchar_url NOT NULL, -- enclosure url + pubdate TIMESTAMPTZ, -- + title varchar_normal, -- + + -- hidden items are no longer available in the rss feed, but are still in the database. + hidden BOOLEAN DEFAULT FALSE, + -- markedForDeletion items are no longer available in the rss feed, and may be able to be deleted. + marked_for_deletion BOOLEAN DEFAULT FALSE +); + +CREATE UNIQUE INDEX item_slug ON item(slug) WHERE slug IS NOT NULL; +CREATE INDEX idx_item_channel_id ON item(channel_id); + +--** ITEM > ABOUT > ITUNES TYPE + +-- <item> -> <itunes:episodeType> +CREATE TABLE item_itunes_episode_type ( + id SERIAL PRIMARY KEY, + itunes_episode_type TEXT UNIQUE CHECK (itunes_episode_type IN ('full', 'trailer', 'bonus')) +); + +INSERT INTO item_itunes_episode_type (itunes_episode_type) VALUES ('full'), ('trailer'), ('bonus'); + +--** ITEM > ABOUT + +CREATE TABLE item_about ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL UNIQUE REFERENCES item(id) ON DELETE CASCADE, + duration media_player_time, -- <itunes:duration> + explicit BOOLEAN, -- <itunes:explicit> + website_link_url varchar_url, -- <link> + item_itunes_episode_type_id INTEGER REFERENCES item_itunes_episode_type(id) -- <itunes:episodeType> +); + +CREATE INDEX idx_item_about_item_id ON item_about(item_id); +CREATE INDEX idx_item_about_item_itunes_episode_type_id ON item_about(item_itunes_episode_type_id); + +--** ITEM > CHAPTERS + +-- <item> -> <podcast:chapters> +CREATE TABLE item_chapters_feed ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL UNIQUE REFERENCES item(id) ON DELETE CASCADE, + url varchar_url NOT NULL, + type varchar_short NOT NULL +); + +CREATE INDEX idx_item_chapters_feed_item_id ON item_chapters_feed(item_id); + +--** ITEM > CHAPTERS > LOG + +-- <item> -> <podcast:chapters> -> parsing logs + +CREATE TABLE item_chapters_feed_log ( + id SERIAL PRIMARY KEY, + item_chapters_feed_id INTEGER NOT NULL UNIQUE REFERENCES item_chapters_feed(id) ON DELETE CASCADE, + last_http_status INTEGER, + last_good_http_status_time server_time, + last_finished_parse_time server_time, + parse_errors INTEGER DEFAULT 0 +); + +CREATE INDEX idx_item_chapters_feed_log_item_chapters_feed_id ON item_chapters_feed_log(item_chapters_feed_id); + +--** ITEM > CHAPTERS > CHAPTER + +-- -- <item> -> <podcast:chapters> -> chapter items correspond with jsonChapters.md example file +CREATE TABLE item_chapter ( + id SERIAL PRIMARY KEY, + id_text short_id_v2 UNIQUE NOT NULL, + item_chapters_feed_id INTEGER NOT NULL REFERENCES item_chapters_feed(id) ON DELETE CASCADE, + start_time media_player_time NOT NULL, + end_time media_player_time, + title varchar_normal, + img varchar_url, + web_url varchar_url, + table_of_contents BOOLEAN DEFAULT TRUE +); + +CREATE INDEX idx_item_chapter_item_chapters_feed_id ON item_chapter(item_chapters_feed_id); + +--** ITEM > CHAPTER > LOCATION + +-- <item> -> <podcast:chapters> -> chapter items correspond with jsonChapters.md example file +CREATE TABLE item_chapter_location ( + id SERIAL PRIMARY KEY, + item_chapter_id INTEGER NOT NULL UNIQUE REFERENCES item_chapter(id) ON DELETE CASCADE, + geo varchar_normal, + osm varchar_normal, + CHECK (geo IS NOT NULL OR osm IS NOT NULL), + name varchar_normal +); + +CREATE INDEX idx_item_chapter_location_item_chapter_id ON item_chapter_location(item_chapter_id); + +--** ITEM > CHAT + +-- <item> -> <podcast:chat> +CREATE TABLE item_chat ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL UNIQUE REFERENCES item(id) ON DELETE CASCADE, + server varchar_fqdn NOT NULL, + protocol varchar_short NOT NULL, + account_id varchar_normal, + space varchar_normal +); + +CREATE INDEX idx_item_chat_item_id ON item_chat(item_id); + +--** ITEM > CONTENT LINK + +-- <item> -> <podcast:contentLink> +CREATE TABLE item_content_link ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + href varchar_url NOT NULL, + title varchar_normal +); + +CREATE INDEX idx_item_content_link_item_id ON item_content_link(item_id); + +--** ITEM > DESCRIPTION + +-- <item> -> <description> AND possibly other tags that contain a description +CREATE TABLE item_description ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL UNIQUE REFERENCES item(id) ON DELETE CASCADE, + value varchar_long NOT NULL +); + +CREATE INDEX idx_item_description_item_id ON item_description(item_id); + +--** ITEM > ENCLOSURE (AKA ALTERNATE ENCLOSURE) + +-- NOTE: the older <enclosure> tag style is integrated into the item_enclosure table. + +-- <item> -> <podcast:alternateEnclosure> AND <item> -> <enclosure> +CREATE TABLE item_enclosure ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + type varchar_short NOT NULL, + length INTEGER, + bitrate INTEGER, + height INTEGER, + language varchar_short, + title varchar_short, + rel varchar_short, + codecs varchar_short, + item_enclosure_default BOOLEAN DEFAULT FALSE +); + +CREATE INDEX idx_item_enclosure_item_id ON item_enclosure(item_id); + +-- <item> -> <podcast:alternateEnclosure> -> <podcast:source> +CREATE TABLE item_enclosure_source ( + id SERIAL PRIMARY KEY, + item_enclosure_id INTEGER NOT NULL REFERENCES item_enclosure(id) ON DELETE CASCADE, + uri varchar_uri NOT NULL, + content_type varchar_short +); + +CREATE INDEX idx_item_enclosure_source_item_id ON item_enclosure_source(item_enclosure_id); + +-- <item> -> <podcast:alternateEnclosure> -> <podcast:integrity> +CREATE TABLE item_enclosure_integrity ( + id SERIAL PRIMARY KEY, + item_enclosure_id INTEGER NOT NULL UNIQUE REFERENCES item_enclosure_source(id) ON DELETE CASCADE, + type TEXT NOT NULL CHECK (type IN ('sri', 'pgp-signature')), + value varchar_long NOT NULL +); + +CREATE INDEX idx_item_enclosure_integrity_item_enclosure_id ON item_enclosure_integrity(item_enclosure_id); + +--** ITEM > FUNDING + +-- <item> -> <podcast:funding> +CREATE TABLE item_funding ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + url varchar_url NOT NULL, + title varchar_normal +); + +CREATE INDEX idx_item_funding_item_id ON item_funding(item_id); + +--** ITEM > IMAGE + +-- <item> -> <podcast:image> AND all other image tags in the rss feed +CREATE TABLE item_image ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + url varchar_url NOT NULL, + image_width_size INTEGER, -- <podcast:image> must have a width specified, but older image tags will not, so allow null. + + -- If true, then the image is hosted by us in a service like S3. + -- When is_resized images are deleted, the corresponding image in S3 + -- should also be deleted. + is_resized BOOLEAN DEFAULT FALSE +); + +CREATE INDEX idx_item_image_item_id ON item_image(item_id); + +--** ITEM > LICENSE + +-- <item> -> <podcast:license> +CREATE TABLE item_license ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL UNIQUE REFERENCES item(id) ON DELETE CASCADE, + identifier varchar_normal NOT NULL, + url varchar_url +); + +CREATE INDEX idx_item_license_item_id ON item_license(item_id); + +--** ITEM > LOCATION + +-- <item> -> <podcast:location> +CREATE TABLE item_location ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL UNIQUE REFERENCES item(id) ON DELETE CASCADE, + geo varchar_normal, + osm varchar_normal, + CHECK (geo IS NOT NULL OR osm IS NOT NULL), + name varchar_normal +); + +CREATE INDEX idx_item_location_item_id ON item_location(item_id); + +--** ITEM > PERSON + +-- <item> -> <podcast:person> +CREATE TABLE item_person ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + name varchar_normal NOT NULL, + role varchar_normal, + person_group varchar_normal DEFAULT 'cast', -- group is a reserved keyword in sql + img varchar_url, + href varchar_url +); + +CREATE INDEX idx_item_person_item_id ON item_person(item_id); + +--** ITEM > SEASON + +-- <item> -> <podcast:season> +CREATE TABLE item_season ( + id SERIAL PRIMARY KEY, + channel_season_id INTEGER NOT NULL REFERENCES channel_season(id) ON DELETE CASCADE, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + title varchar_normal +); + +CREATE INDEX idx_item_season_channel_season_id ON item_season(channel_season_id); +CREATE INDEX idx_item_season_item_id ON item_season(item_id); + +--** ITEM > SEASON > EPISODE + +-- <item> -> <podcast:season> -> <podcast:episode> +CREATE TABLE item_season_episode ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL UNIQUE REFERENCES item(id) ON DELETE CASCADE, + display varchar_short, + number FLOAT NOT NULL +); + +CREATE INDEX idx_item_season_episode_item_id ON item_season_episode(item_id); + +--** ITEM > SOCIAL INTERACT + +-- <item> -> <podcast:socialInteract> +CREATE TABLE item_social_interact ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + protocol varchar_short NOT NULL, + uri varchar_uri NOT NULL, + account_id varchar_normal, + account_url varchar_url, + priority INTEGER +); + +CREATE INDEX idx_item_social_interact_item_id ON item_social_interact(item_id); + +--** ITEM > SOUNDBITE + +-- <item> -> <podcast:soundbite> +CREATE TABLE item_soundbite ( + id SERIAL PRIMARY KEY, + id_text short_id_v2 UNIQUE NOT NULL, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + start_time media_player_time NOT NULL, + duration media_player_time NOT NULL, + title varchar_normal +); + +CREATE INDEX idx_item_soundbite_item_id ON item_soundbite(item_id); + +--** ITEM > TRANSCRIPT + +-- <item> -> <podcast:transcript> +CREATE TABLE item_transcript ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + url varchar_url NOT NULL, + type varchar_short NOT NULL, + language varchar_short, + rel VARCHAR(50) CHECK (rel IS NULL OR rel = 'captions') +); + +CREATE INDEX idx_item_transcript_item_id ON item_transcript(item_id); + +--** ITEM > TXT + +-- <item> -> <podcast:txt> +CREATE TABLE item_txt ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + purpose varchar_normal, + value varchar_long NOT NULL +); + +CREATE INDEX idx_item_txt_item_id ON item_txt(item_id); + +--** ITEM > VALUE + +-- <item> -> <podcast:value> +CREATE TABLE item_value ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + type varchar_short NOT NULL, + method varchar_short NOT NULL, + suggested FLOAT +); + +CREATE INDEX idx_item_value_item_id ON item_value(item_id); + +--** ITEM > VALUE > RECEIPIENT + +-- <item> -> <podcast:value> -> <podcast:valueRecipient> +CREATE TABLE item_value_recipient ( + id SERIAL PRIMARY KEY, + item_value_id INTEGER NOT NULL REFERENCES item_value(id) ON DELETE CASCADE, + type varchar_short NOT NULL, + address varchar_long NOT NULL, + split FLOAT NOT NULL, + name varchar_normal, + custom_key varchar_long, + custom_value varchar_long, + fee BOOLEAN DEFAULT FALSE +); + +CREATE INDEX idx_item_value_recipient_item_value_id ON item_value_recipient(item_value_id); + +--** ITEM > VALUE > TIME SPLIT + +-- <item> -> <podcast:value> -> <podcast:valueTimeSplit> +CREATE TABLE item_value_time_split ( + id SERIAL PRIMARY KEY, + item_value_id INTEGER NOT NULL REFERENCES item_value(id) ON DELETE CASCADE, + start_time media_player_time NOT NULL, + duration media_player_time NOT NULL, + remote_start_time media_player_time DEFAULT 0, + remote_percentage media_player_time DEFAULT 100 +); + +CREATE INDEX idx_item_value_time_split_item_value_id ON item_value_time_split(item_value_id); + +--** ITEM > VALUE > TIME SPLIT > REMOTE ITEM + +-- <item> -> <podcast:value> -> <podcast:valueTimeSplit> -> <podcast:remoteItem> +CREATE TABLE item_value_time_split_remote_item ( + id SERIAL PRIMARY KEY, + item_value_time_split_id INTEGER NOT NULL UNIQUE REFERENCES item_value_time_split(id) ON DELETE CASCADE, + feed_guid UUID NOT NULL, + feed_url varchar_url, + item_guid varchar_uri, + title varchar_normal +); + +CREATE INDEX idx_item_value_time_split_remote_item_item_value_time_split_id ON item_value_time_split_remote_item(item_value_time_split_id); +CREATE INDEX idx_item_value_time_split_remote_item_feed_guid ON item_value_time_split_remote_item(feed_guid); +CREATE INDEX idx_item_value_time_split_remote_item_feed_url ON item_value_time_split_remote_item(feed_url); +CREATE INDEX idx_item_value_time_split_remote_item_item_guid ON item_value_time_split_remote_item(item_guid); + +--** ITEM > VALUE > TIME SPLIT > VALUE RECIPEINT + +-- <item> -> <podcast:value> -> <podcast:valueTimeSplit> -> <podcast:valueRecipient> +CREATE TABLE item_value_time_split_recipient ( + id SERIAL PRIMARY KEY, + item_value_time_split_id INTEGER NOT NULL REFERENCES item_value_time_split(id) ON DELETE CASCADE, + type varchar_short NOT NULL, + address varchar_long NOT NULL, + split FLOAT NOT NULL, + name varchar_normal, + custom_key varchar_long, + custom_value varchar_long, + fee BOOLEAN DEFAULT FALSE +); + +CREATE INDEX idx_item_value_time_split_recipient_item_value_time_split_id ON item_value_time_split_recipient(item_value_time_split_id); + +--** LIVE ITEM > STATUS + +CREATE TABLE live_item_status ( + id SERIAL PRIMARY KEY, + status TEXT UNIQUE CHECK (status IN ('pending', 'live', 'ended')) +); + +INSERT INTO live_item_status (status) VALUES ('pending'), ('live'), ('ended'); + +--** LIVE ITEM + +-- Technically the live_item table could be named channel_live_item, +-- but for consistency with the item table, it is called live_item. + +-- <channel> -> <podcast:liveItem> +CREATE TABLE live_item ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL UNIQUE REFERENCES item(id) ON DELETE CASCADE, + live_item_status_id INTEGER NOT NULL REFERENCES live_item_status(id), + start_time TIMESTAMPTZ NOT NULL, + end_time TIMESTAMPTZ, + chat_web_url varchar_url +); + +CREATE INDEX idx_live_item_item_id ON live_item(item_id); +CREATE INDEX idx_live_item_live_item_status_id ON live_item(live_item_status_id); + +-- 0002 migration + +CREATE TABLE sharable_status ( + id SERIAL PRIMARY KEY, + status TEXT UNIQUE CHECK (status IN ('public', 'unlisted', 'private')) +); + +INSERT INTO sharable_status (status) VALUES ('public'), ('unlisted'), ('private'); + +CREATE TABLE account ( + id SERIAL PRIMARY KEY, + id_text short_id_v2 UNIQUE NOT NULL, + verified BOOLEAN DEFAULT FALSE, + sharable_status_id INTEGER NOT NULL REFERENCES sharable_status(id) +); + +CREATE INDEX idx_account_sharable_status_id ON account(sharable_status_id); + +CREATE TABLE account_credentials ( + id SERIAL PRIMARY KEY, + account_id integer REFERENCES account(id) ON DELETE CASCADE, + email varchar_email UNIQUE NOT NULL, + password varchar_password NOT NULL +); + +CREATE INDEX idx_account_credentials_account_id ON account_credentials(account_id); + +CREATE TABLE account_profile ( + id SERIAL PRIMARY KEY, + account_id integer REFERENCES account(id) ON DELETE CASCADE, + display_name varchar_normal, + bio varchar_long +); + +CREATE INDEX idx_account_profile_account_id ON account_profile(account_id); + +CREATE TABLE account_reset_password ( + id SERIAL PRIMARY KEY, + account_id integer REFERENCES account(id) ON DELETE CASCADE, + reset_token varchar_guid, + reset_token_expires_at TIMESTAMP +); + +CREATE INDEX idx_account_reset_password_account_id ON account_reset_password(account_id); + +CREATE TABLE account_verification ( + id SERIAL PRIMARY KEY, + account_id integer REFERENCES account(id) ON DELETE CASCADE, + verification_token varchar_guid, + verification_token_expires_at TIMESTAMP +); + +CREATE INDEX idx_account_verification_account_id ON account_verification(account_id); + +CREATE TABLE account_membership ( + id SERIAL PRIMARY KEY, + tier TEXT UNIQUE CHECK (tier IN ('trial', 'basic')) +); + +INSERT INTO account_membership (tier) VALUES ('trial'), ('basic'); + +CREATE TABLE account_membership_status ( + id SERIAL PRIMARY KEY, + account_id integer REFERENCES account(id) ON DELETE CASCADE, + account_membership_id INTEGER NOT NULL REFERENCES account_membership(id), + membership_expires_at TIMESTAMP +); + +CREATE INDEX idx_account_membership_status_account_id ON account_membership_status(account_id); +CREATE INDEX idx_account_membership_status_account_membership_id ON account_membership_status(account_membership_id); + +CREATE TABLE account_admin_roles ( + id SERIAL PRIMARY KEY, + account_id integer REFERENCES account(id) ON DELETE CASCADE, + dev_admin BOOLEAN DEFAULT FALSE, + podping_admin BOOLEAN DEFAULT FALSE +); + +CREATE INDEX idx_account_admin_roles_account_id ON account_admin_roles(account_id); + +-- 0003 migration + +CREATE TABLE clip ( + id SERIAL PRIMARY KEY, + id_text short_id_v2 UNIQUE NOT NULL, + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + start_time media_player_time NOT NULL, + end_time media_player_time, + title varchar_normal, + description varchar_long, + sharable_status_id INTEGER NOT NULL REFERENCES sharable_status(id) +); + +CREATE INDEX idx_clip_account_id ON clip(account_id); +CREATE INDEX idx_clip_item_id ON clip(item_id); +CREATE INDEX idx_clip_sharable_status_id ON clip(sharable_status_id); + +-- 0004 migration + +CREATE TABLE playlist ( + id SERIAL PRIMARY KEY, + id_text short_id_v2 UNIQUE NOT NULL, + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + sharable_status_id INTEGER NOT NULL REFERENCES sharable_status(id), + title varchar_normal, + description varchar_long, + is_default_favorites BOOLEAN DEFAULT FALSE, + is_public BOOLEAN DEFAULT FALSE, + item_count INTEGER DEFAULT 0, + medium_id INTEGER NOT NULL REFERENCES medium(id) +); + +CREATE INDEX idx_playlist_account_id ON playlist(account_id); +CREATE INDEX idx_playlist_sharable_status_id ON playlist(sharable_status_id); +CREATE INDEX idx_playlist_medium_id ON playlist(medium_id); + +CREATE TABLE playlist_resource_base ( + id SERIAL PRIMARY KEY, + playlist_id INTEGER NOT NULL REFERENCES playlist(id) ON DELETE CASCADE, + list_position list_position NOT NULL CHECK (list_position != 0 OR list_position = 0::numeric), + UNIQUE (playlist_id, list_position) +); + +CREATE INDEX idx_playlist_resource_base_playlist_id ON playlist_resource_base(playlist_id); + +CREATE TABLE playlist_resource_item ( + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE +) INHERITS (playlist_resource_base); + +CREATE INDEX idx_playlist_resource_item_item_id ON playlist_resource_item(item_id); + +CREATE TABLE playlist_resource_item_add_by_rss ( + resource_data jsonb NOT NULL +) INHERITS (playlist_resource_base); + +CREATE INDEX idx_playlist_resource_item_add_by_rss_resource_data ON playlist_resource_item_add_by_rss USING gin (resource_data); + +CREATE TABLE playlist_resource_item_chapter ( + item_chapter_id INTEGER NOT NULL REFERENCES item_chapter(id) ON DELETE CASCADE +) INHERITS (playlist_resource_base); + +CREATE INDEX idx_playlist_resource_item_chapter_item_chapter_id ON playlist_resource_item_chapter(item_chapter_id); + +CREATE TABLE playlist_resource_clip ( + clip_id INTEGER NOT NULL REFERENCES clip(id) ON DELETE CASCADE +) INHERITS (playlist_resource_base); + +CREATE INDEX idx_playlist_resource_clip_clip_id ON playlist_resource_clip(clip_id); + +CREATE TABLE playlist_resource_item_soundbite ( + soundbite_id INTEGER NOT NULL REFERENCES item_soundbite(id) ON DELETE CASCADE +) INHERITS (playlist_resource_base); + +CREATE INDEX idx_playlist_resource_item_soundbite_soundbite_id ON playlist_resource_item_soundbite(soundbite_id); + +CREATE OR REPLACE FUNCTION delete_playlist_resource_base() +RETURNS TRIGGER AS $$ +BEGIN + DELETE FROM playlist_resource_base WHERE id = OLD.id; + RETURN OLD; +END; +$$ LANGUAGE plpgsql; + +CREATE TRIGGER delete_playlist_resource_base_trigger_item +BEFORE DELETE ON playlist_resource_item +FOR EACH ROW +EXECUTE FUNCTION delete_playlist_resource_base(); + +CREATE TRIGGER delete_playlist_resource_base_trigger_item_add_by_rss +BEFORE DELETE ON playlist_resource_item_add_by_rss +FOR EACH ROW +EXECUTE FUNCTION delete_playlist_resource_base(); + +CREATE TRIGGER delete_playlist_resource_base_trigger_item_chapter +BEFORE DELETE ON playlist_resource_item_chapter +FOR EACH ROW +EXECUTE FUNCTION delete_playlist_resource_base(); + +CREATE TRIGGER delete_playlist_resource_base_trigger_clip +BEFORE DELETE ON playlist_resource_clip +FOR EACH ROW +EXECUTE FUNCTION delete_playlist_resource_base(); + +CREATE TRIGGER delete_playlist_resource_base_trigger_item_soundbite +BEFORE DELETE ON playlist_resource_item_soundbite +FOR EACH ROW +EXECUTE FUNCTION delete_playlist_resource_base(); + +-- 0005 migration + +CREATE TABLE queue ( + id SERIAL PRIMARY KEY, + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + medium_id INTEGER NOT NULL REFERENCES medium(id), + UNIQUE (account_id, medium_id) +); + +CREATE INDEX idx_queue_account_id ON queue(account_id); +CREATE INDEX idx_queue_medium_id ON queue(medium_id); + +CREATE TABLE queue_resource_base ( + id SERIAL PRIMARY KEY, + queue_id INTEGER NOT NULL REFERENCES queue(id) ON DELETE CASCADE, + UNIQUE (queue_id, list_position), + list_position list_position NOT NULL CHECK (list_position != 0 OR list_position = 0::numeric), + playback_position media_player_time NOT NULL DEFAULT 0, + media_file_duration media_player_time NOT NULL DEFAULT 0, + completed BOOLEAN NOT NULL DEFAULT FALSE +); + +CREATE INDEX idx_queue_resource_base_queue_id ON queue_resource_base(queue_id); + +CREATE TABLE queue_resource_item ( + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + UNIQUE (queue_id) +) INHERITS (queue_resource_base); + +CREATE INDEX idx_queue_resource_item_item_id ON queue_resource_item(item_id); + +CREATE TABLE queue_resource_item_add_by_rss ( + resource_data jsonb NOT NULL, + UNIQUE (queue_id) +) INHERITS (queue_resource_base); + +CREATE INDEX idx_queue_resource_item_add_by_rss_resource_data ON queue_resource_item_add_by_rss USING gin (resource_data); + +CREATE TABLE queue_resource_item_chapter ( + item_chapter_id INTEGER NOT NULL REFERENCES item_chapter(id) ON DELETE CASCADE, + UNIQUE (queue_id) +) INHERITS (queue_resource_base); + +CREATE INDEX idx_queue_resource_item_chapter_item_chapter_id ON queue_resource_item_chapter(item_chapter_id); + +CREATE TABLE queue_resource_clip ( + clip_id INTEGER NOT NULL REFERENCES clip(id) ON DELETE CASCADE, + UNIQUE (queue_id) +) INHERITS (queue_resource_base); + +CREATE INDEX idx_queue_resource_clip_clip_id ON queue_resource_clip(clip_id); + +CREATE TABLE queue_resource_item_soundbite ( + soundbite_id INTEGER NOT NULL REFERENCES item_soundbite(id) ON DELETE CASCADE, + UNIQUE (queue_id) +) INHERITS (queue_resource_base); + +CREATE INDEX idx_queue_resource_item_soundbite_soundbite_id ON queue_resource_item_soundbite(soundbite_id); + +CREATE OR REPLACE FUNCTION delete_queue_resource_base() +RETURNS TRIGGER AS $$ +BEGIN + DELETE FROM queue_resource_base WHERE id = OLD.id; + RETURN OLD; +END; +$$ LANGUAGE plpgsql; + +CREATE TRIGGER delete_queue_resource_base_trigger_item +BEFORE DELETE ON queue_resource_item +FOR EACH ROW +EXECUTE FUNCTION delete_queue_resource_base(); + +CREATE TRIGGER delete_queue_resource_base_trigger_item_add_by_rss +BEFORE DELETE ON queue_resource_item_add_by_rss +FOR EACH ROW +EXECUTE FUNCTION delete_queue_resource_base(); + +CREATE TRIGGER delete_queue_resource_base_trigger_item_chapter +BEFORE DELETE ON queue_resource_item_chapter +FOR EACH ROW +EXECUTE FUNCTION delete_queue_resource_base(); + +CREATE TRIGGER delete_queue_resource_base_trigger_clip +BEFORE DELETE ON queue_resource_clip +FOR EACH ROW +EXECUTE FUNCTION delete_queue_resource_base(); + +CREATE TRIGGER delete_queue_resource_base_trigger_item_soundbite +BEFORE DELETE ON queue_resource_item_soundbite +FOR EACH ROW +EXECUTE FUNCTION delete_queue_resource_base(); + +-- 0006 migration + +CREATE TABLE account_following_account ( + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + following_account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + PRIMARY KEY (account_id, following_account_id) +); + +CREATE INDEX idx_account_following_account_account_id ON account_following_account(account_id); +CREATE INDEX idx_account_following_account_following_account_id ON account_following_account(following_account_id); + +CREATE TABLE account_following_channel ( + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + PRIMARY KEY (account_id, channel_id) +); + +CREATE INDEX idx_account_following_channel_account_id ON account_following_channel(account_id); +CREATE INDEX idx_account_following_channel_channel_id ON account_following_channel(channel_id); + +CREATE TABLE account_following_playlist ( + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + playlist_id INTEGER NOT NULL REFERENCES playlist(id) ON DELETE CASCADE, + PRIMARY KEY (account_id, playlist_id) +); + +CREATE INDEX idx_account_following_playlist_account_id ON account_following_playlist(account_id); +CREATE INDEX idx_account_following_playlist_playlist_id ON account_following_playlist(playlist_id); + +CREATE TABLE account_following_add_by_rss_channel ( + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + feed_url varchar_url NOT NULL, + PRIMARY KEY (account_id, feed_url), + title varchar_normal, + image_url varchar_url +); + +CREATE INDEX idx_account_following_add_by_rss_channel_account_id ON account_following_add_by_rss_channel(account_id); + +-- 0007 + +CREATE TABLE account_notification ( + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + PRIMARY KEY (channel_id, account_id) +); + +CREATE INDEX idx_account_notification_channel_id ON account_notification(channel_id); +CREATE INDEX idx_account_notification_account_id ON account_notification(account_id); + +CREATE TABLE account_up_device ( + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + up_endpoint varchar_url PRIMARY KEY, + up_public_key varchar_long NOT NULL, + up_auth_key varchar_long NOT NULL +); + +CREATE INDEX idx_account_up_device_account_id ON account_up_device(account_id); + +CREATE TABLE account_fcm_device ( + fcm_token varchar_fcm_token PRIMARY KEY, + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE +); + +CREATE INDEX idx_account_fcm_device_account_id ON account_fcm_device(account_id); + +-- 0008 + +CREATE TABLE account_paypal_order ( + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + payment_id VARCHAR PRIMARY KEY, + state VARCHAR +); + +CREATE INDEX idx_account_paypal_order_account_id ON account_paypal_order(account_id); + +CREATE TABLE account_app_store_purchase ( + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + transaction_id VARCHAR PRIMARY KEY, + cancellation_date VARCHAR, + cancellation_date_ms VARCHAR, + cancellation_date_pst VARCHAR, + cancellation_reason VARCHAR, + expires_date VARCHAR, + expires_date_ms VARCHAR, + expires_date_pst VARCHAR, + is_in_intro_offer_period BOOLEAN, + is_trial_period BOOLEAN, + original_purchase_date VARCHAR, + original_purchase_date_ms VARCHAR, + original_purchase_date_pst VARCHAR, + original_transaction_id VARCHAR, + product_id VARCHAR, + promotional_offer_id VARCHAR, + purchase_date VARCHAR, + purchase_date_ms VARCHAR, + purchase_date_pst VARCHAR, + quantity INT, + web_order_line_item_id VARCHAR +); + +CREATE INDEX idx_account_app_store_purchase_account_id ON account_app_store_purchase(account_id); + +CREATE TABLE account_google_play_purchase ( + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + transaction_id VARCHAR PRIMARY KEY, + acknowledgement_state INT NULL, + consumption_state INT NULL, + developer_payload VARCHAR NULL, + kind VARCHAR NULL, + product_id VARCHAR NOT NULL, + purchase_time_millis VARCHAR NULL, + purchase_state INT NULL, + purchase_token VARCHAR UNIQUE NOT NULL +); + +CREATE INDEX idx_account_google_play_purchase_account_id ON account_google_play_purchase(account_id); + +-- 0009 + +CREATE TABLE membership_claim_token ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + claimed BOOLEAN DEFAULT FALSE, + years_to_add INT DEFAULT 1, + account_membership_id INT REFERENCES account_membership(id) ON DELETE CASCADE +); + +CREATE INDEX idx_membership_claim_token_account_membership_id ON membership_claim_token(account_membership_id); + diff --git a/database/migrations/0000_init_helpers.sql b/database/migrations/0000_init_helpers.sql new file mode 100644 index 0000000..c39b172 --- /dev/null +++ b/database/migrations/0000_init_helpers.sql @@ -0,0 +1,38 @@ +-- 0000 migration + +-- Helpers + +-- In the previous version of the app, short_id was 7-14 characters long. +-- To make migration to v2 easier, we will use a 15 character long short_id, +-- so we can easily distinguish between v1 and v2 short_ids. +CREATE DOMAIN short_id_v2 AS VARCHAR(15); + +CREATE DOMAIN varchar_short AS VARCHAR(50); +CREATE DOMAIN varchar_normal AS VARCHAR(255); +CREATE DOMAIN varchar_long AS VARCHAR(2500); + +CREATE DOMAIN varchar_email AS VARCHAR(255) CHECK (VALUE ~ '^.+@.+\..+$'); +CREATE DOMAIN varchar_fcm_token AS VARCHAR(255); +CREATE DOMAIN varchar_fqdn AS VARCHAR(253); +CREATE DOMAIN varchar_guid AS VARCHAR(36); +CREATE DOMAIN varchar_md5 AS VARCHAR(32); +CREATE DOMAIN varchar_password AS VARCHAR(36); +CREATE DOMAIN varchar_slug AS VARCHAR(100); +CREATE DOMAIN varchar_uri AS VARCHAR(2083); +CREATE DOMAIN varchar_url AS VARCHAR(2083) CHECK (VALUE ~ '^https?://|^http?://'); + +CREATE DOMAIN server_time AS TIMESTAMP; +CREATE DOMAIN server_time_with_default AS TIMESTAMP DEFAULT NOW(); + +CREATE DOMAIN media_player_time AS NUMERIC(10, 2); +CREATE DOMAIN list_position AS NUMERIC(22, 21); +CREATE DOMAIN numeric_20_11 AS NUMERIC(20, 11); + +-- Function to set updated_at +CREATE OR REPLACE FUNCTION set_updated_at_field() +RETURNS TRIGGER AS $$ +BEGIN + NEW.updated_at := NOW(); + RETURN NEW; +END; +$$ LANGUAGE plpgsql; diff --git a/database/migrations/0001_init_podcasting_20_database.sql b/database/migrations/0001_init_podcasting_20_database.sql new file mode 100644 index 0000000..bdbe726 --- /dev/null +++ b/database/migrations/0001_init_podcasting_20_database.sql @@ -0,0 +1,913 @@ +-- 0001 migration + +/* + +PODCASTING 2.0 DATABASE SCHEMA + +- The `id` column is a SERIAL column that is used as the primary key for every table. + +- The `id_text` column is only intended for tables where the data is available as urls. + For example, https://podverse.fm/podcast/abc123def456, the `id_text` column would be `abc123def456`. + +- The `slug` column is not required, but functions as an alternative for `id_text`. + For example, https://podverse.fm/podcast/podcasting-20 would have a `slug` column with the value `podcasting-20`. + +- The `podcast_index_id` ensures that our database only contains feed data that is available in the Podcast Index API. + +*/ + +----------** GLOBAL REFERENCE TABLES **---------- +-- These tables are referenced across many tables, and must be created first. + +--** CATEGORY + +-- Allowed category values align with the standard categories and subcategories +-- supported by Apple iTunes through the <itunes:category> tag. +-- +CREATE TABLE category ( + id SERIAL PRIMARY KEY, + node_text varchar_normal NOT NULL, -- <itunes:category> + display_name varchar_normal NOT NULL, -- our own display name for the category + slug varchar_normal NOT NULL -- our own slug for the category +); + +--** MEDIUM VALUE + +-- <podcast:medium> +CREATE TABLE medium ( + id SERIAL PRIMARY KEY, + value TEXT UNIQUE CHECK (VALUE IN ( + 'publisher', + 'podcast', 'music', 'video', 'film', 'audiobook', 'newsletter', 'blog', 'publisher', 'course', + 'mixed', 'podcastL', 'musicL', 'videoL', 'filmL', 'audiobookL', 'newsletterL', 'blogL', 'publisherL', 'courseL' + )) +); + +INSERT INTO medium (value) VALUES + ('publisher'), + ('podcast'), ('music'), ('video'), ('film'), ('audiobook'), ('newsletter'), ('blog'), ('course'), + ('mixed'), ('podcastL'), ('musicL'), ('videoL'), ('filmL'), ('audiobookL'), ('newsletterL'), ('blogL'), ('publisherL'), ('courseL') +; + +----------** TABLES **---------- + +--** FEED > FLAG STATUS + +-- used internally for identifying and handling spam and other special flag statuses. +CREATE TABLE feed_flag_status ( + id SERIAL PRIMARY KEY, + status TEXT UNIQUE CHECK (status IN ('none', 'spam', 'takedown', 'other', 'always-allow')), + created_at server_time_with_default, + updated_at server_time_with_default +); + +CREATE TRIGGER set_updated_at_feed_flag_status +BEFORE UPDATE ON feed_flag_status +FOR EACH ROW +EXECUTE FUNCTION set_updated_at_field(); + +INSERT INTO feed_flag_status (status) VALUES ('none'), ('spam'), ('takedown'), ('other'), ('always-allow'); + +--** FEED + +-- The top-level table for storing feed data, and internal parsing data. +CREATE TABLE feed ( + id SERIAL PRIMARY KEY, + url varchar_url UNIQUE NOT NULL, + + -- feed flag + feed_flag_status_id INTEGER NOT NULL REFERENCES feed_flag_status(id), + + -- internal + + -- Used to prevent another thread from parsing the same feed. + -- Set to current time at beginning of parsing, and NULL at end of parsing. + -- This is to prevent multiple threads from parsing the same feed. + -- If is_parsing is over X minutes old, assume last parsing failed and proceed to parse. + is_parsing server_time, + + -- 0 will only be parsed when PI API reports an update. + -- higher parsing_priority will be parsed more frequently on a schedule. + parsing_priority INTEGER DEFAULT 0 CHECK (parsing_priority BETWEEN 0 AND 5), + + -- the hash of the last parsed feed file. + -- used for comparison to determine if full re-parsing is needed. + last_parsed_file_hash varchar_md5, + + -- the run-time environment container id + container_id VARCHAR(12), + + created_at server_time_with_default, + updated_at server_time_with_default +); + +CREATE INDEX idx_feed_feed_flag_status_id ON feed(feed_flag_status_id); + +CREATE TRIGGER set_updated_at_feed +BEFORE UPDATE ON feed +FOR EACH ROW +EXECUTE FUNCTION set_updated_at_field(); + +CREATE TABLE feed_log ( + id SERIAL PRIMARY KEY, + feed_id INTEGER NOT NULL UNIQUE REFERENCES feed(id) ON DELETE CASCADE, + last_http_status INTEGER, + last_good_http_status_time server_time, + last_finished_parse_time server_time, + parse_errors INTEGER DEFAULT 0 +); + +CREATE INDEX idx_feed_log_feed_id ON feed_log(feed_id); + +--** CHANNEL + +-- <channel> +CREATE TABLE channel ( + id SERIAL PRIMARY KEY, + id_text short_id_v2 UNIQUE NOT NULL, + slug varchar_slug, + feed_id INTEGER NOT NULL UNIQUE REFERENCES feed(id) ON DELETE CASCADE, + podcast_index_id INTEGER UNIQUE NOT NULL, + podcast_guid UUID UNIQUE, -- <podcast:guid> + title varchar_normal, + sortable_title varchar_short, -- all lowercase, ignores articles at beginning of title + medium_id INTEGER REFERENCES medium(id), + + -- channels that have a PI value tag require special handling to request value data + -- from the Podcast Index API. + has_podcast_index_value BOOLEAN DEFAULT FALSE, + + -- this column is used for optimization purposes to determine if all of the items + -- for a channel need to have their value time split remote items parsed. + has_value_time_splits BOOLEAN DEFAULT FALSE, + + -- hidden items are no longer available in the rss feed, but are still in the database. + hidden BOOLEAN DEFAULT FALSE, + -- markedForDeletion items are no longer available in the rss feed, and may be able to be deleted. + marked_for_deletion BOOLEAN DEFAULT FALSE +); + +CREATE UNIQUE INDEX channel_podcast_guid_unique ON channel(podcast_guid) WHERE podcast_guid IS NOT NULL; +CREATE UNIQUE INDEX channel_slug ON channel(slug) WHERE slug IS NOT NULL; +CREATE INDEX idx_channel_feed_id ON channel(feed_id); +CREATE INDEX idx_channel_medium_id ON channel(medium_id); + +--** CHANNEL > ABOUT > ITUNES TYPE + +-- <channel> -> <itunes:type> +CREATE TABLE channel_itunes_type ( + id SERIAL PRIMARY KEY, + itunes_type TEXT UNIQUE CHECK (itunes_type IN ('episodic', 'serial')) +); + +INSERT INTO channel_itunes_type (itunes_type) VALUES ('episodic'), ('serial'); + +--** CHANNEL > ABOUT + +-- various <channel> child data from multiple tags +CREATE TABLE channel_about ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL UNIQUE REFERENCES channel(id) ON DELETE CASCADE, + author varchar_normal, -- <itunes:author> and <author> + episode_count INTEGER, -- aggregated count for convenience + explicit BOOLEAN, -- <itunes:explicit> + itunes_type_id INTEGER REFERENCES channel_itunes_type(id), + language varchar_short, -- <language> + last_pub_date server_time_with_default, -- <pubDate> + website_link_url varchar_url -- <link> +); + +CREATE INDEX idx_channel_about_channel_id ON channel_about(channel_id); +CREATE INDEX idx_channel_about_itunes_type_id ON channel_about(itunes_type_id); + +--** CHANNEL > CATEGORY + +CREATE TABLE channel_category ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + parent_id INTEGER REFERENCES channel_category(id) ON DELETE CASCADE +); + +CREATE INDEX idx_channel_category_channel_id ON channel_category(channel_id); +CREATE INDEX idx_channel_category_parent_id ON channel_category(parent_id); + +--** CHANNEL > CHAT + +-- <channel> -> <podcast:chat> +CREATE TABLE channel_chat ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL UNIQUE REFERENCES channel(id) ON DELETE CASCADE, + server varchar_fqdn NOT NULL, + protocol varchar_short NOT NULL, + account_id varchar_normal, + space varchar_normal +); + +CREATE INDEX idx_channel_chat_channel_id ON channel_chat(channel_id); + +--** CHANNEL > DESCRIPTION + +-- <channel> -> <description> AND possibly other tags that contain a description +CREATE TABLE channel_description ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL UNIQUE REFERENCES channel(id) ON DELETE CASCADE, + value varchar_long NOT NULL +); + +CREATE INDEX idx_channel_description_channel_id ON channel_description(channel_id); + +--** CHANNEL > FUNDING + +-- <channel> -> <podcast:funding> +CREATE TABLE channel_funding ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + url varchar_url NOT NULL, + title varchar_normal +); + +CREATE INDEX idx_channel_funding_channel_id ON channel_funding(channel_id); + +--** CHANNEL > IMAGE + +-- <channel> -> <podcast:image> AND all other image tags in the rss feed +CREATE TABLE channel_image ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + url varchar_url NOT NULL, + image_width_size INTEGER, -- <podcast:image> must have a width specified, but older image tags will not, so allow null. + + -- If true, then the image is hosted by us in a service like S3. + -- When is_resized images are deleted, the corresponding image in S3 + -- should also be deleted. + is_resized BOOLEAN DEFAULT FALSE +); + +CREATE INDEX idx_channel_image_channel_id ON channel_image(channel_id); + +--** CHANNEL > INTERNAL SETTINGS + +CREATE TABLE channel_internal_settings ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + -- needed to approve which web domains can override the player with query params. + -- this prevents malicious parties from misrepresenting the podcast contents on another website. + embed_approved_media_url_paths TEXT +); + +CREATE INDEX idx_channel_internal_settings_channel_id ON channel_internal_settings(channel_id); + +--** CHANNEL > LICENSE + +-- <channel> -> <podcast:license> +CREATE TABLE channel_license ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL UNIQUE REFERENCES channel(id) ON DELETE CASCADE, + identifier varchar_normal NOT NULL, + url varchar_url +); + +CREATE INDEX idx_channel_license_channel_id ON channel_license(channel_id); + +--** CHANNEL > LOCATION + +-- <channel> -> <podcast:location> +CREATE TABLE channel_location ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL UNIQUE REFERENCES channel(id) ON DELETE CASCADE, + geo varchar_normal, + osm varchar_normal, + CHECK (geo IS NOT NULL OR osm IS NOT NULL), + name varchar_normal +); + +CREATE INDEX idx_channel_location_channel_id ON channel_location(channel_id); + +--** CHANNEL > PERSON + +-- <channel> -> <podcast:person> +CREATE TABLE channel_person ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + name varchar_normal NOT NULL, + role varchar_normal, + person_group varchar_normal DEFAULT 'cast', -- group is a reserved keyword in sql + img varchar_url, + href varchar_url +); + +CREATE INDEX idx_channel_person_channel_id ON channel_person(channel_id); + +--** CHANNEL > PODROLL + +-- <channel> -> <podcast:podroll> +CREATE TABLE channel_podroll ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL UNIQUE REFERENCES channel(id) ON DELETE CASCADE +); + +CREATE INDEX idx_channel_podroll_channel_id ON channel_podroll(channel_id); + +--** CHANNEL > PODROLL > REMOTE ITEM + +-- <channel> -> <podcast:podroll> --> <podcast:remoteItem> +CREATE TABLE channel_podroll_remote_item ( + id SERIAL PRIMARY KEY, + channel_podroll_id INTEGER NOT NULL REFERENCES channel_podroll(id) ON DELETE CASCADE, + feed_guid UUID NOT NULL, + feed_url varchar_url, + item_guid varchar_uri, + title varchar_normal, + medium_id INTEGER REFERENCES medium(id) +); + +CREATE INDEX idx_channel_podroll_remote_item_channel_podroll_id ON channel_podroll_remote_item(channel_podroll_id); +CREATE INDEX idx_channel_podroll_remote_item_medium_id ON channel_podroll_remote_item(medium_id); +CREATE INDEX idx_channel_podroll_remote_item_feed_guid ON channel_podroll_remote_item(feed_guid); +CREATE INDEX idx_channel_podroll_remote_item_feed_url ON channel_podroll_remote_item(feed_url); +CREATE INDEX idx_channel_podroll_remote_item_item_guid ON channel_podroll_remote_item(item_guid); + +--** CHANNEL > PUBLISHER + +-- <channel> -> <podcast:publisher> +CREATE TABLE channel_publisher ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL UNIQUE REFERENCES channel(id) ON DELETE CASCADE +); + +CREATE INDEX idx_channel_publisher_channel_id ON channel_publisher(channel_id); + +--** CHANNEL > PUBLISHER > REMOTE ITEM + +-- <channel> -> <podcast:publisher> -> <podcast:remoteItem> +CREATE TABLE channel_publisher_remote_item ( + id SERIAL PRIMARY KEY, + channel_publisher_id INTEGER NOT NULL UNIQUE REFERENCES channel_publisher(id) ON DELETE CASCADE, + feed_guid UUID NOT NULL, + feed_url varchar_url, + item_guid varchar_uri, + title varchar_normal, + medium_id INTEGER REFERENCES medium(id) +); + +CREATE INDEX idx_channel_publisher_remote_item_channel_publisher_id ON channel_publisher_remote_item(channel_publisher_id); +CREATE INDEX idx_channel_publisher_remote_item_medium_id ON channel_publisher_remote_item(medium_id); +CREATE INDEX idx_channel_publisher_remote_item_feed_guid ON channel_publisher_remote_item(feed_guid); +CREATE INDEX idx_channel_publisher_remote_item_feed_url ON channel_publisher_remote_item(feed_url); +CREATE INDEX idx_channel_publisher_remote_item_item_guid ON channel_publisher_remote_item(item_guid); + +--** CHANNEL > REMOTE ITEM + +-- Remote items at the channel level are only used when the <podcast:medium> for the channel +-- is set to 'mixed' or another list medium like 'podcastL'. + +-- <channel> -> <podcast:remoteItem> +CREATE TABLE channel_remote_item ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + feed_guid UUID NOT NULL, + feed_url varchar_url, + item_guid varchar_uri, + title varchar_normal, + medium_id INTEGER REFERENCES medium(id) +); + +CREATE INDEX idx_channel_remote_item_channel_id ON channel_remote_item(channel_id); +CREATE INDEX idx_channel_remote_item_medium_id ON channel_remote_item(medium_id); +CREATE INDEX idx_channel_remote_item_feed_guid ON channel_remote_item(feed_guid); +CREATE INDEX idx_channel_remote_item_feed_url ON channel_remote_item(feed_url); +CREATE INDEX idx_channel_remote_item_item_guid ON channel_remote_item(item_guid); + +--** CHANNEL > SEASON + +-- channels with seasons need to be rendered in client apps differently. +-- you can only determine if a channel is in a "season" format is by finding +-- the <itunes:season> tag in an item in that channel. + +-- NOTE: A channel season does not exist in the Podcasting 2.0 spec, +-- but it is useful for organizing seasons at the channel level, +-- and could be in the P2.0 spec someday. + +CREATE TABLE channel_season ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + number INTEGER NOT NULL, + UNIQUE (channel_id, number), + name varchar_normal +); + +CREATE INDEX idx_channel_season_channel_id ON channel_season(channel_id); + +--** CHANNEL > SOCIAL INTERACT + +-- <channel> -> <podcast:socialInteract> +CREATE TABLE channel_social_interact ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + protocol varchar_short NOT NULL, + uri varchar_uri NOT NULL, + account_id varchar_normal, + account_url varchar_url, + priority INTEGER +); + +CREATE INDEX idx_channel_social_interact_channel_id ON channel_social_interact(channel_id); + +--** CHANNEL > TRAILER + +-- <channel> -> <podcast:trailer> +CREATE TABLE channel_trailer ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + url varchar_url NOT NULL, + title varchar_normal, + pubdate TIMESTAMPTZ NOT NULL, + length INTEGER, + type varchar_short, + channel_season_id INTEGER REFERENCES channel_season(id), + UNIQUE (channel_id, url) +); + +CREATE INDEX idx_channel_trailer_channel_id ON channel_trailer(channel_id); +CREATE INDEX idx_channel_trailer_channel_season_id ON channel_trailer(channel_season_id); + +--** CHANNEL > TXT + +-- <channel> -> <podcast:txt> +CREATE TABLE channel_txt ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + purpose varchar_normal, + value varchar_long NOT NULL +); + +CREATE INDEX idx_channel_txt_channel_id ON channel_txt(channel_id); + +--** CHANNEL > VALUE + +-- <channel> -> <podcast:value> +CREATE TABLE channel_value ( + id SERIAL PRIMARY KEY, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + type varchar_short NOT NULL, + method varchar_short NOT NULL, + suggested FLOAT +); + +CREATE INDEX idx_channel_value_channel_id ON channel_value(channel_id); + +--** CHANNEL > VALUE > RECEIPIENT + +-- <channel> -> <podcast:value> -> <podcast:valueRecipient> +CREATE TABLE channel_value_recipient ( + id SERIAL PRIMARY KEY, + channel_value_id INTEGER NOT NULL REFERENCES channel_value(id) ON DELETE CASCADE, + type varchar_short NOT NULL, + address varchar_long NOT NULL, + split FLOAT NOT NULL, + name varchar_normal, + custom_key varchar_long, + custom_value varchar_long, + fee BOOLEAN DEFAULT FALSE +); + +CREATE INDEX idx_channel_value_recipient_channel_value_id ON channel_value_recipient(channel_value_id); + +--** ITEM + +-- Technically the item table could be named channel_item, but it seems easier to understand as item. + +-- <channel> -> <item> +CREATE TABLE item ( + id SERIAL PRIMARY KEY, + id_text short_id_v2 UNIQUE NOT NULL, + slug varchar_slug, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + guid varchar_uri, -- <guid> + guid_enclosure_url varchar_url NOT NULL, -- enclosure url + pubdate TIMESTAMPTZ, -- <pubDate> + title varchar_normal, -- <title> + + -- hidden items are no longer available in the rss feed, but are still in the database. + hidden BOOLEAN DEFAULT FALSE, + -- markedForDeletion items are no longer available in the rss feed, and may be able to be deleted. + marked_for_deletion BOOLEAN DEFAULT FALSE +); + +CREATE UNIQUE INDEX item_slug ON item(slug) WHERE slug IS NOT NULL; +CREATE INDEX idx_item_channel_id ON item(channel_id); + +--** ITEM > ABOUT > ITUNES TYPE + +-- <item> -> <itunes:episodeType> +CREATE TABLE item_itunes_episode_type ( + id SERIAL PRIMARY KEY, + itunes_episode_type TEXT UNIQUE CHECK (itunes_episode_type IN ('full', 'trailer', 'bonus')) +); + +INSERT INTO item_itunes_episode_type (itunes_episode_type) VALUES ('full'), ('trailer'), ('bonus'); + +--** ITEM > ABOUT + +CREATE TABLE item_about ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL UNIQUE REFERENCES item(id) ON DELETE CASCADE, + duration media_player_time, -- <itunes:duration> + explicit BOOLEAN, -- <itunes:explicit> + website_link_url varchar_url, -- <link> + item_itunes_episode_type_id INTEGER REFERENCES item_itunes_episode_type(id) -- <itunes:episodeType> +); + +CREATE INDEX idx_item_about_item_id ON item_about(item_id); +CREATE INDEX idx_item_about_item_itunes_episode_type_id ON item_about(item_itunes_episode_type_id); + +--** ITEM > CHAPTERS + +-- <item> -> <podcast:chapters> +CREATE TABLE item_chapters_feed ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL UNIQUE REFERENCES item(id) ON DELETE CASCADE, + url varchar_url NOT NULL, + type varchar_short NOT NULL +); + +CREATE INDEX idx_item_chapters_feed_item_id ON item_chapters_feed(item_id); + +--** ITEM > CHAPTERS > LOG + +-- <item> -> <podcast:chapters> -> parsing logs + +CREATE TABLE item_chapters_feed_log ( + id SERIAL PRIMARY KEY, + item_chapters_feed_id INTEGER NOT NULL UNIQUE REFERENCES item_chapters_feed(id) ON DELETE CASCADE, + last_http_status INTEGER, + last_good_http_status_time server_time, + last_finished_parse_time server_time, + parse_errors INTEGER DEFAULT 0 +); + +CREATE INDEX idx_item_chapters_feed_log_item_chapters_feed_id ON item_chapters_feed_log(item_chapters_feed_id); + +--** ITEM > CHAPTERS > CHAPTER + +-- -- <item> -> <podcast:chapters> -> chapter items correspond with jsonChapters.md example file +CREATE TABLE item_chapter ( + id SERIAL PRIMARY KEY, + id_text short_id_v2 UNIQUE NOT NULL, + item_chapters_feed_id INTEGER NOT NULL REFERENCES item_chapters_feed(id) ON DELETE CASCADE, + start_time media_player_time NOT NULL, + end_time media_player_time, + title varchar_normal, + img varchar_url, + web_url varchar_url, + table_of_contents BOOLEAN DEFAULT TRUE +); + +CREATE INDEX idx_item_chapter_item_chapters_feed_id ON item_chapter(item_chapters_feed_id); + +--** ITEM > CHAPTER > LOCATION + +-- <item> -> <podcast:chapters> -> chapter items correspond with jsonChapters.md example file +CREATE TABLE item_chapter_location ( + id SERIAL PRIMARY KEY, + item_chapter_id INTEGER NOT NULL UNIQUE REFERENCES item_chapter(id) ON DELETE CASCADE, + geo varchar_normal, + osm varchar_normal, + CHECK (geo IS NOT NULL OR osm IS NOT NULL), + name varchar_normal +); + +CREATE INDEX idx_item_chapter_location_item_chapter_id ON item_chapter_location(item_chapter_id); + +--** ITEM > CHAT + +-- <item> -> <podcast:chat> +CREATE TABLE item_chat ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL UNIQUE REFERENCES item(id) ON DELETE CASCADE, + server varchar_fqdn NOT NULL, + protocol varchar_short NOT NULL, + account_id varchar_normal, + space varchar_normal +); + +CREATE INDEX idx_item_chat_item_id ON item_chat(item_id); + +--** ITEM > CONTENT LINK + +-- <item> -> <podcast:contentLink> +CREATE TABLE item_content_link ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + href varchar_url NOT NULL, + title varchar_normal +); + +CREATE INDEX idx_item_content_link_item_id ON item_content_link(item_id); + +--** ITEM > DESCRIPTION + +-- <item> -> <description> AND possibly other tags that contain a description +CREATE TABLE item_description ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL UNIQUE REFERENCES item(id) ON DELETE CASCADE, + value varchar_long NOT NULL +); + +CREATE INDEX idx_item_description_item_id ON item_description(item_id); + +--** ITEM > ENCLOSURE (AKA ALTERNATE ENCLOSURE) + +-- NOTE: the older <enclosure> tag style is integrated into the item_enclosure table. + +-- <item> -> <podcast:alternateEnclosure> AND <item> -> <enclosure> +CREATE TABLE item_enclosure ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + type varchar_short NOT NULL, + length INTEGER, + bitrate INTEGER, + height INTEGER, + language varchar_short, + title varchar_short, + rel varchar_short, + codecs varchar_short, + item_enclosure_default BOOLEAN DEFAULT FALSE +); + +CREATE INDEX idx_item_enclosure_item_id ON item_enclosure(item_id); + +-- <item> -> <podcast:alternateEnclosure> -> <podcast:source> +CREATE TABLE item_enclosure_source ( + id SERIAL PRIMARY KEY, + item_enclosure_id INTEGER NOT NULL REFERENCES item_enclosure(id) ON DELETE CASCADE, + uri varchar_uri NOT NULL, + content_type varchar_short +); + +CREATE INDEX idx_item_enclosure_source_item_id ON item_enclosure_source(item_enclosure_id); + +-- <item> -> <podcast:alternateEnclosure> -> <podcast:integrity> +CREATE TABLE item_enclosure_integrity ( + id SERIAL PRIMARY KEY, + item_enclosure_id INTEGER NOT NULL UNIQUE REFERENCES item_enclosure_source(id) ON DELETE CASCADE, + type TEXT NOT NULL CHECK (type IN ('sri', 'pgp-signature')), + value varchar_long NOT NULL +); + +CREATE INDEX idx_item_enclosure_integrity_item_enclosure_id ON item_enclosure_integrity(item_enclosure_id); + +--** ITEM > FUNDING + +-- <item> -> <podcast:funding> +CREATE TABLE item_funding ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + url varchar_url NOT NULL, + title varchar_normal +); + +CREATE INDEX idx_item_funding_item_id ON item_funding(item_id); + +--** ITEM > IMAGE + +-- <item> -> <podcast:image> AND all other image tags in the rss feed +CREATE TABLE item_image ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + url varchar_url NOT NULL, + image_width_size INTEGER, -- <podcast:image> must have a width specified, but older image tags will not, so allow null. + + -- If true, then the image is hosted by us in a service like S3. + -- When is_resized images are deleted, the corresponding image in S3 + -- should also be deleted. + is_resized BOOLEAN DEFAULT FALSE +); + +CREATE INDEX idx_item_image_item_id ON item_image(item_id); + +--** ITEM > LICENSE + +-- <item> -> <podcast:license> +CREATE TABLE item_license ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL UNIQUE REFERENCES item(id) ON DELETE CASCADE, + identifier varchar_normal NOT NULL, + url varchar_url +); + +CREATE INDEX idx_item_license_item_id ON item_license(item_id); + +--** ITEM > LOCATION + +-- <item> -> <podcast:location> +CREATE TABLE item_location ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL UNIQUE REFERENCES item(id) ON DELETE CASCADE, + geo varchar_normal, + osm varchar_normal, + CHECK (geo IS NOT NULL OR osm IS NOT NULL), + name varchar_normal +); + +CREATE INDEX idx_item_location_item_id ON item_location(item_id); + +--** ITEM > PERSON + +-- <item> -> <podcast:person> +CREATE TABLE item_person ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + name varchar_normal NOT NULL, + role varchar_normal, + person_group varchar_normal DEFAULT 'cast', -- group is a reserved keyword in sql + img varchar_url, + href varchar_url +); + +CREATE INDEX idx_item_person_item_id ON item_person(item_id); + +--** ITEM > SEASON + +-- <item> -> <podcast:season> +CREATE TABLE item_season ( + id SERIAL PRIMARY KEY, + channel_season_id INTEGER NOT NULL REFERENCES channel_season(id) ON DELETE CASCADE, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + title varchar_normal +); + +CREATE INDEX idx_item_season_channel_season_id ON item_season(channel_season_id); +CREATE INDEX idx_item_season_item_id ON item_season(item_id); + +--** ITEM > SEASON > EPISODE + +-- <item> -> <podcast:season> -> <podcast:episode> +CREATE TABLE item_season_episode ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL UNIQUE REFERENCES item(id) ON DELETE CASCADE, + display varchar_short, + number FLOAT NOT NULL +); + +CREATE INDEX idx_item_season_episode_item_id ON item_season_episode(item_id); + +--** ITEM > SOCIAL INTERACT + +-- <item> -> <podcast:socialInteract> +CREATE TABLE item_social_interact ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + protocol varchar_short NOT NULL, + uri varchar_uri NOT NULL, + account_id varchar_normal, + account_url varchar_url, + priority INTEGER +); + +CREATE INDEX idx_item_social_interact_item_id ON item_social_interact(item_id); + +--** ITEM > SOUNDBITE + +-- <item> -> <podcast:soundbite> +CREATE TABLE item_soundbite ( + id SERIAL PRIMARY KEY, + id_text short_id_v2 UNIQUE NOT NULL, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + start_time media_player_time NOT NULL, + duration media_player_time NOT NULL, + title varchar_normal +); + +CREATE INDEX idx_item_soundbite_item_id ON item_soundbite(item_id); + +--** ITEM > TRANSCRIPT + +-- <item> -> <podcast:transcript> +CREATE TABLE item_transcript ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + url varchar_url NOT NULL, + type varchar_short NOT NULL, + language varchar_short, + rel VARCHAR(50) CHECK (rel IS NULL OR rel = 'captions') +); + +CREATE INDEX idx_item_transcript_item_id ON item_transcript(item_id); + +--** ITEM > TXT + +-- <item> -> <podcast:txt> +CREATE TABLE item_txt ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + purpose varchar_normal, + value varchar_long NOT NULL +); + +CREATE INDEX idx_item_txt_item_id ON item_txt(item_id); + +--** ITEM > VALUE + +-- <item> -> <podcast:value> +CREATE TABLE item_value ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + type varchar_short NOT NULL, + method varchar_short NOT NULL, + suggested FLOAT +); + +CREATE INDEX idx_item_value_item_id ON item_value(item_id); + +--** ITEM > VALUE > RECEIPIENT + +-- <item> -> <podcast:value> -> <podcast:valueRecipient> +CREATE TABLE item_value_recipient ( + id SERIAL PRIMARY KEY, + item_value_id INTEGER NOT NULL REFERENCES item_value(id) ON DELETE CASCADE, + type varchar_short NOT NULL, + address varchar_long NOT NULL, + split FLOAT NOT NULL, + name varchar_normal, + custom_key varchar_long, + custom_value varchar_long, + fee BOOLEAN DEFAULT FALSE +); + +CREATE INDEX idx_item_value_recipient_item_value_id ON item_value_recipient(item_value_id); + +--** ITEM > VALUE > TIME SPLIT + +-- <item> -> <podcast:value> -> <podcast:valueTimeSplit> +CREATE TABLE item_value_time_split ( + id SERIAL PRIMARY KEY, + item_value_id INTEGER NOT NULL REFERENCES item_value(id) ON DELETE CASCADE, + start_time media_player_time NOT NULL, + duration media_player_time NOT NULL, + remote_start_time media_player_time DEFAULT 0, + remote_percentage media_player_time DEFAULT 100 +); + +CREATE INDEX idx_item_value_time_split_item_value_id ON item_value_time_split(item_value_id); + +--** ITEM > VALUE > TIME SPLIT > REMOTE ITEM + +-- <item> -> <podcast:value> -> <podcast:valueTimeSplit> -> <podcast:remoteItem> +CREATE TABLE item_value_time_split_remote_item ( + id SERIAL PRIMARY KEY, + item_value_time_split_id INTEGER NOT NULL UNIQUE REFERENCES item_value_time_split(id) ON DELETE CASCADE, + feed_guid UUID NOT NULL, + feed_url varchar_url, + item_guid varchar_uri, + title varchar_normal +); + +CREATE INDEX idx_item_value_time_split_remote_item_item_value_time_split_id ON item_value_time_split_remote_item(item_value_time_split_id); +CREATE INDEX idx_item_value_time_split_remote_item_feed_guid ON item_value_time_split_remote_item(feed_guid); +CREATE INDEX idx_item_value_time_split_remote_item_feed_url ON item_value_time_split_remote_item(feed_url); +CREATE INDEX idx_item_value_time_split_remote_item_item_guid ON item_value_time_split_remote_item(item_guid); + +--** ITEM > VALUE > TIME SPLIT > VALUE RECIPEINT + +-- <item> -> <podcast:value> -> <podcast:valueTimeSplit> -> <podcast:valueRecipient> +CREATE TABLE item_value_time_split_recipient ( + id SERIAL PRIMARY KEY, + item_value_time_split_id INTEGER NOT NULL REFERENCES item_value_time_split(id) ON DELETE CASCADE, + type varchar_short NOT NULL, + address varchar_long NOT NULL, + split FLOAT NOT NULL, + name varchar_normal, + custom_key varchar_long, + custom_value varchar_long, + fee BOOLEAN DEFAULT FALSE +); + +CREATE INDEX idx_item_value_time_split_recipient_item_value_time_split_id ON item_value_time_split_recipient(item_value_time_split_id); + +--** LIVE ITEM > STATUS + +CREATE TABLE live_item_status ( + id SERIAL PRIMARY KEY, + status TEXT UNIQUE CHECK (status IN ('pending', 'live', 'ended')) +); + +INSERT INTO live_item_status (status) VALUES ('pending'), ('live'), ('ended'); + +--** LIVE ITEM + +-- Technically the live_item table could be named channel_live_item, +-- but for consistency with the item table, it is called live_item. + +-- <channel> -> <podcast:liveItem> +CREATE TABLE live_item ( + id SERIAL PRIMARY KEY, + item_id INTEGER NOT NULL UNIQUE REFERENCES item(id) ON DELETE CASCADE, + live_item_status_id INTEGER NOT NULL REFERENCES live_item_status(id), + start_time TIMESTAMPTZ NOT NULL, + end_time TIMESTAMPTZ, + chat_web_url varchar_url +); + +CREATE INDEX idx_live_item_item_id ON live_item(item_id); +CREATE INDEX idx_live_item_live_item_status_id ON live_item(live_item_status_id); diff --git a/database/migrations/0002_account.sql b/database/migrations/0002_account.sql new file mode 100644 index 0000000..e479c75 --- /dev/null +++ b/database/migrations/0002_account.sql @@ -0,0 +1,79 @@ +-- 0002 migration + +CREATE TABLE sharable_status ( + id SERIAL PRIMARY KEY, + status TEXT UNIQUE CHECK (status IN ('public', 'unlisted', 'private')) +); + +INSERT INTO sharable_status (status) VALUES ('public'), ('unlisted'), ('private'); + +CREATE TABLE account ( + id SERIAL PRIMARY KEY, + id_text short_id_v2 UNIQUE NOT NULL, + verified BOOLEAN DEFAULT FALSE, + sharable_status_id INTEGER NOT NULL REFERENCES sharable_status(id) +); + +CREATE INDEX idx_account_sharable_status_id ON account(sharable_status_id); + +CREATE TABLE account_credentials ( + id SERIAL PRIMARY KEY, + account_id integer REFERENCES account(id) ON DELETE CASCADE, + email varchar_email UNIQUE NOT NULL, + password varchar_password NOT NULL +); + +CREATE INDEX idx_account_credentials_account_id ON account_credentials(account_id); + +CREATE TABLE account_profile ( + id SERIAL PRIMARY KEY, + account_id integer REFERENCES account(id) ON DELETE CASCADE, + display_name varchar_normal, + bio varchar_long +); + +CREATE INDEX idx_account_profile_account_id ON account_profile(account_id); + +CREATE TABLE account_reset_password ( + id SERIAL PRIMARY KEY, + account_id integer REFERENCES account(id) ON DELETE CASCADE, + reset_token varchar_guid, + reset_token_expires_at TIMESTAMP +); + +CREATE INDEX idx_account_reset_password_account_id ON account_reset_password(account_id); + +CREATE TABLE account_verification ( + id SERIAL PRIMARY KEY, + account_id integer REFERENCES account(id) ON DELETE CASCADE, + verification_token varchar_guid, + verification_token_expires_at TIMESTAMP +); + +CREATE INDEX idx_account_verification_account_id ON account_verification(account_id); + +CREATE TABLE account_membership ( + id SERIAL PRIMARY KEY, + tier TEXT UNIQUE CHECK (tier IN ('trial', 'basic')) +); + +INSERT INTO account_membership (tier) VALUES ('trial'), ('basic'); + +CREATE TABLE account_membership_status ( + id SERIAL PRIMARY KEY, + account_id integer REFERENCES account(id) ON DELETE CASCADE, + account_membership_id INTEGER NOT NULL REFERENCES account_membership(id), + membership_expires_at TIMESTAMP +); + +CREATE INDEX idx_account_membership_status_account_id ON account_membership_status(account_id); +CREATE INDEX idx_account_membership_status_account_membership_id ON account_membership_status(account_membership_id); + +CREATE TABLE account_admin_roles ( + id SERIAL PRIMARY KEY, + account_id integer REFERENCES account(id) ON DELETE CASCADE, + dev_admin BOOLEAN DEFAULT FALSE, + podping_admin BOOLEAN DEFAULT FALSE +); + +CREATE INDEX idx_account_admin_roles_account_id ON account_admin_roles(account_id); diff --git a/database/migrations/0003_clip.sql b/database/migrations/0003_clip.sql new file mode 100644 index 0000000..028001c --- /dev/null +++ b/database/migrations/0003_clip.sql @@ -0,0 +1,17 @@ +-- 0003 migration + +CREATE TABLE clip ( + id SERIAL PRIMARY KEY, + id_text short_id_v2 UNIQUE NOT NULL, + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + start_time media_player_time NOT NULL, + end_time media_player_time, + title varchar_normal, + description varchar_long, + sharable_status_id INTEGER NOT NULL REFERENCES sharable_status(id) +); + +CREATE INDEX idx_clip_account_id ON clip(account_id); +CREATE INDEX idx_clip_item_id ON clip(item_id); +CREATE INDEX idx_clip_sharable_status_id ON clip(sharable_status_id); diff --git a/database/migrations/0004_playlist.sql b/database/migrations/0004_playlist.sql new file mode 100644 index 0000000..8b9b4d0 --- /dev/null +++ b/database/migrations/0004_playlist.sql @@ -0,0 +1,90 @@ +-- 0004 migration + +CREATE TABLE playlist ( + id SERIAL PRIMARY KEY, + id_text short_id_v2 UNIQUE NOT NULL, + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + sharable_status_id INTEGER NOT NULL REFERENCES sharable_status(id), + title varchar_normal, + description varchar_long, + is_default_favorites BOOLEAN DEFAULT FALSE, + is_public BOOLEAN DEFAULT FALSE, + item_count INTEGER DEFAULT 0, + medium_id INTEGER NOT NULL REFERENCES medium(id) +); + +CREATE INDEX idx_playlist_account_id ON playlist(account_id); +CREATE INDEX idx_playlist_sharable_status_id ON playlist(sharable_status_id); +CREATE INDEX idx_playlist_medium_id ON playlist(medium_id); + +CREATE TABLE playlist_resource_base ( + id SERIAL PRIMARY KEY, + playlist_id INTEGER NOT NULL REFERENCES playlist(id) ON DELETE CASCADE, + list_position list_position NOT NULL CHECK (list_position != 0 OR list_position = 0::numeric), + UNIQUE (playlist_id, list_position) +); + +CREATE INDEX idx_playlist_resource_base_playlist_id ON playlist_resource_base(playlist_id); + +CREATE TABLE playlist_resource_item ( + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE +) INHERITS (playlist_resource_base); + +CREATE INDEX idx_playlist_resource_item_item_id ON playlist_resource_item(item_id); + +CREATE TABLE playlist_resource_item_add_by_rss ( + resource_data jsonb NOT NULL +) INHERITS (playlist_resource_base); + +CREATE INDEX idx_playlist_resource_item_add_by_rss_resource_data ON playlist_resource_item_add_by_rss USING gin (resource_data); + +CREATE TABLE playlist_resource_item_chapter ( + item_chapter_id INTEGER NOT NULL REFERENCES item_chapter(id) ON DELETE CASCADE +) INHERITS (playlist_resource_base); + +CREATE INDEX idx_playlist_resource_item_chapter_item_chapter_id ON playlist_resource_item_chapter(item_chapter_id); + +CREATE TABLE playlist_resource_clip ( + clip_id INTEGER NOT NULL REFERENCES clip(id) ON DELETE CASCADE +) INHERITS (playlist_resource_base); + +CREATE INDEX idx_playlist_resource_clip_clip_id ON playlist_resource_clip(clip_id); + +CREATE TABLE playlist_resource_item_soundbite ( + soundbite_id INTEGER NOT NULL REFERENCES item_soundbite(id) ON DELETE CASCADE +) INHERITS (playlist_resource_base); + +CREATE INDEX idx_playlist_resource_item_soundbite_soundbite_id ON playlist_resource_item_soundbite(soundbite_id); + +CREATE OR REPLACE FUNCTION delete_playlist_resource_base() +RETURNS TRIGGER AS $$ +BEGIN + DELETE FROM playlist_resource_base WHERE id = OLD.id; + RETURN OLD; +END; +$$ LANGUAGE plpgsql; + +CREATE TRIGGER delete_playlist_resource_base_trigger_item +BEFORE DELETE ON playlist_resource_item +FOR EACH ROW +EXECUTE FUNCTION delete_playlist_resource_base(); + +CREATE TRIGGER delete_playlist_resource_base_trigger_item_add_by_rss +BEFORE DELETE ON playlist_resource_item_add_by_rss +FOR EACH ROW +EXECUTE FUNCTION delete_playlist_resource_base(); + +CREATE TRIGGER delete_playlist_resource_base_trigger_item_chapter +BEFORE DELETE ON playlist_resource_item_chapter +FOR EACH ROW +EXECUTE FUNCTION delete_playlist_resource_base(); + +CREATE TRIGGER delete_playlist_resource_base_trigger_clip +BEFORE DELETE ON playlist_resource_clip +FOR EACH ROW +EXECUTE FUNCTION delete_playlist_resource_base(); + +CREATE TRIGGER delete_playlist_resource_base_trigger_item_soundbite +BEFORE DELETE ON playlist_resource_item_soundbite +FOR EACH ROW +EXECUTE FUNCTION delete_playlist_resource_base(); diff --git a/database/migrations/0005_queue.sql b/database/migrations/0005_queue.sql new file mode 100644 index 0000000..61a817b --- /dev/null +++ b/database/migrations/0005_queue.sql @@ -0,0 +1,91 @@ +-- 0005 migration + +CREATE TABLE queue ( + id SERIAL PRIMARY KEY, + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + medium_id INTEGER NOT NULL REFERENCES medium(id), + UNIQUE (account_id, medium_id) +); + +CREATE INDEX idx_queue_account_id ON queue(account_id); +CREATE INDEX idx_queue_medium_id ON queue(medium_id); + +CREATE TABLE queue_resource_base ( + id SERIAL PRIMARY KEY, + queue_id INTEGER NOT NULL REFERENCES queue(id) ON DELETE CASCADE, + UNIQUE (queue_id, list_position), + list_position list_position NOT NULL CHECK (list_position != 0 OR list_position = 0::numeric), + playback_position media_player_time NOT NULL DEFAULT 0, + media_file_duration media_player_time NOT NULL DEFAULT 0, + completed BOOLEAN NOT NULL DEFAULT FALSE +); + +CREATE INDEX idx_queue_resource_base_queue_id ON queue_resource_base(queue_id); + +CREATE TABLE queue_resource_item ( + item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, + UNIQUE (queue_id) +) INHERITS (queue_resource_base); + +CREATE INDEX idx_queue_resource_item_item_id ON queue_resource_item(item_id); + +CREATE TABLE queue_resource_item_add_by_rss ( + resource_data jsonb NOT NULL, + UNIQUE (queue_id) +) INHERITS (queue_resource_base); + +CREATE INDEX idx_queue_resource_item_add_by_rss_resource_data ON queue_resource_item_add_by_rss USING gin (resource_data); + +CREATE TABLE queue_resource_item_chapter ( + item_chapter_id INTEGER NOT NULL REFERENCES item_chapter(id) ON DELETE CASCADE, + UNIQUE (queue_id) +) INHERITS (queue_resource_base); + +CREATE INDEX idx_queue_resource_item_chapter_item_chapter_id ON queue_resource_item_chapter(item_chapter_id); + +CREATE TABLE queue_resource_clip ( + clip_id INTEGER NOT NULL REFERENCES clip(id) ON DELETE CASCADE, + UNIQUE (queue_id) +) INHERITS (queue_resource_base); + +CREATE INDEX idx_queue_resource_clip_clip_id ON queue_resource_clip(clip_id); + +CREATE TABLE queue_resource_item_soundbite ( + soundbite_id INTEGER NOT NULL REFERENCES item_soundbite(id) ON DELETE CASCADE, + UNIQUE (queue_id) +) INHERITS (queue_resource_base); + +CREATE INDEX idx_queue_resource_item_soundbite_soundbite_id ON queue_resource_item_soundbite(soundbite_id); + +CREATE OR REPLACE FUNCTION delete_queue_resource_base() +RETURNS TRIGGER AS $$ +BEGIN + DELETE FROM queue_resource_base WHERE id = OLD.id; + RETURN OLD; +END; +$$ LANGUAGE plpgsql; + +CREATE TRIGGER delete_queue_resource_base_trigger_item +BEFORE DELETE ON queue_resource_item +FOR EACH ROW +EXECUTE FUNCTION delete_queue_resource_base(); + +CREATE TRIGGER delete_queue_resource_base_trigger_item_add_by_rss +BEFORE DELETE ON queue_resource_item_add_by_rss +FOR EACH ROW +EXECUTE FUNCTION delete_queue_resource_base(); + +CREATE TRIGGER delete_queue_resource_base_trigger_item_chapter +BEFORE DELETE ON queue_resource_item_chapter +FOR EACH ROW +EXECUTE FUNCTION delete_queue_resource_base(); + +CREATE TRIGGER delete_queue_resource_base_trigger_clip +BEFORE DELETE ON queue_resource_clip +FOR EACH ROW +EXECUTE FUNCTION delete_queue_resource_base(); + +CREATE TRIGGER delete_queue_resource_base_trigger_item_soundbite +BEFORE DELETE ON queue_resource_item_soundbite +FOR EACH ROW +EXECUTE FUNCTION delete_queue_resource_base(); diff --git a/database/migrations/0006_account_following_tables.sql b/database/migrations/0006_account_following_tables.sql new file mode 100644 index 0000000..208418a --- /dev/null +++ b/database/migrations/0006_account_following_tables.sql @@ -0,0 +1,38 @@ +-- 0006 migration + +CREATE TABLE account_following_account ( + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + following_account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + PRIMARY KEY (account_id, following_account_id) +); + +CREATE INDEX idx_account_following_account_account_id ON account_following_account(account_id); +CREATE INDEX idx_account_following_account_following_account_id ON account_following_account(following_account_id); + +CREATE TABLE account_following_channel ( + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + PRIMARY KEY (account_id, channel_id) +); + +CREATE INDEX idx_account_following_channel_account_id ON account_following_channel(account_id); +CREATE INDEX idx_account_following_channel_channel_id ON account_following_channel(channel_id); + +CREATE TABLE account_following_playlist ( + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + playlist_id INTEGER NOT NULL REFERENCES playlist(id) ON DELETE CASCADE, + PRIMARY KEY (account_id, playlist_id) +); + +CREATE INDEX idx_account_following_playlist_account_id ON account_following_playlist(account_id); +CREATE INDEX idx_account_following_playlist_playlist_id ON account_following_playlist(playlist_id); + +CREATE TABLE account_following_add_by_rss_channel ( + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + feed_url varchar_url NOT NULL, + PRIMARY KEY (account_id, feed_url), + title varchar_normal, + image_url varchar_url +); + +CREATE INDEX idx_account_following_add_by_rss_channel_account_id ON account_following_add_by_rss_channel(account_id); diff --git a/database/migrations/0007_notifications.sql b/database/migrations/0007_notifications.sql new file mode 100644 index 0000000..aa2f482 --- /dev/null +++ b/database/migrations/0007_notifications.sql @@ -0,0 +1,26 @@ +-- 0007 + +CREATE TABLE account_notification ( + channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + PRIMARY KEY (channel_id, account_id) +); + +CREATE INDEX idx_account_notification_channel_id ON account_notification(channel_id); +CREATE INDEX idx_account_notification_account_id ON account_notification(account_id); + +CREATE TABLE account_up_device ( + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + up_endpoint varchar_url PRIMARY KEY, + up_public_key varchar_long NOT NULL, + up_auth_key varchar_long NOT NULL +); + +CREATE INDEX idx_account_up_device_account_id ON account_up_device(account_id); + +CREATE TABLE account_fcm_device ( + fcm_token varchar_fcm_token PRIMARY KEY, + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE +); + +CREATE INDEX idx_account_fcm_device_account_id ON account_fcm_device(account_id); diff --git a/database/migrations/0008_purchases_paypal_apple_google.sql b/database/migrations/0008_purchases_paypal_apple_google.sql new file mode 100644 index 0000000..5dd43b5 --- /dev/null +++ b/database/migrations/0008_purchases_paypal_apple_google.sql @@ -0,0 +1,51 @@ +-- 0008 + +CREATE TABLE account_paypal_order ( + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + payment_id VARCHAR PRIMARY KEY, + state VARCHAR +); + +CREATE INDEX idx_account_paypal_order_account_id ON account_paypal_order(account_id); + +CREATE TABLE account_app_store_purchase ( + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + transaction_id VARCHAR PRIMARY KEY, + cancellation_date VARCHAR, + cancellation_date_ms VARCHAR, + cancellation_date_pst VARCHAR, + cancellation_reason VARCHAR, + expires_date VARCHAR, + expires_date_ms VARCHAR, + expires_date_pst VARCHAR, + is_in_intro_offer_period BOOLEAN, + is_trial_period BOOLEAN, + original_purchase_date VARCHAR, + original_purchase_date_ms VARCHAR, + original_purchase_date_pst VARCHAR, + original_transaction_id VARCHAR, + product_id VARCHAR, + promotional_offer_id VARCHAR, + purchase_date VARCHAR, + purchase_date_ms VARCHAR, + purchase_date_pst VARCHAR, + quantity INT, + web_order_line_item_id VARCHAR +); + +CREATE INDEX idx_account_app_store_purchase_account_id ON account_app_store_purchase(account_id); + +CREATE TABLE account_google_play_purchase ( + account_id INTEGER NOT NULL REFERENCES account(id) ON DELETE CASCADE, + transaction_id VARCHAR PRIMARY KEY, + acknowledgement_state INT NULL, + consumption_state INT NULL, + developer_payload VARCHAR NULL, + kind VARCHAR NULL, + product_id VARCHAR NOT NULL, + purchase_time_millis VARCHAR NULL, + purchase_state INT NULL, + purchase_token VARCHAR UNIQUE NOT NULL +); + +CREATE INDEX idx_account_google_play_purchase_account_id ON account_google_play_purchase(account_id); diff --git a/database/migrations/0009_membership_claim_token.sql b/database/migrations/0009_membership_claim_token.sql new file mode 100644 index 0000000..3686e08 --- /dev/null +++ b/database/migrations/0009_membership_claim_token.sql @@ -0,0 +1,10 @@ +-- 0009 + +CREATE TABLE membership_claim_token ( + id UUID PRIMARY KEY DEFAULT gen_random_uuid(), + claimed BOOLEAN DEFAULT FALSE, + years_to_add INT DEFAULT 1, + account_membership_id INT REFERENCES account_membership(id) ON DELETE CASCADE +); + +CREATE INDEX idx_membership_claim_token_account_membership_id ON membership_claim_token(account_membership_id); diff --git a/database/scripts/combine_all_migrations.sh b/database/scripts/combine_all_migrations.sh new file mode 100755 index 0000000..d53732a --- /dev/null +++ b/database/scripts/combine_all_migrations.sh @@ -0,0 +1,26 @@ +#!/bin/bash + +# Get the directory of the script +SCRIPT_DIR="$(cd "$(dirname "${BASH_SOURCE[0]}")" && pwd)" + +# Define the source and destination directories based on the script's location +SOURCE_DIR="$SCRIPT_DIR/../migrations" +DEST_DIR="$SCRIPT_DIR/../combined" +DEST_FILE="$DEST_DIR/init_database.sql" + +# Create the destination directory if it does not exist +mkdir -p "$DEST_DIR" + +# Create or clear the destination file +> "$DEST_FILE" + +# Iterate over all .sql files in the source directory +for file in "$SOURCE_DIR"/*.sql; +do + # Append the contents of each .sql file to the destination file + cat "$file" >> "$DEST_FILE" + # Add a newline for separation + echo "" >> "$DEST_FILE" +done + +echo "All .sql files have been combined into $DEST_FILE" diff --git a/dev/deploying.md b/dev/deploying.md new file mode 100644 index 0000000..08b6c47 --- /dev/null +++ b/dev/deploying.md @@ -0,0 +1,4 @@ +# Deploying + +TODO: + diff --git a/dev/local-dev-setup.md b/dev/local-dev-setup.md new file mode 100644 index 0000000..8f2680a --- /dev/null +++ b/dev/local-dev-setup.md @@ -0,0 +1,53 @@ +# Local Dev Setup + +Podverse uses many modules that are maintained in separate repos. This guide is intended to help you use shortcuts for an easier development workflow. + +## Summary + +- Setup environment variables for Docker services and local apps. +- Run the required Docker services. +- Initialize the database schema. +- Install and link all NPM dependencies. +- Run (build + hot reload) all Podverse modules in separate terminals. + +## Environment Variables + +Before running a Podverse Docker service, you will need to create an enviroment variable file for it within the `podverse-ops/config` directory. + +Duplicate each of the `.env.example` files found within `podverse-ops/config` and add the corresponding values. + +The Podverse repos that run locally (the ones that don't simply need to build, but need to run) will need their own `.env` file within their project directory for local development purposes. For example, for local dev, you will need a corresponding `podverse-api/.env` file, and a `podverse-workers/.env` file. + +## Required Docker services + +The Podverse infrastructure requires 2 Docker services: +- `podverse_db` - a Postgres database +- `podverse_amqp` - a RabbitMQ instance (AMQP queue service) + +You will need Docker installed locally. To start these containers in the background, from the root of `podverse-ops`, run the following command (using either `docker-compose` or `docker compose`): + +``` +docker-compose -f ./docker/docker-compose.yml up -d +``` + +## Initialize Database Schema + +When you start a clean instance of `podverse_db`, you will need to initialize the database schema. + +To initialize the database, run the SQL found in the `podverse-ops/database/init_database.sql` file. Execute the following command from the root of the `podverse-ops` repo: + +``` +docker exec -i podverse_db psql -U user -d postgres -f /opt/database/combined/init_database.sql +``` + +Note: the `user` and `postgres` value may need to change depending on your environment variables. + +## Install and link all dependencies + +For a convenient local dev workflow, you can clone all of the Podverse repos on your machine within the same directory, and then run the `podverse-ops/dev/npm-link-modules.sh` script from the root of the `podverse-ops` directory. This will handle 1) installing all the `node_modules` for those repos, and 2) `npm link`-ing the required podverse dependencies for each individual module. + +## Open and run all repos in separate terminals + +If you would like to use one command to run all of the Podverse modules in separate terminals, you can use the VS Code extension Terminals Manager. + +To make it work, duplicate the `podverse-ops/.vscode/terminals.json.example` file, rename it to `terminals.json`, and update the paths in the file to point to where you have the repos cloned locally. Then, with the `terminals.json` file open in VS Code, open the Command Palette, and select `Terminals: Run`. This will open a terminal in each of the (actively developed) Podverse modules, with the `npm run dev:watch` command running. diff --git a/dev/npm-link-modules.sh b/dev/npm-link-modules.sh new file mode 100755 index 0000000..4e0a425 --- /dev/null +++ b/dev/npm-link-modules.sh @@ -0,0 +1,99 @@ +#!/bin/bash + +# Delete and reinstall all node_modules + +echo "Clearing npm cache..." +npm cache clean --force + +echo "Installing podverse-api dependencies..." +cd ../podverse-api +rm -rf node_modules +npm install + +echo "Installing podverse-external-services dependencies..." +cd ../podverse-external-services +rm -rf node_modules +npm install + +echo "Installing podverse-helpers dependencies..." +cd ../podverse-helpers +rm -rf node_modules +npm install + +echo "Installing podverse-orm dependencies..." +cd ../podverse-orm +rm -rf node_modules +npm install + +echo "Installing podverse-parser dependencies..." +cd ../podverse-parser +rm -rf node_modules +npm install + +echo "Installing podverse-queue dependencies..." +cd ../podverse-queue +rm -rf node_modules +npm install + +echo "Installing podverse-workers dependencies..." +cd ../podverse-workers +rm -rf node_modules +npm install + +# Link dependencies to npm + +echo "Linking podverse-external-services dependency..." +cd ../podverse-external-services +npm link + +echo "Linking podverse-helpers dependency..." +cd ../podverse-helpers +npm link + +echo "Linking podverse-orm dependency..." +cd ../podverse-orm +npm link + +echo "Linking podverse-parser dependency..." +cd ../podverse-parser +npm link + +echo "Linking podverse-queue dependency..." +cd ../podverse-queue +npm link + +# Link dependencies to conuming projects + +echo "Linking podverse-api dependencies..." +cd ../podverse-api +npm link podverse-helpers +npm link podverse-orm +npm link podverse-parser + +echo "Linking podverse-external-services dependencies..." +cd ../podverse-external-services +npm link podverse-helpers + +echo "Linking podverse-orm dependencies..." +cd ../podverse-orm +npm link podverse-helpers + +echo "Linking podverse-parser dependencies..." +cd ../podverse-parser +npm link podverse-external-services +npm link podverse-helpers +npm link podverse-orm + +echo "Linking podverse-queue dependencies..." +cd ../podverse-queue +npm link podverse-external-services +npm link podverse-helpers +npm link podverse-orm +npm link podverse-parser + +echo "Linking podverse-workers dependencies..." +cd ../podverse-workers +npm link podverse-helpers +npm link podverse-orm +npm link podverse-parser +npm link podverse-queue diff --git a/docker-compose/docker-compose.yml b/docker-compose/docker-compose.yml new file mode 100644 index 0000000..f4c54da --- /dev/null +++ b/docker-compose/docker-compose.yml @@ -0,0 +1,101 @@ +version: "3.9" + +volumes: + vhost: + rabbitmq_data: + +networks: + podverse_network: + +services: + podverse_db: + image: postgres:16.3 + container_name: podverse_db + env_file: + - ../config/podverse-db.env + ports: + - '5432:5432' + networks: + - podverse_network + volumes: + - ../database/combined/init_database.sql:/opt/database/combined/init_database.sql + command: > + postgres -c max_connections=200 + -c superuser_reserved_connections=20 + -c shared_buffers=2GB + -c effective_cache_size=6GB + -c maintenance_work_mem=512MB + -c checkpoint_completion_target=0.7 + -c wal_buffers=16MB + -c default_statistics_target=100 + -c random_page_cost=1.1 + -c effective_io_concurrency=200 + -c work_mem=5242kB + -c min_wal_size=1GB + -c max_wal_size=2GB + -c max_worker_processes=4 + -c max_parallel_workers_per_gather=2 + -c max_parallel_workers=4 + restart: always + shm_size: 1gb + logging: + driver: 'json-file' + options: + max-file: '1' + max-size: '50m' + + podverse_amqp: + image: rabbitmq:3-management + container_name: podverse_amqp + env_file: + - ../config/podverse-amqp.env + ports: + - '5672:5672' + - '15672:15672' + networks: + - podverse_network + restart: always + shm_size: 1gb + logging: + driver: 'json-file' + options: + max-file: '1' + max-size: '50m' + volumes: + - rabbitmq_data:/var/lib/rabbitmq + + podverse_workers: + image: podverse-workers:latest + container_name: podverse_workers + env_file: + - ../config/podverse-workers.env + networks: + - podverse_network + depends_on: + - podverse_db + - podverse_amqp + shm_size: 1gb + logging: + driver: 'json-file' + options: + max-file: '1' + max-size: '50m' + + podverse_workers_debug: + image: podverse-workers:latest + container_name: podverse_workers_debug + env_file: + - ../config/podverse-workers.env + networks: + - podverse_network + depends_on: + - podverse_db + - podverse_amqp + volumes: + - /home/mitch/logs/podverse-workers:/var/logs/pv-workers + shm_size: 1gb + logging: + driver: 'json-file' + options: + max-file: '1' + max-size: '50m' diff --git a/docker-compose/local/docker-compose.yml b/docker-compose/local/docker-compose.yml deleted file mode 100644 index c4ba2b9..0000000 --- a/docker-compose/local/docker-compose.yml +++ /dev/null @@ -1,37 +0,0 @@ -version: "3.9" - -volumes: - vhost: - -services: - podverse_db: - image: postgres:16.3 - container_name: podverse_db_local - env_file: - - ../../config/podverse-db-local.env - ports: - - '5432:5432' - command: > - postgres -c max_connections=200 - -c superuser_reserved_connections=20 - -c shared_buffers=2GB - -c effective_cache_size=6GB - -c maintenance_work_mem=512MB - -c checkpoint_completion_target=0.7 - -c wal_buffers=16MB - -c default_statistics_target=100 - -c random_page_cost=1.1 - -c effective_io_concurrency=200 - -c work_mem=5242kB - -c min_wal_size=1GB - -c max_wal_size=2GB - -c max_worker_processes=4 - -c max_parallel_workers_per_gather=2 - -c max_parallel_workers=4 - restart: always - shm_size: 1gb - logging: - driver: 'json-file' - options: - max-file: '1' - max-size: '50m' diff --git a/docs/database/0001_init_database.sql b/docs/database/0001_init_database.sql deleted file mode 100644 index 6311b1d..0000000 --- a/docs/database/0001_init_database.sql +++ /dev/null @@ -1,302 +0,0 @@ -/* -NOTES: - -- The `id` column is a SERIAL column that is used as the primary key for every table. - -- The `id_text` column is only intended for tables where the data is available as urls. - For example, https://podverse.fm/podcast/abc123def456, the `id_text` column would be `abc123def456`. - -- The `slug` column is not required, but functions as an alternative for `id_text`. - For example, https://podverse.fm/podcast/podcasting-20 would have a `slug` column with the value `podcasting-20`. - -- The `podcast_index_id` ensures that our database only contains feed data that is available in the Podcast Index API. - -- The columns that are within top-level tables, like channel, are intended to be the most essential information, - and information that is useful for identifying what the channel corresponds with if you are viewing the database - in a tool like pgAdmin. Example: title makes it easy to see which id corresponds with a podcast you are looking for, - and description and author can help identify different podcasts with the same title. - -*/ - --- TODO: many TEXT columns should be changed to VARCHAR(255) or similar to prevent abuse. - --- Helpers - -CREATE DOMAIN medium_type AS TEXT CHECK (VALUE IN ( - 'podcast', 'music', 'video', 'film', 'audiobook', 'newsletter', 'blog', 'publisher', 'course', - 'podcastL', 'musicL', 'videoL', 'filmL', 'audiobookL', 'newsletterL', 'blogL', 'publisherL', 'courseL', 'mixed' -)); - -CREATE DOMAIN short_id AS VARCHAR(14); -CREATE DOMAIN varchar_short AS VARCHAR(50); -CREATE DOMAIN varchar_medium AS VARCHAR(255); -CREATE DOMAIN varchar_long AS VARCHAR(5000); -CREATE DOMAIN varchar_fqdn AS VARCHAR(253); -CREATE DOMAIN varchar_uri AS VARCHAR(2083); -CREATE DOMAIN varchar_url AS VARCHAR(2083) CHECK (VALUE ~ '^https?://|^http?://'); - -CREATE DOMAIN numeric_20_11 AS NUMERIC(20, 11); - --- Init tables - --- TODO: should every table have a created_at and updated_at column? --- or only some tables? or none? - -CREATE TABLE channel ( - id SERIAL PRIMARY KEY, - id_text short_id UNIQUE NOT NULL, - podcast_index_id INTEGER UNIQUE NOT NULL, - feed_url varchar_url UNIQUE NOT NULL, - podcast_guid UUID UNIQUE, -- As defined by the Podcast Index spec. - title varchar_medium, - sortable_title varchar_short, -- all lowercase, ignores articles at beginning of title - description varchar_long, - medium medium_type, - - -- channels with seasons need to be rendered in client apps differently. - -- you can only determine if a channel is in a "season" format is by finding - -- the <itunes:season> tag in an item in that channel. - has_season BOOLEAN DEFAULT FALSE, - - -- TODO: should we hash the last parsed feed, so we can compare it to the hash of - -- a feed before completely parsing it, to check if it has changed before continuing? - - -- TODO: categories, how to best handle to account for sub-categories? - - -- channels that have a PI value tag require special handling to request value_tag data - -- from the Podcast Index API. - has_podcast_index_value_tags BOOLEAN DEFAULT FALSE, - - -- Used to prevent another thread from parsing the same feed. - -- Set to current time at beginning of parsing, and NULL at end of parsing. - -- This is to prevent multiple threads from parsing the same feed. - -- If is_parsing is over X minutes old, assume last parsing failed and proceed to parse. - is_parsing TIMESTAMP -); - -CREATE UNIQUE INDEX channel_podcast_guid_unique ON channel(podcast_guid) WHERE podcast_guid IS NOT NULL; - -CREATE TABLE item ( - id SERIAL PRIMARY KEY, - id_text short_id UNIQUE NOT NULL, - channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, - guid varchar_uri -- Deprecated. The older RSS guid style, which is less reliable. - -- TODO: add item columns -); - -CREATE TABLE live_item ( - id SERIAL PRIMARY KEY, - channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, - item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, - status TEXT NOT NULL CHECK (status IN ('pending', 'live', 'ended')), - start_time TIMESTAMP NOT NULL, - end_time TIMESTAMP, - chat_web_url varchar_url -); - -CREATE TABLE channel_about ( - id SERIAL PRIMARY KEY, - channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, - author varchar_medium, - episode_count INTEGER, - explicit BOOLEAN, - itunes_type TEXT CHECK (itunes_type IN ('episodic', 'serial')), - language varchar_short NOT NULL, - website_link_url varchar_url -); - -CREATE TABLE channel_funding ( - id SERIAL PRIMARY KEY, - channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, - url varchar_url NOT NULL, - title varchar_medium -); - -CREATE TABLE channel_internal_settings ( - id SERIAL PRIMARY KEY, - channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, - embed_approved_media_url_paths TEXT, - flag_status TEXT CHECK (flag_status IN ('none', 'spam', 'takedown', 'other', 'always-allow')) -); - -CREATE TABLE channel_podroll ( - id SERIAL PRIMARY KEY, - channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE -); - -CREATE TABLE channel_trailer ( - id SERIAL PRIMARY KEY, - channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, - title varchar_medium, - url varchar_url NOT NULL, - pub_date TIMESTAMP NOT NULL, -- TODO: does this need timezone handling? - length INTEGER, - type varchar_short, - season INTEGER -); - -CREATE TABLE chat ( - id SERIAL PRIMARY KEY, - channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, - item_id INTEGER REFERENCES item(id) ON DELETE CASCADE, - live_item_id INTEGER REFERENCES live_item(id) ON DELETE CASCADE, - server varchar_fqdn NOT NULL, - protocol varchar_short, - account_id varchar_medium, - space varchar_medium -); - -CREATE TABLE feed ( - id SERIAL PRIMARY KEY, - channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, - publisher_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, - CHECK ( - (channel_id IS NOT NULL AND publisher_id IS NULL) OR - (channel_id IS NULL AND publisher_id IS NOT NULL) - ), - content_type varchar_short, - -- 0 to 5, 0 will only be parsed when PI API reports an update, - -- higher parsing_priority will be parsed more frequently on a schedule. - parsing_priority INTEGER DEFAULT 0, - last_http_status INTEGER, - last_crawl_time TIMESTAMP, - last_good_http_status_time TIMESTAMP, - last_parse_time TIMESTAMP, - last_update_time TIMESTAMP, - crawl_errors INTEGER DEFAULT 0, - parse_errors INTEGER DEFAULT 0, - locked BOOLEAN DEFAULT FALSE -); - -CREATE TABLE image ( - id SERIAL PRIMARY KEY, - channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, - item_id INTEGER REFERENCES item(id) ON DELETE CASCADE, - url varchar_url NOT NULL, - image_width_size INTEGER, -- <podcast:image> must have a width specified, but older image tags will not, so allow null. - -- If true, then the image is hosted by us in a service like S3. - -- When is_resized images are deleted, the corresponding image in S3 - -- should also be deleted. - is_resized BOOLEAN DEFAULT FALSE -); - -CREATE TABLE item_chapters ( - id SERIAL PRIMARY KEY, - item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, - url varchar_url NOT NULL, - type varchar_short NOT NULL, - version varchar_short NOT NULL -); - -CREATE TABLE item_chapter ( - id SERIAL PRIMARY KEY, - item_chapters_file_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, - start_time numeric_20_11 NOT NULL, - title varchar_medium -); - -CREATE TABLE item_soundbite ( - id SERIAL PRIMARY KEY, - item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, - url varchar_url NOT NULL, - start_time INTEGER NOT NULL, - duration INTEGER NOT NULL, - title varchar_medium -); - -CREATE TABLE item_transcript ( - id SERIAL PRIMARY KEY, - item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, - url varchar_url NOT NULL, - type varchar_short NOT NULL, - language varchar_short, - rel VARCHAR(50) CHECK (rel IS NULL OR rel = 'captions') -); - -CREATE TABLE location ( - id SERIAL PRIMARY KEY, - channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, - item_id INTEGER REFERENCES item(id) ON DELETE CASCADE, - geo varchar_medium, - osm varchar_medium, - CHECK ( - (geo IS NOT NULL AND osm IS NULL) OR - (geo IS NULL AND osm IS NOT NULL) - ) -); - --- TODO: write notifications table - -CREATE TABLE person ( - id SERIAL PRIMARY KEY, - channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, - item_id INTEGER REFERENCES item(id) ON DELETE CASCADE, - name varchar_medium, - role varchar_medium, - person_group TEXT DEFAULT 'cast', -- group is a reserved keyword in sql - img varchar_url, - href varchar_url -); - --- TODO: write the publisher table schema --- see https://github.com/Podcastindex-org/podcast-namespace/blob/ccfb191c98762ba31f98620bd1ba30c1822f6fbd/publishers/publishers.md -CREATE TABLE publisher ( - id SERIAL PRIMARY KEY, - channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE -); - -CREATE TABLE remote_item ( - id SERIAL PRIMARY KEY, - channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, - podroll_id INTEGER REFERENCES channel_podroll(id), - publisher_id INTEGER REFERENCES publisher(id), - item_id INTEGER NOT NULL REFERENCES item(id) ON DELETE CASCADE, - feed_guid UUID NOT NULL, - feed_url varchar_url, - item_guid varchar_uri, - medium medium_type, - title varchar_medium -); - -CREATE TABLE social_interact ( - id SERIAL PRIMARY KEY, - channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, - item_id INTEGER REFERENCES item(id) ON DELETE CASCADE, - protocol varchar_short NOT NULL, - uri varchar_uri NOT NULL, - account_id varchar_medium, - account_url varchar_url, - priority INTEGER -); - --- TODO: write stats solution (further down the road) - -CREATE TABLE value_tag ( - id SERIAL PRIMARY KEY, - channel_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, - item_id INTEGER REFERENCES item(id) ON DELETE CASCADE, - type varchar_short NOT NULL, - method varchar_short NOT NULL, - suggested numeric_20_11 -); - -CREATE TABLE value_tag_receipient ( - id SERIAL PRIMARY KEY, - value_tag_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, - type varchar_short NOT NULL, - address varchar_long NOT NULL, - split numeric_20_11 NOT NULL, - name varchar_medium, - custom_key varchar_long, - custom_value varchar_long, - fee BOOLEAN DEFAULT FALSE -); - -CREATE TABLE value_tag_time_split ( - id SERIAL PRIMARY KEY, - value_tag_id INTEGER NOT NULL REFERENCES channel(id) ON DELETE CASCADE, - start_time INTEGER NOT NULL, - duration INTEGER NOT NULL, - remote_start_time INTEGER DEFAULT 0, - remote_percentage INTEGER DEFAULT 100 -); diff --git a/yarn.lock b/yarn.lock new file mode 100644 index 0000000..fb57ccd --- /dev/null +++ b/yarn.lock @@ -0,0 +1,4 @@ +# THIS IS AN AUTOGENERATED FILE. DO NOT EDIT THIS FILE DIRECTLY. +# yarn lockfile v1 + +