317 lines
10 KiB
SQL

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
);
create index if not exists idx_oi_squad_id on operations_info(squad_id);
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 text,
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 text,
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
updated = (select timestamp from operations_info where operations_info.operation_id = new.operation_id),
operation_id = new.operation_id,
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
updated = (select timestamp from operations_info where operations_info.operation_id = new.operation_id),
operation_id = new.operation_id,
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;
create index if not exists idx_snh_operation_id_desc on squadrons_news_historical (operation_id desc);