This commit is contained in:
norohind 2021-10-19 20:20:15 +03:00
commit 551643fa38
Signed by: norohind
GPG Key ID: 01C3BECC26FB59E1
3 changed files with 229 additions and 0 deletions

109
doc.txt Normal file
View File

@ -0,0 +1,109 @@
what to store?
1. Systems:
history of system's updates
softwareName + softwareVersion for every update
system_name
star_class
system_id
x
y
z
2. Routes
Sequence of system_id s
tables:
systems
system_name
star_class
system_id
x
y
z
updated_timestamp (from event, not gateway)
software_name
software_version
systems_history (should be done by triggers on `systems` updates)
old_system_name
new_system_name
old_star_class
new_star_class
old_system_id
new_system_id
old_x
new_x
old_y
new_y
old_z
new_z
old_updated_timestamp
new_updated_timestamp
software_name
software_version
timestamp (default) (timestamp of insertion)
routes:
route_id (by the program)
point_id (from 0 to ...)
system_id
timestamp (from event, not gateway)
how to handle:
1. Iterate over the route, save data to `systems`
1.1 If event's timestamp < updated_timestamp, then do nothing
2. Get last route_id from DB and increment it - it is our new route_id
3. Iterate over the route, save data to `routes`
creating:
create table if not exists systems (system_name text, star_class text, system_id int unique, x float, y float, z float,
updated_timestamp text, software_name text, software_version text);
create table if not exists routes (route_id int, point_id int, system_id int, timestamp str);
create table if not exists systems_history (old_system_name text, new_system_name text, old_star_class text,
new_star_class text, new_system_id int, old_system_id int, old_x text, new_x text, old_y text, new_y text, old_z text,
new_z text, old_updated_timestamp text, new_updated_timestamp text, software_name text, software_version text,
timestamp text default current_timestamp);
create trigger if not exists update_systems_history_insert
before insert on systems
begin
insert into systems_history (new_system_name, new_star_class, new_system_id, new_x, new_y, new_z, new_updated_timestamp,
software_name, software_version)
values (new.system_name, new.star_class, new.system_id, new.x, new.y, new.z, new.updated_timestamp, new.software_name, new.software_version);
end;
create trigger if not exists update_systems_history_update
before update on systems
begin
insert into systems_history (
old_system_name, new_system_name,
old_star_class, new_star_class,
old_system_id, new_system_id,
old_x, new_x,
old_y, new_y,
old_z, new_z,
old_updated_timestamp, new_updated_timestamp,
software_name,
software_version
) values (
old.system_name, new.system_name,
old.star_class, new.star_class,
old.system_id, new.system_id,
old.x, new.x,
old.y, new.y,
old.z, new.z,
old.updated_timestamp, new.updated_timestamp,
new.software_name,
new.software_version
);
end;

83
main.py Normal file
View File

@ -0,0 +1,83 @@
import json
import sys
import sqlite3
sql_conn = sqlite3.connect('navroutes.sqlite')
with open('schema.sql', 'r', encoding='utf-8') as schema_file:
sql_conn.executescript(''.join(schema_file.readlines()))
for line in sys.stdin: # open('example.txt', 'r').readlines():
event = json.loads(line)
if event['$schemaRef'] != 'https://eddn.edcd.io/schemas/navroute/1':
continue
software_name = event['header']['softwareName']
software_version = event['header']['softwareVersion']
timestamp = event['message']['timestamp']
route = event['message']['Route']
route_for_insert = list()
point_id = 0
route_id = sql_conn.execute('select route_id from routes order by route_id desc limit 1;').fetchone()
if route_id is None:
route_id = 0
else:
route_id = route_id[0] + 1
for route_point in route:
StarSystem = route_point['StarSystem']
StarSystemID = route_point['SystemAddress']
StarClass = route_point['StarClass']
x = route_point['StarPos'][0]
y = route_point['StarPos'][1]
z = route_point['StarPos'][2]
sql_r = sql_conn.execute('select count(*) from systems where system_id = ?', [StarSystemID])
route_for_insert.append([route_id, point_id, StarSystemID, timestamp])
point_id = point_id + 1
if sql_r.fetchone()[0] > 0:
with sql_conn:
sql_conn.execute('update systems set '
'system_name = ?,'
'star_class = ?,'
'x = ?,'
'y = ?,'
'z = ?,'
'updated_timestamp = ?,'
'software_name = ?,'
'software_version = ? '
'where system_id = ?',
[StarSystem, StarClass, x, y, z, timestamp,
software_name, software_version, StarSystemID])
else:
with sql_conn:
sql_conn.execute('insert into systems ('
'system_name,'
'star_class,'
'system_id,'
'x,'
'y,'
'z,'
'updated_timestamp,'
'software_name,'
'software_version'
') values (?, ?, ?, ?, ?, ?, ?, ?, ?);',
[StarSystem, StarClass, StarSystemID, x, y, z,
timestamp, software_name, software_version])
with sql_conn:
sql_conn.executemany('insert into routes (route_id, point_id, system_id, timestamp) values (?, ?, ?, ?)'
, route_for_insert)
sql_conn.close()

37
schema.sql Normal file
View File

@ -0,0 +1,37 @@
create table if not exists systems (system_name text, star_class text, system_id int unique, x float, y float, z float,
updated_timestamp text, software_name text, software_version text);
create table if not exists routes (route_id int, point_id int, system_id int, timestamp str);
create table if not exists systems_history (old_system_name text, new_system_name text, old_star_class text,
new_star_class text, new_system_id int, old_system_id int, old_x text, new_x text, old_y text, new_y text, old_z text,
new_z text, old_updated_timestamp text, new_updated_timestamp text, software_name text, software_version text,
timestamp text default current_timestamp);
create trigger if not exists update_systems_history_insert
before insert on systems
begin
insert into systems_history (new_system_name, new_star_class, new_system_id, new_x, new_y, new_z, new_updated_timestamp,
software_name, software_version)
values (new.system_name, new.star_class, new.system_id, new.x, new.y, new.z, new.updated_timestamp, new.software_name, new.software_version);
end;
create trigger if not exists update_systems_history_update
before update on systems
begin
insert into systems_history (
old_system_name, new_system_name,
old_star_class, new_star_class,
old_system_id, new_system_id,
old_x, new_x,
old_y, new_y,
old_z, new_z,
old_updated_timestamp, new_updated_timestamp,
software_name,
software_version) values (
old.system_name, new.system_name,
old.star_class, new.star_class,
old.system_id, new.system_id,
old.x, new.x,
old.y, new.y,
old.z, new.z,
old.updated_timestamp, new.updated_timestamp,
new.software_name,
new.software_version);
end;