diff --git a/data/spells.sql b/data/spells.sql index a90585e..513f98d 100644 --- a/data/spells.sql +++ b/data/spells.sql @@ -1,9 +1,13 @@ + INSERT INTO spelltypes ( + spelltypes_id, + name +) +VALUES (1, 'Spell'), (2, 'Cantrip'), (3, 'Focus'), - (3, 'Ritual') -); + (4, 'Ritual'); INSERT INTO spellcomponents ( spellcomponents_id, @@ -41,4 +45,4 @@ VALUES (5, 1, '298','Evocation', 'TODO'), (6, 1, '298','Illusion', 'TODO'), (7, 1, '298','Necromancy', 'TODO'), - (8, 1, '298','Transmutation', 'Transmutation spells make alterations to or transform the physical form of a creature or object. The morph and polymorph traits appear primarily in transmutation spells.'), + (8, 1, '298','Transmutation', 'Transmutation spells make alterations to or transform the physical form of a creature or object. The morph and polymorph traits appear primarily in transmutation spells.'); diff --git a/data/third_party_json/spells.py b/data/third_party_json/spells.py index aad7eda..9685f18 100644 --- a/data/third_party_json/spells.py +++ b/data/third_party_json/spells.py @@ -1,4 +1,5 @@ import json +import sqlite3 def main(): # load json into python @@ -25,12 +26,271 @@ def main(): sorted_dicts.append(x) # NOW we can go alphabetically spell by spell - for i in sorted_dicts: - do_sql(i) -# TODO write this function after sql schema drafted -def do_sql(): - pass + ## Get database connection + conn = sqlite3.connect('../../pf2.db') + + # load in ids for traits from traits table so we only call this once + # instead of every spell + stmt = "SELECT trait_id, short_name FROM traits" + c = conn.cursor() + c.execute(stmt) + traits = c.fetchall() + # print(traits) + + # load in ids for spelltypes from spelltypes table so we only call this once + # instead of every spell + stmt = "SELECT spelltypes_id, name FROM spelltypes" + c = conn.cursor() + c.execute(stmt) + stypes = c.fetchall() + + # TODO FIX THIS FOR SPELL COMPONENTS + # CREATE TABLE spellcomponents ( + # spellcomponents_id INTEGER PRIMARY KEY, + # name TEXT NOT NULL UNIQUE + # ); + + # load in ids for spelltypes from spelltypes table so we only call this once + # instead of every spell + stmt = "SELECT spellcomponents_id, name FROM spellcomponents" + c = conn.cursor() + c.execute(stmt) + ctypes = c.fetchall() + + # List the various triggers and see if there are any duplicates + # THERE ARE NOT IN THE CRB SO NOT BOTHERING WITH SEPARATE TRIGGERS TABLE YET + ### trigs = [] + ### for i in sorted_dicts: + ### if 'trigger' in i: + ### trigs.append(i['trigger']) + ### print(sorted(trigs)) + ### print(len(trigs)) + ### print(len(set(trigs))) + + # List the various targets and see if there are any duplicates + ## YES, there are MANY duplicates, so we need a separate targets table + targs = [] + for i in sorted_dicts: + if 'targets' in i: + targs.append(i['targets']) + dedup_targs = set(targs) + sorted_targs = sorted(dedup_targs) + inp_targs = [] + id = 0 + for i in sorted_targs: + id += 1 + inp_targs.append((id,i)) + stmt = "INSERT INTO spelltargets (spelltargets_id, name) VALUES (?,?)" + try: + conn.executemany(stmt,inp_targs) + except: + print("Error creating targets") + else: + conn.commit() + + # load in ids for targets so just doing this once + stmt = "SELECT spelltargets_id, name FROM spelltargets" + c = conn.cursor() + c.execute(stmt) + ttypes = c.fetchall() + + + + # print(sorted(targs)) + # print(len(targs)) + # print(len(set(targs))) + + + id = 0 + for i in sorted_dicts: + id += 1 + do_basic_sql(i, id, conn) + do_range_numbers(i,id,conn) + do_sources_pages(i,id,conn) + do_spell_traits(i,id,conn,traits) + do_spell_types(i,id,conn,stypes) + do_spell_components(i,id,conn,ctypes) + do_spell_targets(i,id,conn,ttypes) + +def do_spell_components(i,id,conn,ctypes): + res = None + for j in ctypes: + for k in i['components']: + if k.capitalize() == j[1]: + res = j[0] + + inp = (res, id) + + stmt = "INSERT INTO spells_spellcomponents (spells_id, spellcomponents_id) VALUES (?,?)" + + try: + conn.execute(stmt, inp) + except: + print("Error inserting spell components") + else: + conn.commit() + +def do_spell_targets(i,id,conn,ttypes): + if 'targets' not in i: + return + res = 0 + for j in ttypes: + if i['targets'] == j[1]: + res = j[0] + # print(id , res) + + inp = (res, id) + + stmt = "UPDATE spells SET spelltargets_id=? WHERE spells_id=?" + + try: + conn.execute(stmt, inp) + except: + print("Error updating spelltargets_id") + else: + conn.commit() + +def do_spell_types(i,id,conn,stypes): + res = 0 + for j in stypes: + if i['type'] == j[1]: + res = j[0] + # print(id , res) + + inp = (res, id) + + stmt = "UPDATE spells SET spelltypes_id=? WHERE spells_id=?" + + try: + conn.execute(stmt, inp) + except: + print("Error updating spell types") + else: + conn.commit() + +def do_spell_traits(i, id, conn, traits): + + # get list of traits from the json and capitalize first letter + traits_json = [] + for item in i['traits']: + traits_json.append(item.capitalize()) + + trait_ids =[] + for j in traits_json: + for k in traits: + if j == k[1]: + trait_ids.append(k[0]) + # print(trait_ids) + + inp = [] + for j in trait_ids: + inp.append((id,j)) + # print(inp) + + # insert into sql + stmt = "INSERT OR REPLACE INTO spells_traits (spells_id, traits_id) VALUES (?,?)" + try: + conn.executemany(stmt, inp) + except: + print("Error updating traits") + else: + conn.commit() + + + +def do_sources_pages(i, id, conn): + if 'source' not in i: + return + + res = '' + source_id = 0 + # Do Core Rulebook branch + if "Core Rulebook" in i['source']: + res = i['source'].replace('Core Rulebook pg.','').strip() + source_id = 1 + + stmt = "UPDATE spells SET sources_id=?, sources_pages=? WHERE spells_id=?" + inp = (source_id, res, id) + + try: + conn.execute(stmt, inp) + except: + print("Error updating sources") + else: + conn.commit() + + + + +def do_range_numbers(i, id, conn): + # no need to do range + if 'range' not in i: + return + rg = -1 + # convert range_text to an integer representation + if i['range'] == 'touch': + rg = 0 + elif i['range'] == 'planetary': + rg = 999999999 + # is the only one in CRB with emanation 40' from current scraping + elif i['name'] == 'Repulsion': + rg = 40 + else: + # DO SPLITS + splits = i['range'].split(' ') + # print(splits) + rg = splits[0] + inp = (rg, id) + stmt = "UPDATE spells SET range_ft=? WHERE spells_id=?" + try: + conn.execute(stmt, inp) + except: + print("Error updating range_ft") + else: + conn.commit() + # print("Successfully updated range_ft") + + +def do_basic_sql(i, id, conn): + print("Doing spell id #{}: {}".format(id, i['name'])) + stmt = """INSERT INTO spells ( + spells_id, + sources_id, + sources_pages, + nethysurl, + name, + level, + descr, + range_text, + trigger, + area_text) + VALUES (?,?,?,?,?,?,?,?,?,?)""" + + rge = None + if 'range' in i: + rge = i['range'] + + dscr = None + if 'description' in i: + dscr = i['description'] + + trg = None + if 'trigger' in i: + trg = i['trigger'] + + area = None + if 'area' in i: + area = i['area'] + + inp = (id, 1, i['source'], i['nethysUrl'], i['name'], i['level'], dscr, rge, trg, area) + try: + conn.execute(stmt, inp) + except: + print("Error inserting row") + else: + conn.commit() + # print("Successfully inserted row") if __name__ == "__main__": diff --git a/gendb.sh b/gendb.sh index 9fdfeaf..3b41dbe 100755 --- a/gendb.sh +++ b/gendb.sh @@ -8,6 +8,7 @@ sqlite3 pf2.db < schema/bulk.sql sqlite3 pf2.db < schema/sizes.sql sqlite3 pf2.db < schema/langs.sql sqlite3 pf2.db < schema/traits.sql +sqlite3 pf2.db < schema/spells.sql sqlite3 pf2.db < schema/feats.sql sqlite3 pf2.db < schema/senses.sql sqlite3 pf2.db < schema/ancestries.sql @@ -22,9 +23,20 @@ sqlite3 pf2.db < data/senses.sql sqlite3 pf2.db < data/sizes.sql sqlite3 pf2.db < data/langs.sql sqlite3 pf2.db < data/traits.sql +sqlite3 pf2.db < data/spells.sql sqlite3 pf2.db < data/feats.sql sqlite3 pf2.db < data/ancestries.sql sqlite3 pf2.db < data/armor.sql sqlite3 pf2.db < data/heritages.sql +# Comment out the following three lines if you don't want to generate the spell data. +cd data/third_party_json +python3 spells.py +cd ../.. + +# TODO Eventually we will stop relying on the spells.py script and I will have +# the actual .sql files for the spell data; I am waiting to see if the +# third-party source improves the data in the next few weeks. If not, we'll +# "divorce" from that data, dump to .sql, and manually manipulate going +# forward. diff --git a/schema/spells.sql b/schema/spells.sql index 2ad2a4d..7a5ab90 100644 --- a/schema/spells.sql +++ b/schema/spells.sql @@ -15,6 +15,11 @@ CREATE TABLE spelltraditions ( name TEXT NOT NULL UNIQUE ); +CREATE TABLE spelltargets ( + spelltargets_id INTEGER PRIMARY KEY, + name TEXT NOT NULL UNIQUE +); + CREATE TABLE spellschools ( spellschools_id INTEGER PRIMARY KEY, sources_id INTEGER NOT NULL, @@ -24,27 +29,32 @@ CREATE TABLE spellschools ( FOREIGN KEY (sources_id) REFERENCES sources(sources_id) ); - +-- TODO eventually once data is finalized, lock down variables as NOT NULL / +-- UNIQUE as sanity requires :) +-- TODO Area eventually needs its own table CREATE TABLE spells ( spells_id INTEGER PRIMARY KEY, - sources_id INTEGER NOT NULL, - sources_pages TEXT, - nethysurl TEXT, - name TEXT NOT NULL UNIQUE, - source TEXT, - level INTEGER NOT NULL, - has_trigger BOOLEAN NOT NULL, - trigger TEXT, - descr TEXT NOT NULL, - spelltypes_id INTEGER NOT NULL, - range_text TEXT, - range_ft INTEGER, - targets TEXT, + sources_id INTEGER NOT NULL, -- generated in spells.py from scraped data + sources_pages TEXT, -- generated in spells.py from scraped data + name TEXT NOT NULL UNIQUE, -- scraped from github repo + level INTEGER, -- scraped from github repo + trigger TEXT, -- scraped from spells.py NOTE, there are no duplicate triggers + -- as of CRB, so not bothering with a separate spell triggers + -- table at this time + descr TEXT, -- scraped from github repo + spelltypes_id INTEGER, -- generated from spells.py + range_text TEXT, -- scraped from github repo + range_ft INTEGER, -- generated from text in spells.py + area_text TEXT, -- TODO need to figure out some sort of programmatic representation for this too + spelltargets_id INTEGER, + nethysurl TEXT, -- scraped from github repo FOREIGN KEY (sources_id) REFERENCES sources(sources_id), - FOREIGN KEY (spelltypes_id) REFERENCES spelltypes(spelltypes_id) + FOREIGN KEY (spelltypes_id) REFERENCES spelltypes(spelltypes_id), + FOREIGN KEY (spelltargets_id) REFERENCES spelltargets(spelltargets_id) ); CREATE TABLE spells_spellcomponents( + id INTEGER PRIMARY KEY, spells_id INTEGER NOT NULL, spellcomponents_id INTEGER NOT NULL, FOREIGN KEY (spells_id) REFERENCES spells(spells_id), @@ -56,6 +66,7 @@ CREATE TABLE spells_traits ( id INTEGER PRIMARY KEY, spells_id INTEGER NOT NULL, traits_id INTEGER NOT NULL, + UNIQUE(spells_id, traits_id), FOREIGN KEY (spells_id) REFERENCES spells(spells_id), FOREIGN KEY (traits_id) REFERENCES traits(traits_id) );