-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Initial commit, implemented initial MTGJSON import
- Loading branch information
0 parents
commit e89a7fc
Showing
4 changed files
with
260 additions
and
0 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,4 @@ | ||
.DS_Store | ||
|
||
/ormos-data.sql | ||
/mtgjson |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,30 @@ | ||
# Ormos | ||
|
||
**Ormos** is a web app for keeping inventory of [*Magic: the Gathering*](https://magic.wizards.com) cards. | ||
It is an open-source, self-hosted alternative to existing services such as [Deckbox](https://deckbox.org) | ||
and [TappedOut.net](https://tappedout.net). It also provides an interactive database of all *Magic* | ||
cards ever printed, similar to the official [Gatherer](https://gatherer.wizards.com/) database and | ||
others such as [Scryfall](https://scryfall.com/). Ormos is named after the *Magic* card | ||
[Ormos, Archive Keeper](https://scryfall.com/card/jmp/13/ormos-archive-keeper). | ||
|
||
## Dependencies | ||
|
||
This project uses [MariaDB](https://mariadb.org) 10.6 (LTS). | ||
|
||
You will need [Bash](https://www.gnu.org/software/bash/) and [jq](https://stedolan.github.io/jq/) in | ||
order to generate the initial database import. | ||
|
||
## Setup | ||
|
||
This project uses [MTGJSON](https://mtgjson.com/) v5.2 to obtain the base card data. To generate the | ||
database import, create a folder `mtgjson`, [download](https://mtgjson.com/downloads/all-files/) the | ||
MTGJSON files `AtomicCards.json`, `AllPrintings.json`, and `SetList.json`, saving them in that folder, | ||
and then run `./generate-ormos-data.sh > ormos-data.sql`. You can then create the database schema and | ||
import the data by sourcing the files `ormos-schema.sql` and `ormos-data.sql` in MariaDB. (WARNING! | ||
Doing this will overwrite/delete any existing data in the database/schema named `ormos`, if you already | ||
have one. This includes your inventory data!) | ||
|
||
``` | ||
SOURCE ormos-schema.sql; | ||
SOURCE ormos-data.sql; | ||
``` |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,72 @@ | ||
#!/bin/bash -e | ||
|
||
cd ${BASH_SOURCE%/*}/mtgjson | ||
|
||
echo "INSERT INTO card_name (name) VALUES" | ||
cat AtomicCards.json \ | ||
| jq -r ' | ||
.data | ||
| keys[] | ||
| "( \(. | @sh) )," | ||
' \ | ||
| sed -E "s/\'\\\'\'/\\\'/g ; $ s/,$/;/" | ||
echo | ||
|
||
echo "INSERT INTO card_oracle (id, name, text) VALUES" | ||
cat AtomicCards.json \ | ||
| jq -r ' | ||
.data | ||
| to_entries | ||
| map(.value) | ||
| flatten[] | ||
| select( | ||
( .identifiers | has("scryfallOracleId") ) | ||
and ( | ||
(has("side") | not) | ||
or .side == "a" | ||
) | ||
) | ||
| "( UUID_TO_BIN(\(.identifiers.scryfallOracleId | @sh), TRUE), \(.name | @sh), \(if has("text") then .text else "" end | @sh) )," | ||
' \ | ||
| sed -E "s/\'\\\'\'/\\\'/g ; $ s/,$/;/" | ||
echo | ||
|
||
echo "INSERT INTO expansion_type (type) VALUES" | ||
cat SetList.json \ | ||
| jq -r ' | ||
.data | ||
| map(.type) | ||
| unique[] | ||
| @sh | ||
| "(\(.))," | ||
' \ | ||
| sed -E "s/\'\\\'\'/\\\'/g ; $ s/,$/;/" | ||
echo | ||
|
||
echo "INSERT INTO expansion (code, name, release_date, type) VALUES" | ||
cat SetList.json \ | ||
| jq -r ' | ||
.data[] | ||
| "( \(.code | @sh), \(.name | @sh), \(.releaseDate | @sh), \(.type | @sh) )," | ||
' \ | ||
| sed -E "s/\'\\\'\'/\\\'/g ; $ s/,$/;/" | ||
echo | ||
|
||
echo "INSERT INTO card_printing (id, oracle_id, expansion_code, collector_number) VALUES" | ||
cat AllPrintings.json \ | ||
| jq -r ' | ||
.data | ||
| to_entries | ||
| map(.value.cards) | ||
| flatten[] | ||
| select( | ||
( .identifiers | has("scryfallOracleId") ) | ||
and ( | ||
(has("side") | not) | ||
or .side == "a" | ||
) | ||
) | ||
| "( UUID_TO_BIN( \(.identifiers.scryfallId | @sh), TRUE ), UUID_TO_BIN( \(.identifiers.scryfallOracleId | @sh), TRUE ), \(.setCode | @sh), \(.number | @sh) )," | ||
' \ | ||
| sed -E "s/\'\\\'\'/\\\'/g ; $ s/,$/;/" | ||
echo |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,154 @@ | ||
DROP DATABASE IF EXISTS ormos; | ||
|
||
CREATE DATABASE ormos | ||
DEFAULT CHARACTER SET utf8mb4 | ||
COLLATE utf8mb4_unicode_ci | ||
; | ||
|
||
USE ormos; | ||
|
||
CREATE TABLE card_name ( | ||
name VARCHAR(255) NOT NULL PRIMARY KEY | ||
); | ||
|
||
CREATE TABLE card_oracle ( | ||
id /*UUID*/ BINARY(16) NOT NULL PRIMARY KEY, | ||
-- The `scryfallOracleId` from the *Card (Atomic)* object | ||
name VARCHAR(255) NOT NULL, | ||
text TEXT(1023) NOT NULL, | ||
|
||
FOREIGN KEY (name) REFERENCES card_name (name) | ||
ON DELETE RESTRICT | ||
ON UPDATE CASCADE | ||
); | ||
|
||
CREATE TABLE expansion_type ( | ||
type VARCHAR(31) NOT NULL PRIMARY KEY | ||
); | ||
|
||
CREATE TABLE expansion ( | ||
code VARCHAR(7) NOT NULL PRIMARY KEY, | ||
-- The short code (usually three capital letters) | ||
name VARCHAR(127) NOT NULL UNIQUE, | ||
release_date DATE NOT NULL, | ||
type VARCHAR(31) NOT NULL, | ||
|
||
FOREIGN KEY (type) REFERENCES expansion_type (type) | ||
ON DELETE RESTRICT | ||
ON UPDATE CASCADE, | ||
|
||
INDEX (release_date) | ||
); | ||
|
||
CREATE TABLE card_printing ( | ||
id /*UUID*/ BINARY(16) NOT NULL PRIMARY KEY, | ||
-- The `scryfallId` from the *Card (Set)* object | ||
oracle_id /*UUID*/ BINARY(16) NOT NULL, | ||
expansion_code VARCHAR(7) NOT NULL, | ||
collector_number VARCHAR(15) NOT NULL, | ||
|
||
FOREIGN KEY (oracle_id) REFERENCES card_oracle (id) | ||
ON DELETE RESTRICT | ||
ON UPDATE CASCADE, | ||
|
||
FOREIGN KEY (expansion_code) REFERENCES expansion (code) | ||
ON DELETE RESTRICT | ||
ON UPDATE CASCADE, | ||
|
||
UNIQUE (expansion_code, collector_number) | ||
); | ||
|
||
CREATE VIEW card_printing_full AS | ||
SELECT | ||
card_oracle.name, | ||
card_printing.expansion_code, | ||
card_printing.collector_number, | ||
card_printing.id, | ||
card_printing.oracle_id, | ||
card_oracle.text AS oracle_text | ||
FROM | ||
card_printing | ||
JOIN card_oracle ON | ||
card_oracle.id = card_printing.oracle_id | ||
JOIN expansion ON | ||
expansion.code = card_printing.expansion_code | ||
; | ||
|
||
CREATE TABLE card ( | ||
id INT UNSIGNED NOT NULL PRIMARY KEY AUTO_INCREMENT, | ||
printing_id /*UUID*/ BINARY(16) NOT NULL, | ||
|
||
FOREIGN KEY (printing_id) REFERENCES card_printing (id) | ||
ON DELETE RESTRICT | ||
ON UPDATE CASCADE | ||
); | ||
|
||
CREATE VIEW card_full AS | ||
SELECT | ||
card.id, | ||
card_oracle.name, | ||
card_printing.expansion_code, | ||
card_printing.collector_number, | ||
card.printing_id, | ||
card_printing.oracle_id, | ||
card_oracle.text AS oracle_text | ||
FROM | ||
card | ||
JOIN card_printing ON | ||
card_printing.id = card.printing_id | ||
JOIN card_oracle ON | ||
card_oracle.id = card_printing.oracle_id | ||
JOIN expansion ON | ||
expansion.code = card_printing.expansion_code | ||
; | ||
|
||
CREATE TABLE format ( | ||
id INT UNSIGNED NOT NULL PRIMARY KEY, | ||
name VARCHAR(63) NOT NULL UNIQUE | ||
); | ||
|
||
CREATE TABLE format_legality ( | ||
format_id INT UNSIGNED NOT NULL, | ||
card_name VARCHAR(255) NOT NULL, | ||
|
||
FOREIGN KEY (format_id) REFERENCES format (id) | ||
ON DELETE RESTRICT | ||
ON UPDATE CASCADE, | ||
|
||
FOREIGN KEY (card_name) REFERENCES card_name (name) | ||
ON DELETE RESTRICT | ||
ON UPDATE CASCADE | ||
); | ||
|
||
-- Polyfill from <https://stackoverflow.com/a/58015720> | ||
DELIMITER $$ | ||
|
||
CREATE FUNCTION BIN_TO_UUID(b BINARY(16), f BOOLEAN) | ||
RETURNS CHAR(36) | ||
DETERMINISTIC | ||
BEGIN | ||
DECLARE hexStr CHAR(32); | ||
SET hexStr = HEX(b); | ||
RETURN LOWER(CONCAT( | ||
IF(f,SUBSTR(hexStr, 9, 8),SUBSTR(hexStr, 1, 8)), '-', | ||
IF(f,SUBSTR(hexStr, 5, 4),SUBSTR(hexStr, 9, 4)), '-', | ||
IF(f,SUBSTR(hexStr, 1, 4),SUBSTR(hexStr, 13, 4)), '-', | ||
SUBSTR(hexStr, 17, 4), '-', | ||
SUBSTR(hexStr, 21) | ||
)); | ||
END$$ | ||
|
||
CREATE FUNCTION UUID_TO_BIN(uuid CHAR(36), f BOOLEAN) | ||
RETURNS BINARY(16) | ||
DETERMINISTIC | ||
BEGIN | ||
RETURN UNHEX(CONCAT( | ||
IF(f,SUBSTRING(uuid, 15, 4),SUBSTRING(uuid, 1, 8)), | ||
SUBSTRING(uuid, 10, 4), | ||
IF(f,SUBSTRING(uuid, 1, 8),SUBSTRING(uuid, 15, 4)), | ||
SUBSTRING(uuid, 20, 4), | ||
SUBSTRING(uuid, 25) | ||
)); | ||
END$$ | ||
|
||
DELIMITER ; |