7.4 KiB
7.4 KiB
Items Table Expansion - Migration Plan
Goal
Expand the items table to support efficient queries for an interactive map and media wiki server.
Database Design Strategy
We'll use a hybrid approach:
- Commonly queried fields → Direct columns in
itemstable - One-to-many/many-to-many relationships → Separate normalized tables
- Complex nested data → Keep in JSON
datacolumn
Phase 1: Add Core Columns to Items Table
New Columns for items table:
ALTER TABLE items ADD COLUMN item_type TEXT NOT NULL DEFAULT 'resource';
ALTER TABLE items ADD COLUMN level INTEGER NOT NULL DEFAULT 1;
ALTER TABLE items ADD COLUMN price INTEGER NOT NULL DEFAULT 0;
ALTER TABLE items ADD COLUMN max_stack INTEGER NOT NULL DEFAULT 1;
ALTER TABLE items ADD COLUMN skill TEXT NOT NULL DEFAULT 'none';
ALTER TABLE items ADD COLUMN tool TEXT NOT NULL DEFAULT 'none';
ALTER TABLE items ADD COLUMN description TEXT NOT NULL DEFAULT '';
-- Boolean flags (stored as INTEGER: 0=false, 1=true)
ALTER TABLE items ADD COLUMN two_handed INTEGER NOT NULL DEFAULT 0;
ALTER TABLE items ADD COLUMN undroppable INTEGER NOT NULL DEFAULT 0;
ALTER TABLE items ADD COLUMN undroppable_on_death INTEGER NOT NULL DEFAULT 0;
ALTER TABLE items ADD COLUMN unequip_destroy INTEGER NOT NULL DEFAULT 0;
ALTER TABLE items ADD COLUMN generate_icon INTEGER NOT NULL DEFAULT 0;
ALTER TABLE items ADD COLUMN hide_milestone INTEGER NOT NULL DEFAULT 0;
ALTER TABLE items ADD COLUMN cannot_craft_exceptional INTEGER NOT NULL DEFAULT 0;
ALTER TABLE items ADD COLUMN storage_all_items INTEGER NOT NULL DEFAULT 0;
-- IDs for relationships
ALTER TABLE items ADD COLUMN ability_id INTEGER NOT NULL DEFAULT 0;
ALTER TABLE items ADD COLUMN special_ability INTEGER NOT NULL DEFAULT 0;
ALTER TABLE items ADD COLUMN learn_ability_id INTEGER NOT NULL DEFAULT 0;
ALTER TABLE items ADD COLUMN book_id INTEGER NOT NULL DEFAULT 0;
ALTER TABLE items ADD COLUMN swap_item INTEGER NOT NULL DEFAULT 0;
ALTER TABLE items ADD COLUMN storage_size INTEGER NOT NULL DEFAULT 0;
Use Case: Direct filtering and sorting
- "Show all items with level > 50"
- "Show all weapons"
- "Show stackable items"
Phase 2: Create Related Tables
2.1 Item Categories (many-to-many)
CREATE TABLE item_categories (
item_id INTEGER NOT NULL,
category TEXT NOT NULL,
PRIMARY KEY (item_id, category),
FOREIGN KEY (item_id) REFERENCES items(id) ON DELETE CASCADE
);
CREATE INDEX idx_item_categories_category ON item_categories(category);
Use Case:
- "Show all bows"
- "Show all heavy armor"
2.2 Item Stats (one-to-many)
CREATE TABLE item_stats (
item_id INTEGER NOT NULL,
stat_type TEXT NOT NULL,
value REAL NOT NULL,
PRIMARY KEY (item_id, stat_type),
FOREIGN KEY (item_id) REFERENCES items(id) ON DELETE CASCADE
);
CREATE INDEX idx_item_stats_stat_type ON item_stats(stat_type);
CREATE INDEX idx_item_stats_value ON item_stats(value);
Use Case:
- "Show all items with Health > 100"
- "Show all items with DamagePhysical"
2.3 Crafting Recipes (normalized)
CREATE TABLE crafting_recipes (
id INTEGER PRIMARY KEY AUTOINCREMENT,
product_item_id INTEGER NOT NULL,
skill TEXT NOT NULL,
level INTEGER NOT NULL,
workbench_id INTEGER NOT NULL,
xp INTEGER NOT NULL DEFAULT 0,
unlocked_by_default INTEGER NOT NULL DEFAULT 1,
checks TEXT, -- nullable, for conditional recipes
FOREIGN KEY (product_item_id) REFERENCES items(id) ON DELETE CASCADE
);
CREATE INDEX idx_crafting_recipes_product ON crafting_recipes(product_item_id);
CREATE INDEX idx_crafting_recipes_skill ON crafting_recipes(skill);
CREATE INDEX idx_crafting_recipes_level ON crafting_recipes(level);
CREATE TABLE crafting_recipe_items (
recipe_id INTEGER NOT NULL,
item_id INTEGER NOT NULL,
amount INTEGER NOT NULL,
PRIMARY KEY (recipe_id, item_id),
FOREIGN KEY (recipe_id) REFERENCES crafting_recipes(id) ON DELETE CASCADE,
FOREIGN KEY (item_id) REFERENCES items(id)
);
CREATE INDEX idx_crafting_recipe_items_item ON crafting_recipe_items(item_id);
Use Case:
- "Show all recipes that use Copper Ore"
- "Show all Blacksmithy recipes"
- "What can I craft with these items?"
2.4 Item Storage (for storage_items vec)
CREATE TABLE item_storage_allowed (
storage_item_id INTEGER NOT NULL,
allowed_item_id INTEGER NOT NULL,
PRIMARY KEY (storage_item_id, allowed_item_id),
FOREIGN KEY (storage_item_id) REFERENCES items(id) ON DELETE CASCADE,
FOREIGN KEY (allowed_item_id) REFERENCES items(id)
);
Use Case:
- "What items can be stored in this container?"
2.5 Item XP Boosts
CREATE TABLE item_xp_boosts (
item_id INTEGER NOT NULL,
skill_type TEXT NOT NULL,
multiplier REAL NOT NULL,
PRIMARY KEY (item_id, skill_type),
FOREIGN KEY (item_id) REFERENCES items(id) ON DELETE CASCADE
);
2.6 Permanent Stat Boosts
CREATE TABLE item_permanent_stat_boosts (
item_id INTEGER NOT NULL,
stat_type TEXT NOT NULL,
amount INTEGER NOT NULL,
PRIMARY KEY (item_id, stat_type),
FOREIGN KEY (item_id) REFERENCES items(id) ON DELETE CASCADE
);
Phase 3: Keep JSON Data Column
The data column stays as-is for:
- Complete item retrieval without joins
- Fields rarely queried (animations, models, audio, etc.)
- Custom names/descriptions with checks
- Future flexibility
Implementation Steps
Step 1: Create Migration File
- Create
migrations/2026-01-11-expand-items/up.sql - Create
migrations/2026-01-11-expand-items/down.sql
Step 2: Update Rust Schema
- Run
diesel migration generate expand_items - Update
src/schema.rs(diesel will auto-generate)
Step 3: Update save_to_db() in item_database.rs
- Insert item columns
- Insert related records (categories, stats, recipes, etc.)
- Use transactions for consistency
Step 4: Update load_from_db() in item_database.rs
- Load items with all related data
- Reconstruct full Item struct from columns + related tables
Step 5: Add Query Helper Methods
// Examples:
pub fn search_by_name(&self, query: &str) -> Vec<&Item>
pub fn filter_by_level_range(&self, min: i32, max: i32) -> Vec<&Item>
pub fn filter_by_stat(&self, stat_type: StatType, min_value: f32) -> Vec<&Item>
pub fn get_items_using_ingredient(&self, ingredient_id: i32) -> Vec<&Item>
Benefits of This Approach
✅ Efficient Queries - No JSON parsing for common filters ✅ Flexible - JSON fallback for complex data ✅ Maintainable - Clear relationships between entities ✅ Scalable - Can add indexes as needed ✅ Wiki-Friendly - Easy joins for "Used In" sections
Query Examples for Wiki/Map
-- Find all level 50+ weapons
SELECT * FROM items WHERE item_type = 'weapon' AND level >= 50;
-- Find items that give health bonuses
SELECT i.* FROM items i
JOIN item_stats s ON i.id = s.item_id
WHERE s.stat_type = 'health' AND s.value > 0;
-- Find all recipes using Copper Ore (id=33)
SELECT i.name, r.level, r.skill FROM crafting_recipes r
JOIN crafting_recipe_items ri ON r.id = ri.recipe_id
JOIN items i ON r.product_item_id = i.id
WHERE ri.item_id = 33;
-- Find all bows
SELECT i.* FROM items i
JOIN item_categories c ON i.id = c.item_id
WHERE c.category = 'bow';
Next Steps
Would you like me to:
- ✅ Generate the migration files?
- ✅ Update the
save_to_db()andload_from_db()methods? - ✅ Add query helper methods?
- ⚠️ Keep it simple and just add Phase 1 columns first?