Fix materialized views
Prices may not exist for some card versions, use a LEFT JOIN so cards don't get omitted.
This commit is contained in:
parent
4081634ad6
commit
8303394ced
1 changed files with 57 additions and 0 deletions
57
postgres/003-left-join-prices-in-materialized-views.sql
Normal file
57
postgres/003-left-join-prices-in-materialized-views.sql
Normal file
|
@ -0,0 +1,57 @@
|
|||
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")
|
||||
LEFT 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")
|
||||
LEFT 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");
|
Loading…
Reference in a new issue