DB schema done
Migration script done
This commit is contained in:
norohind 2022-04-09 22:21:37 +03:00
parent 96b8aee9c2
commit 5955f2f093
Signed by: norohind
GPG Key ID: 01C3BECC26FB59E1
4 changed files with 614 additions and 0 deletions

220
DataMigration.py Normal file
View File

@ -0,0 +1,220 @@
from datetime import datetime, timedelta
from time import time
from collections import defaultdict
import sqlite3
import signal
old_db = sqlite3.connect("..\\NewSquadsMonitor\\squads.sqlite")
old_db.row_factory = lambda c, r: dict(zip([col[0] for col in c.description], r))
# old_db.row_factory = sqlite3.Row
new_db = sqlite3.connect('jubilant-system.sqlite')
new_db.row_factory = lambda c, r: dict(zip([col[0] for col in c.description], r))
# new_db.row_factory = sqlite3.Row
class QUERIES:
class NEW:
SCHEMA = ''.join(open('sql\\schema.sql', mode='r').readlines())
CREATE_OPERATION_ID = 'insert into operations_info (squad_id, timestamp) values (:squad_id, :timestamp);'
GET_OPERATION_ID = 'select operation_id from operations_info order by operation_id desc limit 1;'
INSERT_DELETED_SQUAD = 'insert into squadrons_deleted (operation_id, squad_id) VALUES (:operation_id, :squad_id);'
IS_DELETED = 'select count(*) as deleted from squadrons_deleted where squad_id = :squad_id;'
INSERT_INFO = """INSERT INTO squadrons_historical_data (
operation_id,
name,
tag,
owner_name,
owner_id,
platform,
created,
created_ts,
accepting_new_members,
power_id,
power_name,
superpower_id,
superpower_name,
faction_id,
faction_name,
user_tags,
member_count,
pending_count,
"full",
public_comms,
public_comms_override,
public_comms_available,
current_season_trade_score,
previous_season_trade_score,
current_season_combat_score,
previous_season_combat_score,
current_season_exploration_score,
previous_season_exploration_score,
current_season_cqc_score,
previous_season_cqc_score,
current_season_bgs_score,
previous_season_bgs_score,
current_season_powerplay_score,
previous_season_powerplay_score,
current_season_aegis_score,
previous_season_aegis_score
) values (
:operation_id,
:name,
:tag,
:owner_name,
:owner_id,
:platform,
:created,
:created_ts,
:accepting_new_members,
:power_id,
:power_name,
:super_power_id,
:super_power_name,
:faction_id,
:faction_name,
:user_tags,
:member_count,
:pending_count,
:full,
:public_comms,
:public_comms_override,
:public_comms_available,
:current_season_trade_score,
:previous_season_trade_score,
:current_season_combat_score,
:previous_season_combat_score,
:current_season_exploration_score,
:previous_season_exploration_score,
:current_season_cqc_score,
:previous_season_cqc_score,
:current_season_bgs_score,
:previous_season_bgs_score,
:current_season_powerplay_score,
:previous_season_powerplay_score,
:current_season_aegis_score,
:previous_season_aegis_score
);"""
INSERT_NEWS = """INSERT INTO squadrons_news_historical (
operation_id,
type_of_news,
news_id,
date,
category,
activity,
season,
bookmark,
motd,
author,
cmdr_id,
user_id
) values (
:operation_id,
:type_of_news,
:news_id,
:date,
:category,
:activity,
:season,
:bookmark,
:motd,
:author,
:cmdr_id,
:user_id
);"""
class OLD:
ALL_RECORDS = 'select * from squads_states order by inserted_timestamp;'
NEWS_IN_TIME_BOUND = '''select *
from news
where squad_id = :squad_id and
inserted_timestamp between :low_bound and :high_bound and
category = 'Squadrons_History_Category_PublicStatement' and
"date" is not null and
type_of_news = 'public_statements';'''
ALL_NEWS_RECORDS = '''select *
from news
where
category = 'Squadrons_History_Category_PublicStatement' and
"date" is not null and
type_of_news = 'public_statements';'''
exiting: bool = False
def exit_handler(_, __):
global exiting
exiting = True
signal.signal(signal.SIGINT, exiting)
signal.signal(signal.SIGTERM, exiting)
def allocate_operation_id(_squad_id: int, _timestamp: str) -> int:
new_db.execute(QUERIES.NEW.CREATE_OPERATION_ID, {'squad_id': _squad_id, 'timestamp': _timestamp})
return new_db.execute(QUERIES.NEW.GET_OPERATION_ID).fetchone()['operation_id']
new_db.executescript(QUERIES.NEW.SCHEMA)
news: dict[int, list[dict]] = defaultdict(list)
news_cache_timer = time()
for one_news in old_db.execute(QUERIES.OLD.ALL_NEWS_RECORDS):
news[one_news['squad_id']].append(one_news)
print(f'news cached for {time() - news_cache_timer} s')
iterations_counter = 1
loop_timer = time()
loop_timer_secondary = time()
row: dict
for row in old_db.execute(QUERIES.OLD.ALL_RECORDS):
if exiting:
break
squad_id: int = row['squad_id']
# print(f'Processing: {squad_id}')
timestamp: str = row['inserted_timestamp']
if row['tag'] is None:
# "Deleted" record for squad_id
if new_db.execute(QUERIES.NEW.IS_DELETED, {'squad_id': squad_id}).fetchone()['deleted'] == 0:
# with new_db:
operation_id = allocate_operation_id(squad_id, timestamp)
new_db.execute(QUERIES.NEW.INSERT_DELETED_SQUAD, {'operation_id': operation_id, 'squad_id': squad_id})
else:
# it's usual update/first update record
# with new_db:
operation_id = allocate_operation_id(squad_id, timestamp)
row['operation_id'] = operation_id
new_db.execute(
QUERIES.NEW.INSERT_INFO,
row
)
parsed_timestamp = datetime.strptime(timestamp, '%Y-%m-%d %H:%M:%S')
delta = timedelta(minutes=1)
low_bound = parsed_timestamp - delta
high_bound = parsed_timestamp + delta
for one_squad_news in news[squad_id]:
if low_bound < datetime.strptime(one_squad_news['inserted_timestamp'], '%Y-%m-%d %H:%M:%S') < high_bound:
one_squad_news['operation_id'] = operation_id
new_db.execute(QUERIES.NEW.INSERT_NEWS, one_squad_news)
break
if iterations_counter % 1000 == 0:
new_db.commit()
print(f'Iterations: {iterations_counter}; avg iteration time: {(time() - loop_timer)/iterations_counter} s; avg local iter time {(time() - loop_timer_secondary)/1000} s')
loop_timer_secondary = time()
iterations_counter += 1
new_db.commit()
print(f'Iterations: {iterations_counter}; avg total iter time: {(time() - loop_timer)/iterations_counter} s')

