diff --git a/postgres/000-schema.sql b/postgres/000-schema.sql index cf5d56b..68126e0 100644 --- a/postgres/000-schema.sql +++ b/postgres/000-schema.sql @@ -29,7 +29,22 @@ DO $$ BEGIN END IF; END $$; -CREATE TABLE IF NOT EXISTS "cards" ( +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, + "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, "name" TEXT NOT NULL, @@ -50,10 +65,10 @@ CREATE TABLE IF NOT EXISTS "cards" ( 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 INDEX IF NOT EXISTS "cards_name" ON "scryfall" ("name" COLLATE en_us_ci); +CREATE INDEX IF NOT EXISTS "cards_rarity" ON "scryfall" ("rarity"); +CREATE INDEX IF NOT EXISTS "cards_color_identity" ON "scryfall" ("color_identity"); +CREATE INDEX IF NOT EXISTS "cards_oracle_id" ON "scryfall" ("oracle_id"); CREATE TABLE IF NOT EXISTS "copies" ( "id" BIGSERIAL PRIMARY KEY, @@ -62,7 +77,7 @@ CREATE TABLE IF NOT EXISTS "copies" ( "isFoil" BOOLEAN NOT NULL DEFAULT FALSE, "language" TEXT, "condition" TEXT, - FOREIGN KEY ("scryfall_id") REFERENCES "cards" ("scryfall_id") ON DELETE CASCADE + FOREIGN KEY ("scryfall_id") REFERENCES "scryfall" ("scryfall_id") ON DELETE CASCADE ); CREATE TABLE IF NOT EXISTS "card_prices" ( @@ -74,7 +89,7 @@ CREATE TABLE IF NOT EXISTS "card_prices" ( "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 + FOREIGN KEY ("scryfall_id") REFERENCES "scryfall" ("scryfall_id") ON DELETE CASCADE ); CREATE TABLE IF NOT EXISTS "legalities" ( @@ -82,7 +97,7 @@ CREATE TABLE IF NOT EXISTS "legalities" ( "format" TEXT NOT NULL, "legality" TEXT NOT NULL, PRIMARY KEY ("scryfall_id", "format"), - FOREIGN KEY ("scryfall_id") REFERENCES "cards" ("scryfall_id") + FOREIGN KEY ("scryfall_id") REFERENCES "scryfall" ("scryfall_id") ); DO $$ BEGIN @@ -99,7 +114,7 @@ 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") + FOREIGN KEY ("scryfall_id") REFERENCES "scryfall" ("scryfall_id") ); CREATE TABLE IF NOT EXISTS "decks" ( @@ -120,10 +135,26 @@ CREATE TABLE IF NOT EXISTS "deck_cards" ( "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") + FOREIGN KEY ("scryfall_id") REFERENCES "scryfall" ("scryfall_id") ); CREATE TABLE IF NOT EXISTS "vars" ( "key" TEXT PRIMARY KEY, "value" TEXT ); + +CREATE OR REPLACE VIEW "cards" AS +SELECT "oracle"."oracle_id" + , "oracle"."name" + , "oracle"."color_identity" + , "oracle"."cmc" + , "oracle"."type_line" + , "oracle"."edhrec_rank" + , "oracle"."oracle_text" + , "scryfall"."scryfall_id" + , "scryfall"."set_code" + , "scryfall"."collector_number" + , "scryfall"."rarity" + , "scryfall"."release_date" +FROM "oracle" +JOIN "scryfall" USING ("oracle_id"); diff --git a/tutor/cli.py b/tutor/cli.py index c978c52..40c915f 100644 --- a/tutor/cli.py +++ b/tutor/cli.py @@ -252,7 +252,28 @@ def update_scryfall(ctx, filename): print("Updating card data & indexes") await cursor.execute( """ - INSERT INTO "cards" SELECT * FROM "tmp_cards" + INSERT INTO "oracle" + SELECT DISTINCT "oracle_id" + , "name" + , "color_identity" + , "cmc" + , "type_line" + , "edhrec_rank" + , "oracle_text" + FROM "tmp_cards" + ON CONFLICT (oracle_id) DO UPDATE + SET "oracle_id" = "excluded"."oracle_id" + , "name" = "excluded"."name" + , "color_identity" = "excluded"."color_identity" + , "cmc" = "excluded"."cmc" + , "type_line" = "excluded"."type_line" + , "edhrec_rank" = "excluded"."edhrec_rank" + , "oracle_text" = "excluded"."oracle_text" + """ + ) + await cursor.execute( + """ + INSERT INTO "scryfall" SELECT * FROM "tmp_cards" ON CONFLICT (scryfall_id) DO UPDATE SET "oracle_id" = "excluded"."oracle_id" , "name" = "excluded"."name"