91 lines
3.1 KiB
SQL
91 lines
3.1 KiB
SQL
--DROP TABLE IF EXISTS item_stat;
|
|
--DROP TABLE IF EXISTS item_affix;
|
|
--DROP TABLE IF EXISTS item_extra;
|
|
--DROP TABLE IF EXISTS item;
|
|
|
|
CREATE TABLE item (
|
|
id INTEGER PRIMARY KEY,
|
|
created TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
deleted TIMESTAMP DEFAULT NULL,
|
|
-- Nuked: if the item has been removed from storage & user indicated he does not
|
|
-- want to count it as potentially in his possession any longer
|
|
nuked BOOLEAN DEFAULT NULL,
|
|
-- Names: simple items have only a name equal to their base name, most non simple
|
|
-- items have two names: the base name and item_extra.item_name.
|
|
itembase_name TEXT NOT NULL,
|
|
socketed_into INTEGER DEFAULT NULL,
|
|
req_lvl INTEGER DEFAULT 0,
|
|
|
|
-- The following fields match the fields of the item object in item.py
|
|
raw_data BLOB NOT NULL,
|
|
raw_version INTEGER NOT NULL,
|
|
is_identified BOOLEAN NOT NULL,
|
|
is_socketed BOOLEAN NOT NULL,
|
|
is_beginner BOOLEAN NOT NULL,
|
|
is_simple BOOLEAN NOT NULL,
|
|
is_ethereal BOOLEAN NOT NULL,
|
|
is_personalized BOOLEAN NOT NULL,
|
|
is_runeword BOOLEAN NOT NULL,
|
|
code TEXT NOT NULL,
|
|
|
|
FOREIGN KEY (socketed_into) REFERENCES item (id)
|
|
);
|
|
-- Add an index for "... WHERE deletion IS NULL"
|
|
CREATE INDEX item_deletion_partial ON item (deleted) WHERE deleted IS NULL;
|
|
|
|
CREATE TABLE item_extra (
|
|
item_id INTEGER PRIMARY KEY,
|
|
item_name TEXT DEFAULT NULL,
|
|
set_name TEXT DEFAULT NULL,
|
|
req_str INTEGER DEFAULT 0,
|
|
req_dex INTEGER DEFAULT 0,
|
|
req_class TEXT DEFAULT NULL,
|
|
|
|
-- The following fields match the fields of the item object in item.py
|
|
uid INTEGER DEFAULT NULL,
|
|
lvl INTEGER DEFAULT NULL,
|
|
quality INTEGER DEFAULT NULL CHECK(1 <= quality AND quality <= 8),
|
|
graphic INTEGER DEFAULT NULL,
|
|
implicit INTEGER DEFAULT NULL,
|
|
low_quality INTEGER DEFAULT NULL CHECK(0 <= low_quality AND low_quality <= 3),
|
|
set_id INTEGER DEFAULT NULL,
|
|
unique_id INTEGER DEFAULT NULL,
|
|
nameword1 INTEGER DEFAULT NULL,
|
|
nameword2 INTEGER DEFAULT NULL,
|
|
runeword_id INTEGER DEFAULT NULL,
|
|
personal_name TEXT DEFAULT NULL,
|
|
defense INTEGER DEFAULT NULL,
|
|
durability INTEGER DEFAULT NULL,
|
|
max_durability INTEGER DEFAULT NULL,
|
|
sockets INTEGER DEFAULT NULL, -- number of sockets; see item.socketed_into
|
|
quantity INTEGER DEFAULT NULL,
|
|
-- stats: list[Stat] | None = None => see table 'item_stat'
|
|
|
|
FOREIGN KEY (item_id) REFERENCES item (id)
|
|
);
|
|
CREATE INDEX item_extra_item_id ON item_extra (item_id);
|
|
|
|
CREATE TABLE item_stat (
|
|
id INTEGER PRIMARY KEY,
|
|
item_id INTEGER NOT NULL,
|
|
stat INTEGER NOT NULL,
|
|
value1 INTEGER DEFAULT NULL,
|
|
value2 INTEGER DEFAULT NULL,
|
|
value3 INTEGER DEFAULT NULL,
|
|
parameter INTEGER DEFAULT NULL,
|
|
|
|
FOREIGN KEY (item_id) REFERENCES item (id)
|
|
);
|
|
CREATE INDEX item_stat_item_id ON item_stat (item_id);
|
|
CREATE INDEX item_stat_stat ON item_stat (stat);
|
|
|
|
CREATE TABLE item_affix (
|
|
id INTEGER PRIMARY KEY,
|
|
item_id INTEGER NOT NULL,
|
|
prefix BOOLEAN NOT NULL,
|
|
affix_id INTEGER NOT NULL,
|
|
|
|
FOREIGN KEY (item_id) REFERENCES item (id)
|
|
);
|
|
CREATE INDEX item_affix_item_id ON item_affix (item_id);
|