Skip to content
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
8 changes: 8 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -42,3 +42,11 @@ This application is created using [Godot game engine](https://godotengine.org/)
* `Helpers` directory is for classes that are used for getting various data without creating a specific model or attaching to a Godot scene node;
* `Models` contains models classes to work with the game data and application settings;
* `Scenes` contains Godot engine scene files and scripts attached to root nodes of scenes with matching name.

## Creating a SQLite database from the game data

Run `create_crafting_db.py` to convert `crafting_data.json` into a SQLite database.

The script creates `crafting_data.db` by default and stores item information and all recipe details for offline use.

Use `query_crafting_db.py <item name>` to print a dependency tree for an item from the generated database.
108 changes: 108 additions & 0 deletions create_crafting_db.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,108 @@
import argparse
import json
import sqlite3
from pathlib import Path


def build_database(json_path: Path, db_path: Path) -> None:
data = json.loads(json_path.read_text())
conn = sqlite3.connect(db_path)
cur = conn.cursor()

cur.executescript(
"""
PRAGMA journal_mode = WAL;
PRAGMA synchronous = NORMAL;

CREATE TABLE IF NOT EXISTS items (
id INTEGER PRIMARY KEY,
Copy link

@fsobolev fsobolev Jun 27, 2025

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I'm not experienced in SQL, but as I understand INTEGER means Int32. It doesn't fit, items IDs in BitPlanner scripts are expected to be in range of UInt64 (BIGINT UNSIGNED), by using Int32 you will get overflow on cargo items.

name TEXT,
tier INTEGER,
rarity INTEGER,
icon TEXT,
extraction_skill INTEGER
);

CREATE TABLE IF NOT EXISTS recipes (
id INTEGER PRIMARY KEY AUTOINCREMENT,
item_id INTEGER,
output_quantity INTEGER,
level_requirement INTEGER,
FOREIGN KEY(item_id) REFERENCES items(id)
);

CREATE TABLE IF NOT EXISTS recipe_ingredients (
recipe_id INTEGER,
ingredient_id INTEGER,
quantity INTEGER,
FOREIGN KEY(recipe_id) REFERENCES recipes(id),
FOREIGN KEY(ingredient_id) REFERENCES items(id)
);

CREATE TABLE IF NOT EXISTS recipe_possibilities (
recipe_id INTEGER,
quantity INTEGER,
chance REAL,
FOREIGN KEY(recipe_id) REFERENCES recipes(id)
);
"""
)
conn.commit()

cur.execute("BEGIN")
for item_id_str, item in data.items():
item_id = int(item_id_str)
cur.execute(
"INSERT OR REPLACE INTO items (id, name, tier, rarity, icon, extraction_skill) "
"VALUES (?, ?, ?, ?, ?, ?)",
(
item_id,
item.get("name"),
item.get("tier"),
item.get("rarity"),
item.get("icon"),
item.get("extraction_skill", -1),
),
)
for recipe in item.get("recipes", []):
level_req = recipe.get("level_requirements")
lvl = level_req[0] if level_req else None
cur.execute(
"INSERT INTO recipes (item_id, output_quantity, level_requirement) VALUES (?, ?, ?)",
(item_id, recipe.get("output_quantity"), lvl),
)
recipe_id = cur.lastrowid
for ing in recipe.get("consumed_items", []):
cur.execute(
"INSERT INTO recipe_ingredients (recipe_id, ingredient_id, quantity) VALUES (?, ?, ?)",
(recipe_id, ing.get("id"), ing.get("quantity")),
)
for qty, chance in recipe.get("possibilities", {}).items():
cur.execute(
"INSERT INTO recipe_possibilities (recipe_id, quantity, chance) VALUES (?, ?, ?)",
(recipe_id, int(qty), chance),
)
conn.commit()

cur.executescript(
"""
CREATE INDEX IF NOT EXISTS idx_items_name ON items(name);
CREATE INDEX IF NOT EXISTS idx_recipes_item ON recipes(item_id);
CREATE INDEX IF NOT EXISTS idx_ingredients_ing ON recipe_ingredients(ingredient_id);
"""
)
conn.commit()
conn.close()


def main() -> None:
parser = argparse.ArgumentParser(description="Convert crafting_data.json to SQLite database")
parser.add_argument("json_path", nargs="?", default="BitPlanner/crafting_data.json", help="Path to crafting_data.json")
parser.add_argument("db_path", nargs="?", default="crafting_data.db", help="Output SQLite database path")
args = parser.parse_args()

build_database(Path(args.json_path), Path(args.db_path))


if __name__ == "__main__":
main()
40 changes: 40 additions & 0 deletions query_crafting_db.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,40 @@
import argparse
import sqlite3
from pathlib import Path


def query_prerequisites(conn: sqlite3.Connection, item_name: str):
cur = conn.cursor()
cur.execute(
"""
WITH RECURSIVE deps(id, name, depth, path) AS (
SELECT id, name, 0, ',' || id || ',' FROM items WHERE name LIKE ?
UNION ALL
SELECT ri.ingredient_id, i.name, depth + 1, path || ri.ingredient_id || ','
FROM deps
JOIN recipes r ON r.item_id = deps.id
JOIN recipe_ingredients ri ON ri.recipe_id = r.id
JOIN items i ON i.id = ri.ingredient_id
WHERE path NOT LIKE '%,' || ri.ingredient_id || ',%'
)
SELECT id, name, depth FROM deps ORDER BY depth, name
""",
(item_name,)
)
for item_id, name, depth in cur.fetchall():
print(" " * depth + f"{name} (#{item_id})")


def main() -> None:
parser = argparse.ArgumentParser(description="Query prerequisites for an item")
parser.add_argument("item", help="Item name or substring to search")
parser.add_argument("db_path", nargs="?", default="crafting_data.db", help="Path to SQLite database")
args = parser.parse_args()

conn = sqlite3.connect(Path(args.db_path))
query_prerequisites(conn, args.item)
conn.close()


if __name__ == "__main__":
main()