From 6b74f2baad6b7e66eef0d8a87fa9db320bce91c4 Mon Sep 17 00:00:00 2001 From: Mark Cheese <35660089+omfgitsmark@users.noreply.github.com> Date: Sun, 18 Aug 2019 15:43:46 -0400 Subject: [PATCH] Foreign keys and datatype improvements (#24) --- mtgsqlive/json2sql.py | 137 +++++++++++++++++++++--------------------- 1 file changed, 69 insertions(+), 68 deletions(-) diff --git a/mtgsqlive/json2sql.py b/mtgsqlive/json2sql.py index 481ea1f..63bb3a5 100644 --- a/mtgsqlive/json2sql.py +++ b/mtgsqlive/json2sql.py @@ -84,7 +84,7 @@ def build_sql_schema(sql_connection: sqlite3.Connection) -> None: "baseSetSize INTEGER," "block TEXT," "boosterV3 TEXT," - "code TEXT," + "code TEXT UNIQUE NOT NULL," "codeV3 TEXT," "isFoilOnly INTEGER NOT NULL DEFAULT 0," # boolean "isForeignOnly INTEGER NOT NULL DEFAULT 0," # boolean @@ -104,61 +104,6 @@ def build_sql_schema(sql_connection: sqlite3.Connection) -> None: ")" ) - # Translations for set names - cursor.execute( - "CREATE TABLE `set_translations` (" - "id INTEGER PRIMARY KEY AUTOINCREMENT," - "language TEXT," - "setCode TEXT," - "translation TEXT" - ")" - ) - - # Build foreignData table - cursor.execute( - "CREATE TABLE `foreignData` (" - "id INTEGER PRIMARY KEY AUTOINCREMENT," - "flavorText TEXT," - "language TEXT," - "multiverseId INTEGER," - "name TEXT," - "text TEXT," - "type TEXT," - "uuid TEXT(36)" - ")" - ) - - # Build legalities table - cursor.execute( - "CREATE TABLE `legalities` (" - "id INTEGER PRIMARY KEY AUTOINCREMENT," - "format TEXT," - "status TEXT," - "uuid TEXT(36)" - ")" - ) - - # Build ruling table - cursor.execute( - "CREATE TABLE `rulings` (" - "id INTEGER PRIMARY KEY AUTOINCREMENT," - "date TEXT," - "text TEXT," - "uuid TEXT(36)" - ")" - ) - - # Build prices table - cursor.execute( - "CREATE TABLE `prices` (" - "id INTEGER PRIMARY KEY AUTOINCREMENT," - "date TEXT," - "price REAL," - "type TEXT," - "uuid TEXT(36)" - ")" - ) - # Build cards table cursor.execute( "CREATE TABLE `cards` (" @@ -169,7 +114,7 @@ def build_sql_schema(sql_connection: sqlite3.Connection) -> None: "colorIndicator TEXT," "colors TEXT," "convertedManaCost FLOAT," - "duelDeck TEXT," + "duelDeck TEXT(1)," "edhrecRank TEXT," "faceConvertedManaCost FLOAT," "flavorText TEXT," @@ -213,10 +158,10 @@ def build_sql_schema(sql_connection: sqlite3.Connection) -> None: "printings TEXT," "purchaseUrls TEXT," "rarity TEXT," - "scryfallId TEXT," - "scryfallIllustrationId TEXT," - "scryfallOracleId TEXT," - "setCode TEXT," + "scryfallId TEXT(36)," + "scryfallIllustrationId TEXT(36)," + "scryfallOracleId TEXT(36)," + "setCode TEXT REFERENCES sets(code) ON UPDATE CASCADE ON DELETE CASCADE," "side TEXT," "subtypes TEXT," "supertypes TEXT," @@ -226,10 +171,11 @@ def build_sql_schema(sql_connection: sqlite3.Connection) -> None: "toughness TEXT," "type TEXT," "types TEXT," - "uuid TEXT(36)," + "uuid TEXT(36) UNIQUE NOT NULL," "variations TEXT," "watermark TEXT" ")" + #"CREATE UNIQUE INDEX 'cards_uuid' ON cards(uuid);" ) # Build tokens table @@ -241,7 +187,7 @@ def build_sql_schema(sql_connection: sqlite3.Connection) -> None: "colorIdentity TEXT," "colorIndicator TEXT," "colors TEXT," - #"duelDeck TEXT," + "duelDeck TEXT(1)," "isOnlineOnly INTEGER NOT NULL DEFAULT 0," # boolean "layout TEXT," "loyalty TEXT," @@ -250,19 +196,74 @@ def build_sql_schema(sql_connection: sqlite3.Connection) -> None: "number TEXT," "power TEXT," "reverseRelated TEXT," - "scryfallId TEXT," - "scryfallIllustrationId TEXT," - "scryfallOracleId TEXT," - "setCode TEXT," + "scryfallId TEXT(36)," + "scryfallIllustrationId TEXT(36)," + "scryfallOracleId TEXT(36)," + "setCode TEXT REFERENCES sets(code) ON UPDATE CASCADE ON DELETE CASCADE," "side TEXT," "text TEXT," "toughness TEXT," "type TEXT," - "uuid TEXT(36)," + "uuid TEXT(36) UNIQUE," "watermark TEXT" ")" ) + # Translations for set names + cursor.execute( + "CREATE TABLE `set_translations` (" + "id INTEGER PRIMARY KEY AUTOINCREMENT," + "language TEXT," + "setCode TEXT REFERENCES sets(code) ON UPDATE CASCADE ON DELETE CASCADE," + "translation TEXT" + ")" + ) + + # Build foreignData table + cursor.execute( + "CREATE TABLE `foreignData` (" + "id INTEGER PRIMARY KEY AUTOINCREMENT," + "flavorText TEXT," + "language TEXT," + "multiverseId INTEGER," + "name TEXT," + "text TEXT," + "type TEXT," + "uuid TEXT(36) REFERENCES cards(uuid) ON UPDATE CASCADE ON DELETE CASCADE" + ")" + ) + + # Build legalities table + cursor.execute( + "CREATE TABLE `legalities` (" + "id INTEGER PRIMARY KEY AUTOINCREMENT," + "format TEXT," + "status TEXT," + "uuid TEXT(36) REFERENCES cards(uuid) ON UPDATE CASCADE ON DELETE CASCADE" + ")" + ) + + # Build ruling table + cursor.execute( + "CREATE TABLE `rulings` (" + "id INTEGER PRIMARY KEY AUTOINCREMENT," + "date TEXT," + "text TEXT," + "uuid TEXT(36) REFERENCES cards(uuid) ON UPDATE CASCADE ON DELETE CASCADE" + ")" + ) + + # Build prices table + cursor.execute( + "CREATE TABLE `prices` (" + "id INTEGER PRIMARY KEY AUTOINCREMENT," + "date TEXT," + "price REAL," + "type TEXT," + "uuid TEXT(36) REFERENCES cards(uuid) ON UPDATE CASCADE ON DELETE CASCADE" + ")" + ) + # Execute the commands sql_connection.commit()