129 lines
3.7 KiB
SQL
129 lines
3.7 KiB
SQL
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 "cards" (
|
|
"scryfall_id" UUID PRIMARY KEY,
|
|
"oracle_id" UUID,
|
|
"name" TEXT NOT NULL,
|
|
"set_code" TEXT,
|
|
"collector_number" TEXT,
|
|
"release_date" TEXT,
|
|
"rarity" rarity NOT NULL,
|
|
"color_identity" TEXT NOT NULL,
|
|
"cmc" DECIMAL(10, 2) NOT NULL,
|
|
"type_line" TEXT NOT NULL,
|
|
"foil" INTEGER NOT NULL DEFAULT 0,
|
|
"nonfoil" INTEGER NOT NULL DEFAULT 1,
|
|
"variation" INTEGER NOT NULL DEFAULT 0,
|
|
"edhrec_rank" INTEGER,
|
|
"oracle_text" TEXT,
|
|
"games" TEXT[] DEFAULT ARRAY[]::TEXT[],
|
|
"legalities" TEXT[] DEFAULT ARRAY[]::TEXT[],
|
|
FOREIGN KEY ("set_code") REFERENCES "sets" ("set_code")
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS "cards_name" ON "cards" ("name" COLLATE en_us_ci);
|
|
CREATE INDEX IF NOT EXISTS "cards_rarity" ON "cards" ("rarity");
|
|
CREATE INDEX IF NOT EXISTS "cards_color_identity" ON "cards" ("color_identity");
|
|
CREATE INDEX IF NOT EXISTS "cards_oracle_id" ON "cards" ("oracle_id");
|
|
|
|
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 "cards" ("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 "cards" ("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 "cards" ("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 "cards" ("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 "cards" ("scryfall_id")
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS "vars" (
|
|
"key" TEXT PRIMARY KEY,
|
|
"value" TEXT
|
|
);
|