197 lines
8.3 KiB
Python
Executable file
197 lines
8.3 KiB
Python
Executable file
#! /usr/bin/python3
|
|
# Copyright (C) 2018-2020 Merspieler, merspieler _at_ airmail.cc
|
|
#
|
|
# This program is free software; you can redistribute it and/or
|
|
# modify it under the terms of the GNU General Public License as
|
|
# published by the Free Software Foundation; either version 3 of the
|
|
# License, or (at your option) any later version.
|
|
#
|
|
# This program is distributed in the hope that it will be useful, but
|
|
# WITHOUT ANY WARRANTY; without even the implied warranty of
|
|
# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU
|
|
# General Public License for more details.
|
|
#
|
|
# You should have received a copy of the GNU General Public License
|
|
# along with this program; if not, write to the Free Software
|
|
# Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301, USA.
|
|
|
|
import pymysql
|
|
import sys
|
|
from common import norm, get_tile_width, get_tile, get_area_name
|
|
|
|
dbuser= ""
|
|
dbpw = ""
|
|
force = False
|
|
|
|
argc = len(sys.argv)
|
|
i = 1
|
|
while i < argc:
|
|
if sys.argv[i] == "-p" or sys.argv[i] == "--password":
|
|
i += 1
|
|
dbpw = int(sys.argv[i])
|
|
elif sys.argv[i] == "-u" or sys.argv[i] == "--user":
|
|
i += 1
|
|
dbuser = sys.argv[i]
|
|
elif sys.argv[i] == "-f" or sys.argv[i] == "--force":
|
|
force = True
|
|
elif sys.argv[i] == "-h" or sys.argv[i] == "--help":
|
|
print("usage: init-db.py [OPTIONS]")
|
|
print("Initializes worldbuild status db")
|
|
print("")
|
|
print("OPTIONS")
|
|
print(" -p, --password Database password")
|
|
print(" -u, --user Database user")
|
|
print(" -f, --force Recreates everything from scratch")
|
|
print(" -h, --help Shows this help and exit")
|
|
sys.exit(0)
|
|
else:
|
|
print("Unknown option " + sys.argv[i])
|
|
sys.exit(1)
|
|
i += 1
|
|
|
|
if dbuser == "":
|
|
print("ERROR: No database user given")
|
|
sys.exit(1)
|
|
|
|
if dbpw == "":
|
|
print("ERROR: No database password given")
|
|
|
|
states = [
|
|
"pending",
|
|
"started",
|
|
"done",
|
|
"packaged",
|
|
"skip",
|
|
"rebuild"
|
|
]
|
|
|
|
#try:
|
|
db = pymysql.connect("localhost", dbuser, dbpw, "worldbuild")
|
|
|
|
cursor = db.cursor()
|
|
|
|
if force:
|
|
cursor.execute("DROP TABLE IF EXISTS tile")
|
|
cursor.execute("DROP TABLE IF EXISTS secondLevel")
|
|
cursor.execute("DROP TABLE IF EXISTS topLevel")
|
|
cursor.execute("DROP TABLE IF EXISTS status")
|
|
cursor.execute("DROP TRIGGER update_top_level")
|
|
cursor.execute("DROP TRIGGER update_second_level")
|
|
|
|
cursor.execute("CREATE TABLE IF NOT EXISTS status (id INT PRIMARY KEY AUTO_INCREMENT, name VARCHAR(15) UNIQUE NOT NULL);")
|
|
cursor.execute("CREATE TABLE IF NOT EXISTS topLevel (id INT PRIMARY KEY AUTO_INCREMENT, name CHAR(7) UNIQUE NOT NULL, status_id INT NOT NULL, FOREIGN KEY (status_id) REFERENCES status(id));")
|
|
cursor.execute("CREATE TABLE IF NOT EXISTS secondLevel (id INT PRIMARY KEY AUTO_INCREMENT, name CHAR(7) UNIQUE NOT NULL, status_id INT NOT NULL, parent_id INT NOT NULL, FOREIGN KEY (status_id) REFERENCES status(id), FOREIGN KEY (parent_id) REFERENCES topLevel(id));")
|
|
cursor.execute("CREATE TABLE IF NOT EXISTS tile (id INT PRIMARY KEY AUTO_INCREMENT, status_id INT NOT NULL, parent_id INT NOT NULL, FOREIGN KEY (status_id) REFERENCES status(id), FOREIGN KEY (parent_id) REFERENCES secondLevel(id));")
|
|
|
|
|
|
for state in states:
|
|
sql = "INSERT INTO status(name) VALUES ('" + state + "')"
|
|
cursor.execute(sql)
|
|
|
|
sql = "SELECT id FROM status WHERE name='pending'"
|
|
cursor.execute(sql)
|
|
result = cursor.fetchall()
|
|
for row in result:
|
|
sid = str(row[0])
|
|
|
|
print("Creating tile groups")
|
|
ii = -9
|
|
while ii < 9:
|
|
i = ii * 10
|
|
jj = -18
|
|
while jj < 18:
|
|
j = jj * 10
|
|
major = get_area_name(i, j)
|
|
|
|
sql = "INSERT INTO topLevel (name, status_id) VALUES ('" + major + "', " + sid + ");"
|
|
cursor.execute(sql)
|
|
|
|
sql = "SELECT id FROM topLevel WHERE name='" + major + "'"
|
|
cursor.execute(sql)
|
|
result = cursor.fetchall()
|
|
for row in result:
|
|
major_id = str(row[0])
|
|
|
|
for k in range(0, 10):
|
|
iii = i
|
|
for l in range(0, 10):
|
|
minor = get_area_name(iii, j)
|
|
sql = "INSERT INTO secondLevel (parent_id, name, status_id) VALUES (" + major_id + ", '" + minor + "', " + sid + ")"
|
|
cursor.execute(sql)
|
|
iii += 1
|
|
j += 1
|
|
jj += 1
|
|
ii += 1
|
|
|
|
print("Creating tiles")
|
|
lat = -90
|
|
while lat < 90:
|
|
lon = -180
|
|
while lon < 180:
|
|
tile = get_tile(lat, lon)
|
|
parent = get_area_name(int(lat), int(lon))
|
|
sql="SELECT id FROM secondLevel WHERE name='" + parent + "'"
|
|
cursor.execute(sql)
|
|
result = cursor.fetchall()
|
|
for row in result:
|
|
pid = row[0]
|
|
sql = "INSERT INTO tile (id, parent_id, status_id) VALUES (" + str(tile) + ", " + str(pid) + ", " + sid + ")"
|
|
cursor.execute(sql)
|
|
lon += get_tile_width(lat)
|
|
lat += 0.125
|
|
|
|
db.commit()
|
|
|
|
# Get states
|
|
#SELECT status.name AS state, COUNT(status.name) AS occ FROM tile INNER JOIN status ON tile.status_id = status.id WHERE tile.parent_id = 400 GROUP BY status.name;
|
|
|
|
print("Creating triggers")
|
|
|
|
# Trigger for updating secondLevel on tile update
|
|
sql = ('CREATE OR REPLACE TRIGGER update_second_level '
|
|
'AFTER UPDATE ON tile '
|
|
'FOR EACH ROW '
|
|
'BEGIN '
|
|
'IF (SELECT COUNT(status_id) FROM tile WHERE tile.parent_id = NEW.parent_id) = (SELECT COUNT(status_id) FROM tile WHERE tile.parent_id = NEW.parent_id AND status_id = (SELECT id FROM status WHERE name = "packaged")) THEN '
|
|
'UPDATE secondLevel SET status_id = (SELECT id FROM status WHERE name = "packaged") WHERE id = NEW.parent_id; '
|
|
'ELSEIF (SELECT COUNT(status_id) FROM tile WHERE tile.parent_id = NEW.parent_id) = (SELECT COUNT(status_id) FROM tile WHERE tile.parent_id = NEW.parent_id AND status_id = (SELECT id FROM status WHERE name = "done")) THEN '
|
|
'UPDATE secondLevel SET status_id = (SELECT id FROM status WHERE name = "done") WHERE id = NEW.parent_id; '
|
|
'ELSEIF (SELECT COUNT(status_id) FROM tile WHERE tile.parent_id = NEW.parent_id AND status_id = (SELECT id FROM status WHERE name = "started")) > 0 THEN '
|
|
'UPDATE secondLevel SET status_id = (SELECT id FROM status WHERE name = "started") WHERE id = NEW.parent_id; '
|
|
'ELSEIF (SELECT COUNT(status_id) FROM tile WHERE tile.parent_id = NEW.parent_id AND status_id = (SELECT id FROM status WHERE name = "rebuild")) > 0 THEN '
|
|
'UPDATE secondLevel SET status_id = (SELECT id FROM status WHERE name = "rebuild") WHERE id = NEW.parent_id; '
|
|
'ELSEIF (SELECT COUNT(status_id) FROM tile WHERE tile.parent_id = NEW.parent_id AND status_id = (SELECT id FROM status WHERE name = "skip")) > 0 THEN '
|
|
'UPDATE secondLevel SET status_id = (SELECT id FROM status WHERE name = "skip") WHERE id = NEW.parent_id; '
|
|
'ELSE '
|
|
'UPDATE secondLevel SET status_id = (SELECT id FROM status WHERE name = "pending") WHERE id = NEW.parent_id; '
|
|
'END IF; '
|
|
'END; ')
|
|
cursor.execute(sql)
|
|
|
|
# Trigger for updating topLevel on secondLevel update
|
|
sql = ('CREATE OR REPLACE TRIGGER update_top_level '
|
|
'AFTER UPDATE ON secondLevel '
|
|
'FOR EACH ROW '
|
|
'BEGIN '
|
|
'IF (SELECT COUNT(status_id) FROM secondLevel WHERE secondLevel.parent_id = NEW.parent_id) = (SELECT COUNT(status_id) FROM secondLevel WHERE secondLevel.parent_id = NEW.parent_id AND status_id = (SELECT id FROM status WHERE name = "packaged")) THEN '
|
|
'UPDATE topLevel SET status_id = (SELECT id FROM status WHERE name = "packaged") WHERE id = NEW.parent_id; '
|
|
'ELSEIF (SELECT COUNT(status_id) FROM secondLevel WHERE secondLevel.parent_id = NEW.parent_id) = (SELECT COUNT(status_id) FROM secondLevel WHERE secondLevel.parent_id = NEW.parent_id AND status_id = (SELECT id FROM status WHERE name = "done")) THEN '
|
|
'UPDATE topLevel SET status_id = (SELECT id FROM status WHERE name = "done") WHERE id = NEW.parent_id; '
|
|
'ELSEIF (SELECT COUNT(status_id) FROM secondLevel WHERE secondLevel.parent_id = NEW.parent_id AND status_id = (SELECT id FROM status WHERE name = "started")) > 0 THEN '
|
|
'UPDATE topLevel SET status_id = (SELECT id FROM status WHERE name = "started") WHERE id = NEW.parent_id; '
|
|
'ELSEIF (SELECT COUNT(status_id) FROM secondLevel WHERE secondLevel.parent_id = NEW.parent_id AND status_id = (SELECT id FROM status WHERE name = "rebuild")) > 0 THEN '
|
|
'UPDATE topLevel SET status_id = (SELECT id FROM status WHERE name = "rebuild") WHERE id = NEW.parent_id; '
|
|
'ELSEIF (SELECT COUNT(status_id) FROM secondLevel WHERE secondLevel.parent_id = NEW.parent_id AND status_id = (SELECT id FROM status WHERE name = "skip")) > 0 THEN '
|
|
'UPDATE topLevel SET status_id = (SELECT id FROM status WHERE name = "skip") WHERE id = NEW.parent_id; '
|
|
'ELSE '
|
|
'UPDATE topLevel SET status_id = (SELECT id FROM status WHERE name = "pending") WHERE id = NEW.parent_id; '
|
|
'END IF; '
|
|
'END; ')
|
|
cursor.execute(sql)
|
|
db.commit()
|
|
|
|
#except:
|
|
# db.rollback()
|
|
# print("Failed to setup database...")
|
|
#finally:
|
|
db.close()
|