25
main.py Normal file
View File

@ -0,0 +1,25 @@
"""
Workflow to discover new squadrons (db operations):
1. Get next id
2. Query info endpoint
3. If squadron exists:
Insert squad_id into operations_info
get operation_id
Insert into squadrons_historical_data data from info endpoint
Insert into squadrons_news_historical data from news endpoint
else:
ignore, don't insert squad_id to squadrons_deleted
Workflow to update existing squadron:
1. Get most early updated squad from squadrons_current_data
2. Insert squad_id into operations_info
3. Get operation_id
4. Request info endpoint
if squad exists:
query news endpoint
insert data from info and news queries to appropriate historical tables
else:
insert squad_id, operations_id to squadrons_deleted
"""

View File

@ -0,0 +1,61 @@
BEGIN;
delete from squadrons_current_data;
insert into squadrons_current_data
select
squad_id,
name,
tag,
owner_id,
owner_name,
platform,
created,
created_ts,
accepting_new_members,
power_id,
power_name,
superpower_id,
superpower_name,
faction_id,
faction_name,
delete_after,
credits_balance,
credits_in,
credits_out,
user_tags,
member_count,
online_count,
pending_count,
"full",
public_comms,
public_comms_override,
public_comms_available,
current_season_trade_score,
previous_season_trade_score,
current_season_combat_score,
previous_season_combat_score,
current_season_exploration_score,
previous_season_exploration_score,
current_season_cqc_score,
previous_season_cqc_score,
current_season_bgs_score,
previous_season_bgs_score,
current_season_powerplay_score,
previous_season_powerplay_score,
current_season_aegis_score,
previous_season_aegis_score,
motd,
author,
cmdr_id,
user_id,
news_id,
"date",
squadrons_historical_data.operation_id as operation_id,
max(timestamp) as updated
from squadrons_historical_data
inner join operations_info oi
on oi.operation_id = squadrons_historical_data.operation_id
left join squadrons_news_historical snh
on oi.operation_id = snh.operation_id
where squad_id not in (select squad_id from squadrons_deleted)
group by squad_id;
COMMIT;

