CREATE COLLATION en_us_ci ( PROVIDER = icu, -- 'en-US@colStrength=secondary' for old ICU versions LOCALE = 'en-US-u-ks-level2', DETERMINISTIC = FALSE ); CREATE TABLE IF NOT EXISTS "sets" ( "set_code" TEXT PRIMARY KEY, "name" TEXT NOT NULL ); CREATE TABLE IF NOT EXISTS "rarities" ( "rarity" TEXT PRIMARY KEY, "rarity_ord" INTEGER NOT NULL ); DO $$ BEGIN IF NOT EXISTS (SELECT 1 FROM "pg_type" WHERE "typname" = 'rarity') THEN CREATE TYPE "rarity" AS ENUM ( 'n/a', 'common', 'uncommon', 'rare', 'special', 'mythic', 'bonus' ); END IF; END $$; CREATE TABLE IF NOT EXISTS "oracle" ( "oracle_id" UUID PRIMARY KEY, "name" TEXT NOT NULL, "color_identity" TEXT NOT NULL, "cmc" DECIMAL(10, 2) NOT NULL, "mana_cost" TEXT, "type_line" TEXT NOT NULL, "edhrec_rank" INTEGER, "oracle_text" TEXT, "games" TEXT[] DEFAULT ARRAY[]::TEXT[], "legalities" TEXT[] DEFAULT ARRAY[]::TEXT[] ); CREATE INDEX IF NOT EXISTS "oracle_name" ON "oracle" ("name" COLLATE en_us_ci); CREATE INDEX IF NOT EXISTS "oracle_color_identity" ON "oracle" ("color_identity"); CREATE TABLE IF NOT EXISTS "scryfall" ( "scryfall_id" UUID PRIMARY KEY, "oracle_id" UUID, "set_code" TEXT, "collector_number" TEXT, "release_date" TEXT, "rarity" rarity NOT NULL, "foil" INTEGER NOT NULL DEFAULT 0, "nonfoil" INTEGER NOT NULL DEFAULT 1, "variation" INTEGER NOT NULL DEFAULT 0, FOREIGN KEY ("oracle_id") REFERENCES "oracle" ("oracle_id"), FOREIGN KEY ("set_code") REFERENCES "sets" ("set_code") ); CREATE INDEX IF NOT EXISTS "scryfall_rarity" ON "scryfall" ("rarity"); CREATE TABLE IF NOT EXISTS "copies" ( "id" BIGSERIAL PRIMARY KEY, "collection" TEXT NOT NULL DEFAULT 'Default', "scryfall_id" UUID, "isFoil" BOOLEAN NOT NULL DEFAULT FALSE, "language" TEXT, "condition" TEXT, FOREIGN KEY ("scryfall_id") REFERENCES "scryfall" ("scryfall_id") ON DELETE CASCADE ); CREATE TABLE IF NOT EXISTS "card_prices" ( "scryfall_id" UUID, "date" TEXT, "usd" DECIMAL(10, 2), "usd_foil" DECIMAL(10, 2), "eur" DECIMAL(10, 2), "eur_foil" DECIMAL(10, 2), "tix" DECIMAL(10, 2), PRIMARY KEY ("scryfall_id", "date"), FOREIGN KEY ("scryfall_id") REFERENCES "scryfall" ("scryfall_id") ON DELETE CASCADE ); CREATE TABLE IF NOT EXISTS "legalities" ( "scryfall_id" UUID NOT NULL, "format" TEXT NOT NULL, "legality" TEXT NOT NULL, PRIMARY KEY ("scryfall_id", "format"), FOREIGN KEY ("scryfall_id") REFERENCES "scryfall" ("scryfall_id") ); DO $$ BEGIN IF NOT EXISTS (SELECT 1 FROM "pg_type" WHERE "typname" = 'game') THEN CREATE TYPE "game" AS ENUM ( 'paper', 'arena', 'mtgo' ); END IF; END $$; CREATE TABLE IF NOT EXISTS "games" ( "scryfall_id" UUID NOT NULL, "game" game NOT NULL, PRIMARY KEY ("scryfall_id", "game"), FOREIGN KEY ("scryfall_id") REFERENCES "scryfall" ("scryfall_id") ); CREATE TABLE IF NOT EXISTS "decks" ( "deck_id" BIGSERIAL PRIMARY KEY, "name" TEXT NOT NULL ); CREATE TABLE IF NOT EXISTS "deck_list" ( "deck_id" INTEGER NOT NULL, "oracle_id" UUID NOT NULL, "quantity" INTEGER NOT NULL DEFAULT 1, PRIMARY KEY ("deck_id", "oracle_id"), FOREIGN KEY ("deck_id") REFERENCES "decks" ("deck_id") ON DELETE CASCADE ); CREATE TABLE IF NOT EXISTS "deck_cards" ( "deck_id" INTEGER NOT NULL, "scryfall_id" UUID NOT NULL, PRIMARY KEY ("deck_id", "scryfall_id"), FOREIGN KEY ("deck_id") REFERENCES "decks" ("deck_id") ON DELETE CASCADE, FOREIGN KEY ("scryfall_id") REFERENCES "scryfall" ("scryfall_id") ); CREATE TABLE IF NOT EXISTS "vars" ( "key" TEXT PRIMARY KEY, "value" TEXT ); DROP MATERIALIZED VIEW IF EXISTS "cards"; CREATE MATERIALIZED VIEW "cards" AS SELECT "oracle"."oracle_id" , "oracle"."name" , "oracle"."color_identity" , "oracle"."cmc" , "oracle"."mana_cost" , "oracle"."type_line" , "oracle"."edhrec_rank" , "oracle"."oracle_text" , "scryfall"."scryfall_id" , "scryfall"."set_code" , "scryfall"."collector_number" , "scryfall"."release_date" , "scryfall"."rarity" , "sets"."name" AS "set_name" , "card_prices"."usd" AS "price_usd" , "card_prices"."usd_foil" AS "price_usd_foil" , "card_prices"."eur" AS "price_eur" , "card_prices"."eur_foil" AS "price_eur_foil" , "card_prices"."tix" AS "price_tix" FROM "oracle" JOIN "scryfall" USING ("oracle_id") JOIN "card_prices" ON ("scryfall"."scryfall_id" = "card_prices"."scryfall_id" AND "card_prices"."date" = (SELECT VALUE FROM "vars" WHERE "key" = 'last_update')) JOIN "sets" USING ("set_code"); DROP MATERIALIZED VIEW IF EXISTS "oracle_latest"; CREATE MATERIALIZED VIEW "oracle_latest" AS SELECT "oracle"."oracle_id" , "oracle"."name" , "oracle"."color_identity" , "oracle"."cmc" , "oracle"."mana_cost" , "oracle"."type_line" , "oracle"."edhrec_rank" , "oracle"."oracle_text" , "scryfall"."scryfall_id" , "scryfall"."set_code" , "scryfall"."collector_number" , "scryfall"."release_date" , "scryfall"."rarity" , "sets"."name" AS "set_name" , "card_prices"."usd" AS "price_usd" , "card_prices"."usd_foil" AS "price_usd_foil" , "card_prices"."eur" AS "price_eur" , "card_prices"."eur_foil" AS "price_eur_foil" , "card_prices"."tix" AS "price_tix" FROM "oracle" JOIN ( SELECT DISTINCT ON ("oracle_id") * FROM "scryfall" ORDER BY "oracle_id", "release_date" DESC ) "scryfall" USING ("oracle_id") JOIN "card_prices" ON ("scryfall"."scryfall_id" = "card_prices"."scryfall_id" AND "card_prices"."date" = (SELECT VALUE FROM "vars" WHERE "key" = 'last_update')) JOIN "sets" USING ("set_code");