Switch from SQLite to Postgres

This commit is contained in:
Correl Roush 2022-07-27 22:07:10 -04:00
parent 761194d2fa
commit 37f2d37213
8 changed files with 359 additions and 175 deletions

9
docker-compose.yml Normal file
View file

@ -0,0 +1,9 @@
services:
database:
image: postgres:14-alpine
ports:
- 5432:5432
environment:
POSTGRES_PASSWORD: tutor
volumes:
- ./postgres:/docker-entrypoint-initdb.d

31
poetry.lock generated
View file

@ -251,6 +251,25 @@ python-versions = ">=3.6"
dev = ["pre-commit", "tox"]
testing = ["pytest", "pytest-benchmark"]
[[package]]
name = "psycopg"
version = "3.0.15"
description = "PostgreSQL database adapter for Python"
category = "main"
optional = false
python-versions = ">=3.6"
[package.dependencies]
tzdata = {version = "*", markers = "sys_platform == \"win32\""}
[package.extras]
binary = ["psycopg-binary (==3.0.15)"]
c = ["psycopg-c (==3.0.15)"]
dev = ["black (>=22.3.0)", "dnspython (>=2.1)", "flake8 (>=4.0)", "mypy (>=0.920,!=0.930,!=0.931)", "types-setuptools (>=57.4)", "wheel (>=0.37)"]
docs = ["Sphinx (>=4.2)", "furo (==2021.11.23)", "sphinx-autobuild (>=2021.3.14)", "sphinx-autodoc-typehints (>=1.12)", "dnspython (>=2.1)", "shapely (>=1.7)"]
pool = ["psycopg-pool"]
test = ["mypy (>=0.920,!=0.930,!=0.931)", "pproxy (>=2.7)", "pytest (>=6.2.5)", "pytest-asyncio (>=0.16,<0.17)", "pytest-cov (>=3.0)", "pytest-randomly (>=3.10)"]
[[package]]
name = "py"
version = "1.11.0"
@ -354,10 +373,18 @@ category = "main"
optional = false
python-versions = ">=3.7"
[[package]]
name = "tzdata"
version = "2022.1"
description = "Provider of IANA time zone data"
category = "main"
optional = false
python-versions = ">=2"
[metadata]
lock-version = "1.1"
python-versions = "^3.9"
content-hash = "eaabfa09e09f0e120105edc8ccb499d2c9b14902bed765385356c58c8da29e84"
content-hash = "b9d44033776233d12ed64832238a897975a9f08cbd4df3ca445f1f7dac3003f8"
[metadata.files]
aiosqlite = [
@ -412,6 +439,7 @@ pluggy = [
{file = "pluggy-1.0.0-py2.py3-none-any.whl", hash = "sha256:74134bbf457f031a36d68416e1509f34bd5ccc019f0bcc952c7b909d06b37bd3"},
{file = "pluggy-1.0.0.tar.gz", hash = "sha256:4224373bacce55f955a878bf9cfa763c1e360858e330072059e10bad68531159"},
]
psycopg = []
py = [
{file = "py-1.11.0-py2.py3-none-any.whl", hash = "sha256:607c53218732647dff4acdfcd50cb62615cedf612e72d1724fb1a0cc6405b378"},
{file = "py-1.11.0.tar.gz", hash = "sha256:51c75c4126074b472f746a24399ad32f6053d1b34b68d2fa41e558e6f4a98719"},
@ -430,3 +458,4 @@ tomli = []
tornado = []
tqdm = []
typing-extensions = []
tzdata = []

121
postgres/000-schema.sql Normal file
View file

@ -0,0 +1,121 @@
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_cards" (
"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 "vars" (
"key" TEXT PRIMARY KEY,
"value" TEXT
);

View file

@ -14,6 +14,7 @@ httpx = "^0.18.2"
parsy = "^1.3.0"
jsonslicer = "^0.1.7"
tqdm = "^4.64.0"
psycopg = "^3.0"
[tool.poetry.dev-dependencies]
pytest = "*"

View file

@ -10,6 +10,7 @@ import click
import httpx
import humanize
import jsonslicer
import psycopg
import tornado.ioloop
import tornado.web
import tqdm
@ -216,18 +217,66 @@ def update_scryfall(ctx, filename):
async def import_cards():
today = datetime.date.today()
async with aiosqlite.connect(ctx.obj["database"]) as db:
with tqdm.tqdm(total=source.total, unit="b", unit_scale=True) as bar:
for card_json, read in source.cards():
card = tutor.scryfall.to_card(card_json)
await tutor.database.store_card(db, card)
await tutor.database.store_price(db, today, card)
await tutor.database.store_set(
db, card_json["set"].upper(), card_json["set_name"]
async with await psycopg.AsyncConnection.connect(
ctx.obj["database"], autocommit=False
) as conn:
async with conn.cursor() as cursor:
with tqdm.tqdm(total=source.total, unit="b", unit_scale=True) as bar:
await cursor.execute(
"""
CREATE TEMP TABLE "tmp_cards"
(LIKE "cards" INCLUDING DEFAULTS)
ON COMMIT DROP
"""
)
bar.update(read)
await tutor.database.store_var(db, "last_update", str(today))
await db.commit()
await cursor.execute(
"""
CREATE TEMP TABLE "tmp_prices"
(LIKE "card_prices" INCLUDING DEFAULTS)
ON COMMIT DROP
"""
)
for card_json, read in source.cards():
card = tutor.scryfall.to_card(card_json)
await tutor.database.store_set(
cursor, card_json["set"].upper(), card_json["set_name"]
)
await tutor.database.store_card(cursor, card)
await tutor.database.store_price(cursor, today, card)
bar.update(read)
print("Updating card data & indexes")
await cursor.execute(
"""
INSERT INTO "cards" SELECT * FROM "tmp_cards"
ON CONFLICT (scryfall_id) DO UPDATE
SET "oracle_id" = "excluded"."oracle_id"
, "name" = "excluded"."name"
, "set_code" = "excluded"."set_code"
, "collector_number" = "excluded"."collector_number"
, "rarity" = "excluded"."rarity"
, "color_identity" = "excluded"."color_identity"
, "cmc" = "excluded"."cmc"
, "type_line" = "excluded"."type_line"
, "release_date" = "excluded"."release_date"
, "edhrec_rank" = "excluded"."edhrec_rank"
, "oracle_text" = "excluded"."oracle_text"
"""
)
print("Updating card price data & indexes")
await cursor.execute(
"""
INSERT INTO "card_prices" SELECT * FROM "tmp_prices"
ON CONFLICT ("scryfall_id", "date") DO UPDATE
SET "usd" = "excluded"."usd"
, "usd_foil" = "excluded"."usd_foil"
, "eur" = "excluded"."eur"
, "eur_foil" = "excluded"."eur_foil"
, "tix" = "excluded"."tix"
"""
)
await tutor.database.store_var(cursor, "last_update", str(today))
await conn.commit()
tornado.ioloop.IOLoop.current().run_sync(import_cards)

View file

@ -3,7 +3,7 @@ import enum
import logging
import typing
import aiosqlite
import psycopg
import tutor.database
import tutor.models
@ -24,41 +24,43 @@ async def load(
- MTGStand (uses Scryfall ID)
"""
cards = []
async with aiosqlite.connect(settings["database"]) as db:
if mode == ImportMode.replace:
await tutor.database.clear_copies(db)
reader = csv.DictReader(stream)
for row in reader:
is_foil = "Foil" in row and row["Foil"].lower() == "foil"
quantity = int(row.get("Quantity", row.get("Count", 1)))
if "Scryfall ID" in row:
found = await tutor.database.search(
db, scryfall_id=row["Scryfall ID"]
)
else:
found = await tutor.database.search(
db,
name=row["Name"],
set_name=row["Edition"],
collector_number=row["Card Number"],
foil=is_foil or None,
)
if not found:
logging.warning("Could not find card for row %s", row)
continue
else:
if len(found) > 1:
logging.warning(
"Found %s possibilities for row %s", len(found), row
async with await psycopg.AsyncConnection.connect(
settings["database"], autocommit=False
) as conn:
async with conn.cursor() as cursor:
if mode == ImportMode.replace:
await tutor.database.clear_copies(cursor)
reader = csv.DictReader(stream)
for row in reader:
is_foil = "Foil" in row and row["Foil"].lower() == "foil"
quantity = int(row.get("Quantity", row.get("Count", 1)))
if "Scryfall ID" in row:
found = await tutor.database.search(
cursor, scryfall_id=row["Scryfall ID"]
)
card = tutor.models.CardCopy(
card=found[0],
foil=is_foil,
language=row["Language"] or "English",
)
logging.info((quantity, card))
for i in range(quantity):
await tutor.database.store_copy(db, card)
yield card, reader.line_num
await db.commit()
else:
found = await tutor.database.search(
cursor,
name=row["Name"],
set_name=row["Edition"],
collector_number=row["Card Number"],
foil=is_foil or None,
)
if not found:
logging.warning("Could not find card for row %s", row)
continue
else:
if len(found) > 1:
logging.warning(
"Found %s possibilities for row %s", len(found), row
)
card = tutor.models.CardCopy(
card=found[0],
foil=is_foil,
language=row["Language"] or "English",
)
logging.info((quantity, card))
for i in range(quantity):
await tutor.database.store_copy(cursor, card)
yield card, reader.line_num
await conn.commit()

View file

@ -4,7 +4,9 @@ import logging
import typing
import uuid
import aiosqlite
import psycopg
import psycopg.rows
import psycopg.sql as sql
import tutor.models
import tutor.search
@ -14,7 +16,7 @@ logger = logging.getLogger(__name__)
async def search(
db: aiosqlite.Connection,
db: psycopg.Cursor,
name: typing.Optional[str] = None,
collector_number: typing.Optional[str] = None,
set_code: typing.Optional[str] = None,
@ -26,30 +28,30 @@ async def search(
distinct: bool = True,
in_collection: typing.Optional[bool] = None,
) -> typing.List[tutor.models.Card]:
db.row_factory = aiosqlite.Row
db.row_factory = psycopg.rows.dict_row
joins = []
constraints = []
params = {}
if name is not None:
constraints.append("cards.name LIKE :name")
constraints.append("cards.name LIKE %(name)s")
params["name"] = name
if collector_number is not None:
constraints.append("cards.collector_number LIKE :number")
constraints.append("cards.collector_number LIKE %(number)s")
params["number"] = collector_number
if set_code is not None:
constraints.append("cards.set_code LIKE :set_code")
constraints.append("cards.set_code LIKE %(set_code)s")
params["set_code"] = set_code.upper()
if set_name is not None:
constraints.append("sets.name LIKE :set_name")
constraints.append("sets.name LIKE %(set_name)s")
params["set_name"] = set_name
if foil is not None:
constraints.append("cards.foil IS :foil")
constraints.append("cards.foil IS %(foil)s")
params["foil"] = foil
if alternate_art is not None:
constraints.append("cards.variation IS :alternative")
constraints.append("cards.variation IS %(alternative)s")
params["alternative"] = alternate_art
if scryfall_id is not None:
constraints.append("cards.scryfall_id LIKE :scryfall_id")
constraints.append("cards.scryfall_id = %(scryfall_id)s")
params["scryfall_id"] = scryfall_id
if in_collection is not None:
if in_collection:
@ -67,18 +69,18 @@ async def search(
f"LIMIT {limit}",
]
)
cursor = await db.execute(query, params)
rows = await cursor.fetchall()
await db.execute(query, params)
rows = await db.fetchall()
return [
tutor.models.Card(
scryfall_id=uuid.UUID(row["scryfall_id"]),
oracle_id=uuid.UUID(row["oracle_id"]),
scryfall_id=row["scryfall_id"],
oracle_id=row["oracle_id"],
name=row["name"],
set_code=row["set_code"],
collector_number=row["collector_number"],
rarity=tutor.models.Rarity.from_string(row["rarity"]),
color_identity=tutor.models.Color.from_string(row["color_identity"]),
cmc=decimal.Decimal(row["cmc"]),
cmc=row["cmc"],
type_line=row["type_line"],
release_date=datetime.date.fromisoformat(row["release_date"]),
games=set(),
@ -91,14 +93,14 @@ async def search(
async def advanced_search(
db: aiosqlite.Connection,
db: psycopg.Cursor,
search: tutor.search.Search,
limit: int = 10,
offset: int = 0,
sort_by: str = "rarity",
in_collection: typing.Optional[bool] = None,
) -> typing.List[tutor.models.Card]:
db.row_factory = aiosqlite.Row
db.row_factory = psycopg.rows.dict_row
joins = []
constraints = []
params = {}
@ -108,17 +110,17 @@ async def advanced_search(
for i, criterion in enumerate(search.criteria):
param = f"param_{i}"
if isinstance(criterion, tutor.search.Name):
constraints.append(f"cards.name LIKE :{param}")
constraints.append(f"cards.name ILIKE %({param})s")
params[param] = f"%{criterion.text}%"
if isinstance(criterion, tutor.search.Type):
constraints.append(f"cards.type_line LIKE :{param}")
constraints.append(f"cards.type_line ILIKE %({param})s")
params[param] = f"%{criterion.text}%"
if isinstance(criterion, tutor.search.Expansion):
constraints.append(f"cards.set_code LIKE :{param}")
constraints.append(f"cards.set_code ILIKE %({param})s")
params[param] = criterion.set_code
if isinstance(criterion, tutor.search.Color):
if criterion.operator == tutor.search.Operator.matches:
constraints.append(f"cards.color_identity LIKE :{param}")
constraints.append(f"cards.color_identity ILIKE %({param})s")
params[param] = tutor.models.Color.to_string(criterion.colors)
if criterion.operator == tutor.search.Operator.lte:
colors = list({str(color) for color in criterion.colors} | {""})
@ -126,7 +128,7 @@ async def advanced_search(
"({})".format(
" OR ".join(
[
f"cards.color_identity LIKE :{param}_{color}"
f"cards.color_identity ILIKE %({param}_{color})s"
for color in colors
]
)
@ -134,22 +136,22 @@ async def advanced_search(
)
params.update({f"{param}_{color}": color for color in colors})
if criterion.operator == tutor.search.Operator.gte:
constraints.append(f"cards.color_identity LIKE :{param}")
constraints.append(f"cards.color_identity ILIKE %({param})s")
params[param] = "%{}%".format(
"%".join(tutor.models.Color.to_string(criterion.colors))
)
if isinstance(criterion, tutor.search.Rarity):
if criterion.operator == tutor.search.Operator.matches:
constraints.append(f"cards.rarity LIKE :{param}")
constraints.append(f"cards.rarity = %({param})s::rarity")
params[param] = str(criterion.rarity)
if criterion.operator == tutor.search.Operator.lte:
constraints.append(f"rarities.rarity_ord <= :{param}")
constraints.append(f"cards.rarity <= %({param})s::rarity")
params[param] = criterion.rarity.value
if criterion.operator == tutor.search.Operator.gte:
constraints.append(f"rarities.rarity_ord >= :{param}")
constraints.append(f"cards.rarity >= %({param})s::rarity")
params[param] = criterion.rarity.value
if isinstance(criterion, tutor.search.Oracle):
constraints.append(f"cards.oracle_text LIKE :{param}")
constraints.append(f"cards.oracle_text ILIKE %({param})s")
params[param] = f"%{criterion.text}%"
if in_collection is not None:
@ -159,13 +161,12 @@ async def advanced_search(
joins.append("LEFT JOIN copies ON (cards.scryfall_id = copies.scryfall_id)")
constraints.append("copies.id IS NULL")
joins.append("JOIN sets ON (cards.set_code = sets.set_code)")
joins.append("JOIN rarities ON (cards.rarity = rarities.rarity)")
joins.append(
"JOIN card_prices ON (cards.scryfall_id = card_prices.scryfall_id "
"AND card_prices.date = (select value from vars where key = :last_update_key))"
"AND card_prices.date = (select value from vars where key = %(last_update_key)s))"
)
orderings = [
"rarities.rarity_ord DESC",
"cards.rarity DESC",
"length(cards.color_identity) DESC",
"CASE "
" WHEN length(cards.color_identity) > 0 THEN '0'"
@ -186,12 +187,12 @@ async def advanced_search(
" AND ".join(constraints),
"ORDER BY " if orderings else "",
", ".join(orderings),
f"LIMIT {offset},{limit}",
f"LIMIT {limit} OFFSET {offset}",
]
)
logger.debug("Query: %s", (query, params))
cursor = await db.execute(query, params)
rows = await cursor.fetchall()
logger.critical("Query: %s", (query, params))
await db.execute(query, params)
rows = await db.fetchall()
def convert_price(price: typing.Optional[str]) -> typing.Optional[decimal.Decimal]:
if price:
@ -201,14 +202,14 @@ async def advanced_search(
return [
tutor.models.Card(
scryfall_id=uuid.UUID(row["scryfall_id"]),
oracle_id=uuid.UUID(row["oracle_id"]),
scryfall_id=row["scryfall_id"],
oracle_id=row["oracle_id"],
name=row["name"],
set_code=row["set_code"],
collector_number=row["collector_number"],
rarity=tutor.models.Rarity.from_string(row["rarity"]),
color_identity=tutor.models.Color.from_string(row["color_identity"]),
cmc=decimal.Decimal(row["cmc"]),
cmc=row["cmc"],
type_line=row["type_line"],
release_date=datetime.date.fromisoformat(row["release_date"]),
games=set(),
@ -225,28 +226,16 @@ async def advanced_search(
]
async def store_card(db: aiosqlite.Connection, card: tutor.models.Card) -> None:
async def store_card(db: psycopg.Cursor, card: tutor.models.Card) -> None:
await db.execute(
"""
INSERT INTO cards
(`scryfall_id`, `oracle_id`, `name`, `set_code`, `collector_number`,
`rarity`, `color_identity`, `cmc`, `type_line`, `release_date`,
`edhrec_rank`, `oracle_text`)
VALUES (:scryfall_id, :oracle_id, :name, :set_code, :collector_number,
:rarity, :color_identity, :cmc, :type_line, :release_date, :edhrec_rank,
:oracle_text)
ON CONFLICT (scryfall_id) DO UPDATE
SET `oracle_id` = :oracle_id
, `name` = :name
, `set_code` = :set_code
, `collector_number` = :collector_number
, `rarity` = :rarity
, `color_identity` = :color_identity
, `cmc` = :cmc
, `type_line` = :type_line
, `release_date` = :release_date
, `edhrec_rank` = :edhrec_rank
, `oracle_text` = :oracle_text
INSERT INTO tmp_cards
("scryfall_id", "oracle_id", "name", "set_code", "collector_number",
"rarity", "color_identity", "cmc", "type_line", "release_date",
"edhrec_rank", "oracle_text")
VALUES (%(scryfall_id)s, %(oracle_id)s, %(name)s, %(set_code)s,
%(collector_number)s, %(rarity)s, %(color_identity)s, %(cmc)s,
%(type_line)s, %(release_date)s, %(edhrec_rank)s, %(oracle_text)s)
""",
{
"scryfall_id": str(card.scryfall_id),
@ -263,40 +252,17 @@ async def store_card(db: aiosqlite.Connection, card: tutor.models.Card) -> None:
"oracle_text": card.oracle_text,
},
)
await db.execute(
"DELETE FROM `games` WHERE `scryfall_id` = ?",
[str(card.scryfall_id)],
)
for game in card.games:
await db.execute(
"INSERT INTO `games` (`scryfall_id`, `game`) VALUES (?, ?)",
(str(card.scryfall_id), game.value),
)
await db.execute(
"DELETE FROM `legalities` WHERE `scryfall_id` = ?",
[str(card.scryfall_id)],
)
for game_format, legality in card.legalities.items():
await db.execute(
"INSERT INTO `legalities` (`scryfall_id`, `format`, `legality`) "
"VALUES (?, ?, ?)",
(str(card.scryfall_id), game_format, legality.value),
)
async def store_price(
db: aiosqlite.Connection, date: datetime.date, card: tutor.models.Card
db: psycopg.Cursor, date: datetime.date, card: tutor.models.Card
) -> None:
await db.execute(
"INSERT INTO `card_prices`"
" (`scryfall_id`, `date`, `usd`, `usd_foil`, `eur`, `eur_foil`, `tix`) "
"VALUES (:scryfall_id, :date, :usd, :usd_foil, :eur, :eur_foil, :tix) "
"ON CONFLICT (`scryfall_id`, `date`) DO UPDATE "
"SET `usd` = :usd"
" , `usd_foil` = :usd_foil"
" , `eur` = :eur"
" , `eur_foil` = :eur_foil"
" , `tix` = :tix",
"""
INSERT INTO "tmp_prices"
("scryfall_id", "date", "usd", "usd_foil", "eur", "eur_foil", "tix")
VALUES (%(scryfall_id)s, %(date)s, %(usd)s, %(usd_foil)s, %(eur)s, %(eur_foil)s, %(tix)s)
""",
{
"scryfall_id": card.scryfall_id,
"date": str(date),
@ -309,19 +275,23 @@ async def store_price(
)
async def store_set(db: aiosqlite.Connection, set_code: str, name: str) -> None:
async def store_set(db: psycopg.Cursor, set_code: str, name: str) -> None:
await db.execute(
"INSERT INTO `sets` (`set_code`, `name`) "
"VALUES (:set_code, :name) "
"ON CONFLICT (`set_code`) DO NOTHING",
"""
INSERT INTO "sets" ("set_code", "name")
VALUES (%(set_code)s, %(name)s)
ON CONFLICT ("set_code") DO NOTHING
""",
{"set_code": set_code, "name": name},
)
async def store_copy(db: aiosqlite.Connection, copy: tutor.models.CardCopy) -> None:
async def store_copy(db: psycopg.Cursor, copy: tutor.models.CardCopy) -> None:
await db.execute(
"INSERT INTO copies (scryfall_id, isFoil, condition)"
"VALUES (:scryfall_id, :foil, :condition)",
"""
INSERT INTO copies ("scryfall_id", "isFoil", "condition")
VALUES (%(scryfall_id)s, %(foil)s, %(condition)s)
""",
{
"scryfall_id": str(copy.card.scryfall_id),
"foil": copy.foil,
@ -330,38 +300,40 @@ async def store_copy(db: aiosqlite.Connection, copy: tutor.models.CardCopy) -> N
)
async def clear_copies(
db: aiosqlite.Connection, collection: typing.Optional[str] = None
):
async def clear_copies(db: psycopg.Cursor, collection: typing.Optional[str] = None):
if collection:
await db.execute("DELETE FROM copies WHERE collection = ?", collection)
await db.execute("DELETE FROM copies WHERE collection = %s", collection)
else:
await db.execute("DELETE FROM copies")
async def store_deck(db: aiosqlite.Connection, name: str) -> None:
async def store_deck(db: psycopg.Cursor, name: str) -> None:
cursor = await db.execute(
"INSERT INTO `decks` (`name`) VALUES (:name)",
'INSERT INTO "decks" ("name") VALUES (%(name)s)',
{"name": name},
)
return cursor.lastrowid
async def store_deck_card(
db: aiosqlite.Connection, deck_id: int, oracle_id: uuid.UUID, quantity: int = 1
db: psycopg.Cursor, deck_id: int, oracle_id: uuid.UUID, quantity: int = 1
) -> None:
await db.execute(
"INSERT INTO `deck_cards` (`deck_id`, `oracle_id`, `quantity`)"
"VALUES (:deck_id, :oracle_id, :quantity)",
"""
INSERT INTO "deck_cards" ("deck_id", "oracle_id", "quantity")
VALUES (%(deck_id)s, %(oracle_id)s, %(quantity)s)
""",
{"deck_id": deck_id, "oracle_id": str(oracle_id), "quantity": quantity},
)
async def store_var(db: aiosqlite.Connection, key: str, value: str) -> None:
async def store_var(db: psycopg.Cursor, key: str, value: str) -> None:
await db.execute(
"INSERT INTO `vars` (`key`, `value`)"
"VALUES (:key, :value)"
"ON CONFLICT (`key`) DO UPDATE "
"SET `value` = :value",
"""
INSERT INTO "vars" ("key", "value")
VALUES (%(key)s, %(value)s)
ON CONFLICT ("key") DO UPDATE
SET "value" = %(value)s
""",
{"key": key, "value": value},
)

View file

@ -3,7 +3,7 @@ import json
import typing
import urllib.parse
import aiosqlite
import psycopg
import tornado.web
import tutor.database
@ -56,23 +56,24 @@ class SearchHandler(tornado.web.RequestHandler):
)
async def get(self) -> None:
async with aiosqlite.connect(self.application.settings["database"]) as db:
query = self.get_argument("q", "")
in_collection = self.get_argument("in_collection", None)
page = max(1, int(self.get_argument("page", 1)))
limit = int(self.get_argument("limit", 10))
sort_by = self.get_argument("sort_by", "rarity")
search = tutor.search.search.parse(query)
cards = await tutor.database.advanced_search(
db,
search,
limit=limit + 1,
offset=limit * (page - 1),
sort_by=sort_by,
in_collection=in_collection in ("yes", "true")
if in_collection
else None,
)
async with await psycopg.AsyncConnection.connect(self.application.settings["database"]) as conn:
async with conn.cursor() as cursor:
query = self.get_argument("q", "")
in_collection = self.get_argument("in_collection", None)
page = max(1, int(self.get_argument("page", 1)))
limit = int(self.get_argument("limit", 10))
sort_by = self.get_argument("sort_by", "rarity")
search = tutor.search.search.parse(query)
cards = await tutor.database.advanced_search(
cursor,
search,
limit=limit + 1,
offset=limit * (page - 1),
sort_by=sort_by,
in_collection=in_collection in ("yes", "true")
if in_collection
else None,
)
has_more = cards and len(cards) > limit
self.set_header("Content-Type", "application/json")
self.set_header("Access-Control-Allow-Origin", "*")