308
sql/schema.sql Normal file
View File

@ -0,0 +1,308 @@
create table if not exists settings (
key varchar(25) primary key not null,
int_value int,
txt_value text
);
create table if not exists operations_info (
operation_id integer primary key autoincrement not null,
"timestamp" datetime default current_timestamp,
squad_id integer
);
insert into settings (key, int_value) values ('disable_triggers', 1) on conflict do nothing;
create table if not exists squadrons_news_historical (
operation_id integer,
type_of_news text,
news_id int,
"date" int,
category text,
activity text,
season int,
bookmark text,
motd text,
author text,
cmdr_id int,
user_id int,
foreign key (operation_id) references operations_info(operation_id)
);
create table if not exists squadrons_historical_data (
operation_id integer,
name text,
tag text,
owner_id integer,
owner_name text,
platform text,
created text,
created_ts int,
accepting_new_members bool,
power_id int,
power_name text,
superpower_id int,
superpower_name text,
faction_id int,
faction_name text,
delete_after text,
credits_balance int,
credits_in int,
credits_out int,
user_tags text,
member_count int,
online_count int,
pending_count int,
"full" bool,
public_comms bool,
public_comms_override bool,
public_comms_available bool,
current_season_trade_score int,
previous_season_trade_score int,
current_season_combat_score int,
previous_season_combat_score int,
current_season_exploration_score int,
previous_season_exploration_score int,
current_season_cqc_score int,
previous_season_cqc_score int,
current_season_bgs_score int,
previous_season_bgs_score int,
current_season_powerplay_score int,
previous_season_powerplay_score int,
current_season_aegis_score int,
previous_season_aegis_score int,
foreign key (operation_id) references operations_info(operation_id)
);
create table if not exists squadrons_deleted(
operation_id int,
squad_id int primary key not null,
foreign key (operation_id) references operations_info(operation_id)
);
create table if not exists squadrons_current_data(
squad_id int primary key not null,
name text,
tag text,
owner_id integer,
owner_name text,
platform text,
created text,
created_ts int,
accepting_new_members bool,
power_id int,
power_name text,
superpower_id int,
superpower_name text,
faction_id int,
faction_name text,
delete_after text,
credits_balance int,
credits_in int,
credits_out int,
user_tags text,
member_count int,
online_count int,
pending_count int,
"full" bool,
public_comms bool,
public_comms_override bool,
public_comms_available bool,
current_season_trade_score int,
previous_season_trade_score int,
current_season_combat_score int,
previous_season_combat_score int,
current_season_exploration_score int,
previous_season_exploration_score int,
current_season_cqc_score int,
previous_season_cqc_score int,
current_season_bgs_score int,
previous_season_bgs_score int,
current_season_powerplay_score int,
previous_season_powerplay_score int,
current_season_aegis_score int,
previous_season_aegis_score int,
motd text,
author text,
cmdr_id int,
user_id int,
news_id int,
"date" int,
operation_id int,
updated text,
foreign key (operation_id) references operations_info(operation_id)
);
create trigger if not exists tgr_squadron_deleted
after insert on squadrons_deleted
when (select int_value from settings where key = 'disable_triggers') != 1
begin
delete from squadrons_current_data where squadrons_current_data.squad_id = new.squad_id;
end;
create trigger if not exists tgr_squadron_data_updated
after insert on squadrons_historical_data
when (select int_value from settings where key = 'disable_triggers') != 1
begin
insert into squadrons_current_data (
squad_id,
operation_id,
name,
tag,
owner_id,
owner_name,
platform,
created,
created_ts,
accepting_new_members,
power_id,
power_name,
superpower_id,
superpower_name,
faction_id,
faction_name,
delete_after,
credits_balance,
credits_in,
credits_out,
user_tags,
member_count,
online_count,
pending_count,
"full",
public_comms,
public_comms_override,
public_comms_available,
current_season_trade_score,
previous_season_trade_score,
current_season_combat_score,
previous_season_combat_score,
current_season_exploration_score,
previous_season_exploration_score,
current_season_cqc_score,
previous_season_cqc_score,
current_season_bgs_score,
previous_season_bgs_score,
current_season_powerplay_score,
previous_season_powerplay_score,
current_season_aegis_score,
previous_season_aegis_score,
updated) values (
(select squad_id from operations_info where operations_info.operation_id = new.operation_id),
new.operation_id,
new.name,
new.tag,
new.owner_id,
new.owner_name,
new.platform,
new.created,
new.created_ts,
new.accepting_new_members,
new.power_id,
new.power_name,
new.superpower_id,
new.superpower_name,
new.faction_id,
new.faction_name,
new.delete_after,
new.credits_balance,
new.credits_in,
new.credits_out,
new.user_tags,
new.member_count,
new.online_count,
new.pending_count,
new."full",
new.public_comms,
new.public_comms_override,
new.public_comms_available,
new.current_season_trade_score,
new.previous_season_trade_score,
new.current_season_combat_score,
new.previous_season_combat_score,
new.current_season_exploration_score,
new.previous_season_exploration_score,
new.current_season_cqc_score,
new.previous_season_cqc_score,
new.current_season_bgs_score,
new.previous_season_bgs_score,
new.current_season_powerplay_score,
new.previous_season_powerplay_score,
new.current_season_aegis_score,
new.previous_season_aegis_score,
(select timestamp from operations_info where operations_info.operation_id = new.operation_id)) on conflict do update set
name = new.name,
tag = new.tag,
owner_id = new.owner_id,
owner_name = new.owner_name,
platform = new.platform,
created = new.created,
created_ts = new.created_ts,
accepting_new_members = new.accepting_new_members,
power_id = new.power_id,
power_name = new.power_name,
superpower_id = new.superpower_id,
superpower_name = new.superpower_name,
faction_id = new.faction_id,
faction_name = new.faction_name,
delete_after = new.delete_after,
credits_balance = new.credits_balance,
credits_in = new.credits_in,
credits_out = new.credits_out,
user_tags = new.user_tags,
member_count = new.member_count,
online_count = new.online_count,
pending_count = new.pending_count,
"full" = new."full",
public_comms = new.public_comms,
public_comms_override = new.public_comms_override,
public_comms_available = new.public_comms_available,
current_season_trade_score = new.current_season_trade_score,
previous_season_trade_score = new.previous_season_trade_score,
current_season_combat_score = new.current_season_combat_score,
previous_season_combat_score = new.previous_season_combat_score,
current_season_exploration_score = new.current_season_exploration_score,
previous_season_exploration_score = new.previous_season_exploration_score,
current_season_cqc_score = new.current_season_cqc_score,
previous_season_cqc_score = new.previous_season_cqc_score,
current_season_bgs_score = new.current_season_bgs_score,
previous_season_bgs_score = new.previous_season_bgs_score,
current_season_powerplay_score = new.current_season_powerplay_score,
previous_season_powerplay_score = new.previous_season_powerplay_score,
current_season_aegis_score = new.current_season_aegis_score,
previous_season_aegis_score = new.previous_season_aegis_score;
end;
create trigger if not exists tgr_squadron_news_updated
after insert on squadrons_news_historical
when (select int_value from settings where key = 'disable_triggers') != 1
begin
insert into squadrons_current_data (
motd,
author,
cmdr_id,
user_id,
news_id,
"date",
squad_id,
operation_id,
updated
) values
(
new.motd,
new.author,
new.cmdr_id,
new.user_id,
new.news_id,
new.date,
(select squad_id from operations_info where operations_info.operation_id = new.operation_id),
new.operation_id,
(select timestamp from operations_info where operations_info.operation_id = new.operation_id)
) on conflict do update set
motd = new.motd,
author = new.author,
cmdr_id = new.cmdr_id,
user_id = new.user_id,
news_id = new.news_id,
"date" = new.date;
end;