447 lines
13 KiB
SQL
Executable File
447 lines
13 KiB
SQL
Executable File
create database if not exists KStats character set utf8mb4 collate utf8mb4_general_ci;
|
|
use KStats;
|
|
|
|
delimiter ;^
|
|
|
|
drop procedure if exists tables_remove;^
|
|
create procedure tables_remove() begin
|
|
|
|
-- Level 2.
|
|
drop table if exists SessionsUrls;
|
|
|
|
-- Level 1.
|
|
drop table if exists Sessions;
|
|
drop table if exists IpsData;
|
|
|
|
-- Level 0.
|
|
drop table if exists Urls;
|
|
drop table if exists Ips;
|
|
drop table if exists Tokens;
|
|
drop table if exists Settings;
|
|
|
|
end;^
|
|
|
|
drop procedure if exists tables_create;^
|
|
create procedure tables_create() begin
|
|
|
|
-- Level 0.
|
|
create table if not exists Ips(
|
|
id integer not null auto_increment,
|
|
address varchar(39) not null,
|
|
date_in datetime not null default now(),
|
|
date_out datetime,
|
|
constraint ips_id primary key(id)
|
|
);
|
|
|
|
create table if not exists Urls(
|
|
id integer not null auto_increment,
|
|
url varchar(2048) not null,
|
|
date_in datetime not null default now(),
|
|
date_out datetime,
|
|
constraint urls_id primary key(id)
|
|
);
|
|
|
|
create table if not exists Tokens(
|
|
id integer not null auto_increment,
|
|
token varchar(256) not null,
|
|
enabled boolean not null default true,
|
|
pattern varchar(2048),
|
|
public boolean not null,
|
|
remarks varchar(2048),
|
|
date_in datetime not null default now(),
|
|
date_out datetime,
|
|
constraint tokens_id primary key(id)
|
|
);
|
|
|
|
create table if not exists Settings(
|
|
id integer not null auto_increment,
|
|
name varchar(32) not null,
|
|
value varchar(256),
|
|
date_in datetime not null default now(),
|
|
date_out datetime,
|
|
constraint settings_id primary key(id)
|
|
);
|
|
|
|
create table if not exists Countries(
|
|
id integer not null auto_increment,
|
|
name varchar(128),
|
|
code varchar(16),
|
|
date_in datetime not null default now(),
|
|
date_out datetime,
|
|
constraint countries_id primary key(id)
|
|
);
|
|
|
|
create table if not exists Isps(
|
|
id integer not null auto_increment,
|
|
name varchar(256),
|
|
date_in datetime not null default now(),
|
|
date_out datetime,
|
|
constraint countries_id primary key(id)
|
|
);
|
|
|
|
-- Level 1.
|
|
create table if not exists Sessions(
|
|
id integer not null auto_increment,
|
|
ip integer not null,
|
|
date_in datetime not null default now(),
|
|
date_last datetime not null default now(),
|
|
date_out datetime,
|
|
constraint sessions_id primary key(id),
|
|
constraint sessions_ip foreign key(ip) references Ips(id)
|
|
);
|
|
|
|
create table if not exists IpsData(
|
|
id integer not null auto_increment,
|
|
ip integer not null,
|
|
country integer not null,
|
|
isp integer,
|
|
latitude decimal(9, 6),
|
|
longitude decimal(9, 6),
|
|
`data` text not null,
|
|
date_in datetime not null default now(),
|
|
date_out datetime,
|
|
constraint ips_data_id primary key(id),
|
|
constraint ips_data_ip foreign key(ip) references Ips(id),
|
|
constraint ips_data_country foreign key(country) references Countries(id),
|
|
constraint ips_data_isp foreign key(isp) references Isps(id)
|
|
);
|
|
|
|
-- Level 2.
|
|
create table if not exists SessionsUrls(
|
|
id integer not null auto_increment,
|
|
`session` integer not null,
|
|
token integer not null,
|
|
url integer not null,
|
|
date_in datetime not null default now(),
|
|
date_last datetime not null default now(),
|
|
date_out datetime,
|
|
constraint sessions_urls_id primary key(id),
|
|
constraint sessions_urls_session foreign key(`session`) references Sessions(id),
|
|
constraint sessions_urls_token foreign key(token) references Tokens(id),
|
|
constraint sessions_urls_url foreign key(url) references Urls(id)
|
|
);
|
|
|
|
end;^
|
|
|
|
drop procedure if exists tables_update;^
|
|
create procedure tables_update() begin
|
|
|
|
if (select 1 from information_schema.columns where table_schema = 'KStats' && table_name = 'Tokens' && column_name = 'enabled' limit 1) is null then
|
|
alter table Tokens add column enabled boolean not null default true;
|
|
end if;
|
|
if (select 1 from information_schema.columns where table_schema = 'KStats' && table_name = 'Tokens' && column_name = 'pattern' limit 1) is null then
|
|
alter table Tokens add column pattern varchar(2048);
|
|
end if;
|
|
if (select 1 from information_schema.columns where table_schema = 'KStats' && table_name = 'Tokens' && column_name = 'public' limit 1) is null then
|
|
alter table Tokens add column public boolean not null;
|
|
end if;
|
|
if (select 1 from information_schema.columns where table_schema = 'KStats' && table_name = 'Tokens' && column_name = 'remarks' limit 1) is null then
|
|
alter table Tokens add column remarks varchar(2048);
|
|
end if;
|
|
if (select 1 from information_schema.columns where table_schema = 'KStats' && table_name = 'SessionsUrls' && column_name = 'date_last' limit 1) is null then
|
|
alter table SessionsUrls add column date_last datetime not null default now();
|
|
end if;
|
|
|
|
end;^
|
|
|
|
drop procedure if exists tables_fill;^
|
|
create procedure tables_fill() begin
|
|
|
|
drop temporary table if exists KStatsTTSettings;
|
|
create temporary table KStatsTTSettings(
|
|
id integer not null auto_increment,
|
|
name varchar(32) not null,
|
|
value varchar(256),
|
|
date_in datetime not null default now(),
|
|
primary key(id)
|
|
);
|
|
|
|
insert into KStatsTTSettings(name, value) values
|
|
('token_alphabet', '123456789ABCDEFGHJKLMNPQRSTUVWXYZabcdefghijkmnopqrstuvwxyz'),
|
|
('token_length', 57),
|
|
('default_value', null),
|
|
('session_timeout', 900);
|
|
|
|
insert into Settings(name, value)
|
|
select name, value from KStatsTTSettings where name not in (
|
|
select name from Settings where date_out is null
|
|
);
|
|
|
|
drop temporary table KStatsTTSettings;
|
|
|
|
end;^
|
|
|
|
-- call tables_remove();^
|
|
call tables_create();^
|
|
call tables_update();^
|
|
call tables_fill();^
|
|
|
|
drop function if exists settings_get;^
|
|
create function settings_get(
|
|
$name varchar(32)
|
|
) returns varchar(256) begin
|
|
return ifnull(
|
|
(select value from Settings where date_out is null && name = $name limit 1),
|
|
(select value from Settings where date_out is null && name in ('default_value', 'value') limit 1)
|
|
);
|
|
end;^
|
|
|
|
drop function if exists settings_get_integer;^
|
|
create function settings_get_integer(
|
|
$name varchar(32)
|
|
) returns integer begin
|
|
return convert(settings_get($name), integer);
|
|
end;^
|
|
|
|
drop procedure if exists token_create;^
|
|
create procedure token_create(
|
|
in $public boolean,
|
|
in $pattern varchar(2048),
|
|
in $remarks varchar(2048),
|
|
out $error bigint,
|
|
out $id integer,
|
|
out $token varchar(256)
|
|
) begin
|
|
|
|
set $id := 0;
|
|
set $error := (
|
|
(case
|
|
when $public is null then 1 << 1
|
|
else 0 end) |
|
|
/*(case
|
|
when $pattern is null then 1 << 2
|
|
when $pattern = '' then 1 << 3
|
|
else 0 end) |
|
|
(case
|
|
when $remarks is null then 1 << 4
|
|
when $remarks = '' then 1 << 5
|
|
else 0 end) |*/
|
|
0
|
|
);
|
|
|
|
if !$error then begin
|
|
|
|
declare $alphabet varchar(256) default settings_get('token_alphabet');
|
|
declare `$length` integer default settings_get_integer('token_length');
|
|
declare $l integer default length($alphabet);
|
|
|
|
while $token is null || (select 1 from Tokens where date_out is null && token = $token limit 1) is not null do
|
|
set $token := '';
|
|
while length($token) < `$length` do
|
|
set $token := concat($token, substring($alphabet, floor(rand() * $l) + 1, 1));
|
|
end while;
|
|
end while;
|
|
|
|
insert into Tokens(token, public, pattern, remarks) values($token, $public, $pattern, $remarks);
|
|
set $id := last_insert_id();
|
|
|
|
end;end if;
|
|
|
|
end;^
|
|
|
|
drop procedure if exists ips_get;^
|
|
create procedure ips_get(
|
|
in $ip varchar(39),
|
|
out $error bigint,
|
|
out $id integer
|
|
) begin
|
|
|
|
set $error := (case
|
|
when $ip is null then 1 << 1
|
|
when $ip = '' then 1 << 2
|
|
-- when $ip not regexp '^[0-9]{1,3}(\.[0-9]{1,3}){0,3}$' then 1 << 3
|
|
else 0 end);
|
|
|
|
if !$error then begin
|
|
|
|
set $id := (select id from Ips where date_out is null && address = $ip limit 1);
|
|
|
|
if $id is null then begin
|
|
insert into Ips(address) values($ip);
|
|
set $id := last_insert_id();
|
|
end;end if;
|
|
|
|
end;end if;
|
|
|
|
end;^
|
|
|
|
drop procedure if exists urls_get;^
|
|
create procedure urls_get(
|
|
in $url varchar(2048),
|
|
out $error bigint,
|
|
out $id integer
|
|
) begin
|
|
|
|
set $error := (case
|
|
when $url is null then 1 << 1
|
|
when $url = '' then 1 << 2
|
|
else 0 end);
|
|
|
|
if !$error then begin
|
|
|
|
set $id := (select id from Urls where date_out is null && url = $url limit 1);
|
|
|
|
if $id is null then begin
|
|
insert into Urls(url) values($url);
|
|
set $id := last_insert_id();
|
|
end;end if;
|
|
|
|
end;end if;
|
|
|
|
end;^
|
|
|
|
drop function if exists token_get;^
|
|
create function token_get(
|
|
$token varchar(256)
|
|
) returns boolean begin
|
|
return (select id from Tokens where date_out is null && token = $token);
|
|
end;^
|
|
|
|
/*drop function if exists token_validate;^
|
|
create function token_validate(
|
|
$token varchar(256),
|
|
$url varchar(2048)
|
|
) returns bigint begin
|
|
return (case
|
|
when $token is null then 1 << 0
|
|
when $token = '' then 1 << 1'Token for YoutubeSoundsGame project.'
|
|
when $token regexp '^[0-9]+$' && convert(integer, $token) < 1 then 1 << 2
|
|
else ifnull((
|
|
select (
|
|
if(enabled, 0, 1 << 4) |
|
|
if(pattern regexp (select url from Urls where date_out is null && (concat('', id) = $url || url = $url) limit 1), 0, 1 << 5) |
|
|
0
|
|
) from Tokens where date_out is null && (concat('', id) = $token || token = $token) limit 1
|
|
), 1 << 3) end);
|
|
end;^*/
|
|
|
|
drop function if exists token_validate;^
|
|
create function token_validate(
|
|
$token integer,
|
|
$url varchar(2048)
|
|
) returns bigint begin
|
|
return (case
|
|
when $token is null then 1 << 0
|
|
when $token < 1 then 1 << 2
|
|
else ifnull((
|
|
select (
|
|
if(enabled, 0, 1 << 4) |
|
|
if(pattern is null || $url regexp pattern, 0, 1 << 5) |
|
|
if(public, 0, 1 << 6) |
|
|
0
|
|
) from Tokens where date_out is null && id = $token limit 1
|
|
), 1 << 3) end);
|
|
end;^
|
|
|
|
drop function if exists session_url_validate;^
|
|
create function session_url_validate(
|
|
`$session` integer,
|
|
$id integer
|
|
) returns bigint begin
|
|
return if(`$session` is null, 1 << 0, (case
|
|
when $id is null then 1 << 1
|
|
when $id < 1 then 1 << 2
|
|
else ifnull((
|
|
select (
|
|
if(date_out is null, 0, 1 << 4) |
|
|
if(`session` = `$session`, 0, 1 << 5) |
|
|
0
|
|
) from SessionsUrls where id = $id limit 1
|
|
), 1 << 3) end));
|
|
end;^
|
|
|
|
drop procedure if exists register;^
|
|
create procedure register(
|
|
in `$session` integer,
|
|
in `$from` integer,
|
|
in $token varchar(256),
|
|
in $ip varchar(39),
|
|
in $url varchar(2048),
|
|
out $error bigint,
|
|
out $current_session integer,
|
|
out $id integer
|
|
) begin
|
|
|
|
declare $ip_id integer;
|
|
declare $ip_error bigint;
|
|
declare $url_id integer;
|
|
declare $url_error bigint;
|
|
declare $token_id integer default token_get($token);
|
|
|
|
call ips_get($ip, $ip_error, $ip_id);
|
|
call urls_get($url, $url_error, $url_id);
|
|
|
|
set $error := (
|
|
($ip_error << 1) |
|
|
($url_error << 5) |
|
|
(token_validate($token_id, $url) << 8) |
|
|
0
|
|
);
|
|
|
|
if !$error then begin
|
|
|
|
if `$session` is null || (select 1 from Sessions where id = `$session` && date_out is null && ip = $ip_id && timestampdiff(second, now(), date_last) > settings_get_integer('session_timeout')) then begin
|
|
insert into Sessions(ip) values($ip_id);
|
|
set `$session` := last_insert_id();
|
|
end;else
|
|
update Sessions set date_last := now() where id = `$session`;
|
|
end if;
|
|
set $current_session := `$session`;
|
|
|
|
if `$from` is not null then begin
|
|
set $error := (
|
|
(session_url_validate(`$session`, `$from`) << 15) |
|
|
0
|
|
);
|
|
if !$error then begin
|
|
set $id := `$from`;
|
|
update SessionsUrls set date_last := now() where id = $id;
|
|
end;end if;
|
|
end;else
|
|
insert into SessionsUrls(`session`, token, url) values(`$session`, $token_id, $url_id);
|
|
set $id := last_insert_id();
|
|
end if;
|
|
|
|
end;end if;
|
|
|
|
end;^
|
|
|
|
drop view if exists SessionsView;^
|
|
create view SessionsView as select
|
|
sessions.id as id,
|
|
sessions.ip as ip_id,
|
|
ips.address as ip,
|
|
sessions.date_in as date_in,
|
|
sessions.date_last as date_last,
|
|
sessions.date_out as date_out,
|
|
timestampdiff(second, sessions.date_in, ifnull(sessions.date_out, sessions.date_last)) as `time`,
|
|
ips.date_in as ip_date_in
|
|
from Sessions sessions
|
|
join Ips ips on sessions.ip = ips.id
|
|
where ips.date_out is null;^
|
|
|
|
drop view if exists SessionsUrlsView;^
|
|
create view SessionsUrlsView as select
|
|
sessions_urls.id as id,
|
|
sessions.id as session_id,
|
|
sessions.ip_id as ip_id,
|
|
sessions.ip as ip,
|
|
urls.id as url_id,
|
|
urls.url as url,
|
|
sessions_urls.date_in as date_in,
|
|
sessions_urls.date_last as date_last,
|
|
timestampdiff(second, sessions_urls.date_in, sessions_urls.date_last) as `time`,
|
|
sessions.date_in as session_date_in,
|
|
sessions.date_last as session_date_last,
|
|
sessions.date_out as session_date_out,
|
|
sessions.ip_date_in as ip_date_in,
|
|
sessions.`time` as session_time,
|
|
urls.date_in as url_date_in
|
|
from SessionsUrls sessions_urls
|
|
join SessionsView sessions on sessions_urls.`session` = sessions.id
|
|
join Urls urls on sessions_urls.url = urls.id
|
|
where
|
|
sessions_urls.date_out is null &&
|
|
urls.date_out is null;^
|
|
|
|
delimiter ; |