2 * This program is free software; you can redistribute it and/or modify
3 * it under the terms of the GNU General Public License as published by
4 * the Free Software Foundation; either version 2 of the License, or
5 * (at your option) any later version.
7 * This program is distributed in the hope that it will be useful,
8 * but WITHOUT ANY WARRANTY; without even the implied warranty of
9 * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
10 * GNU General Public License for more details.
12 * You should have received a copy of the GNU General Public License
13 * along with this program; if not, write to the Free Software
14 * Foundation, Inc., 59 Temple Place, Suite 330, Boston, MA 02111-1307 USA
18 *****************************************************************************
20 * Скрипт генерации структуры базы для хранения данных Stargazer-a
22 * $Id: 00-base-00.sql,v 1.7 2010/01/06 14:41:13 faust Exp $
25 * * dm_permission_flag. Представляет собой битовую маску - rw.
26 * r - чтение, w - изменение параметра.
27 * 0 - дествие запрещено, 1 - действие разрешено
29 * * dm_traff_type. Число определяющее тип подсчета трафика:
30 * 0 - up - считается по upload
31 * 1 - down - считается по download
32 * 2 - max - считается по максимальному среди upload/download
33 * 3 - up+down - считается по сумме upload и download
35 * * dm_ip. IP адресс в виде четырех байтового целого числа со знаком.
36 * Выполнять приведение к знаковуму целому при занесении IP в БД!!!
38 * * dm_period. Задает периодичность показа сообщения пользователю.
39 * Период задается целым числом (int16). Если значение равно 0 то
40 * сообщение показывается только при подключении пользователя.
41 * Также этот домен определяет промежуток времени в течении которого
42 * сообщение показывается пользователю.
44 * * dm_session_event_type. Указывает тип записи в логе о сессии.
45 * 'c' - connect, 'd' - disconnect.
47 *****************************************************************************
51 * CONNECT 'localhost:/var/stg/stargazer.fdb' USER 'stg' PASSWORD '123456';
54 * CREATE DATABASE 'localhost:/var/stg/stargazer.fdb' USER 'stg' PASSWORD '123456' DEFAULT CHARACTER SET UTF8;
60 *****************************************************************************
61 * -= Создание ДОМЕНОВ =-
62 *****************************************************************************
65 CREATE DOMAIN dm_id AS INTEGER NOT NULL;
66 CREATE DOMAIN dm_null_id AS INTEGER;
67 CREATE DOMAIN dm_login AS VARCHAR(32) NOT NULL;
68 CREATE DOMAIN dm_tariff_name AS VARCHAR(32) NOT NULL;
69 CREATE DOMAIN dm_group_name AS VARCHAR(32);
70 CREATE DOMAIN dm_corporation_name AS VARCHAR(32);
71 CREATE DOMAIN dm_parameter_name AS VARCHAR(32);
73 CREATE DOMAIN dm_password AS VARCHAR(64) NOT NULL;
74 /* bitmask - rw => Read, Write */
75 CREATE DOMAIN dm_permission_flag AS SMALLINT NOT NULL
76 CHECK ( VALUE BETWEEN 0 AND 3 );
77 CREATE DOMAIN dm_money AS NUMERIC(10,6) NOT NULL;
78 /* (0, 1, 2, 3) => (up, down, max, up+down) */
79 CREATE DOMAIN dm_traff_type AS SMALLINT NOT NULL
80 CHECK ( VALUE BETWEEN 0 AND 3 );
81 CREATE DOMAIN dm_dir_num AS SMALLINT NOT NULL;
82 CREATE DOMAIN dm_num AS SMALLINT NOT NULL;
83 CREATE DOMAIN dm_traffic_mb AS INTEGER NOT NULL;
84 CREATE DOMAIN dm_traffic_byte AS BIGINT NOT NULL;
85 CREATE DOMAIN dm_time AS TIME NOT NULL;
86 CREATE DOMAIN dm_moment AS TIMESTAMP NOT NULL;
87 CREATE DOMAIN dm_credit_moment AS TIMESTAMP;
88 CREATE DOMAIN dm_ip AS INTEGER NOT NULL;
89 CREATE DOMAIN dm_mask AS INTEGER NOT NULL;
90 CREATE DOMAIN dm_user_address AS VARCHAR(256) DEFAULT '';
91 CREATE DOMAIN dm_bool AS CHAR(1) NOT NULL
92 CHECK ( VALUE IN ('0', '1', 't', 'f', 'T', 'F') );
93 CREATE DOMAIN dm_email AS VARCHAR(256) DEFAULT '';
94 CREATE DOMAIN dm_note AS VARCHAR(256) DEFAULT '';
95 CREATE DOMAIN dm_phone AS VARCHAR(256) DEFAULT '';
96 CREATE DOMAIN dm_user_name AS VARCHAR(256) DEFAULT '';
97 CREATE DOMAIN dm_service_comment AS VARCHAR(256) DEFAULT '';
98 CREATE DOMAIN dm_service_name AS VARCHAR(32) DEFAULT '';
100 CREATE DOMAIN dm_pay_day AS SMALLINT NOT NULL
101 CHECK ( VALUE BETWEEN 0 AND 31 );
102 CREATE DOMAIN dm_period AS INTEGER NOT NULL;
103 CREATE DOMAIN dm_counter AS SMALLINT NOT NULL;
105 CREATE DOMAIN dm_message_ver AS INTEGER NOT NULL;
106 CREATE DOMAIN dm_message_type AS INTEGER NOT NULL;
108 CREATE DOMAIN dm_message AS VARCHAR(256) NOT NULL;
109 CREATE DOMAIN dm_user_data AS VARCHAR(256) NOT NULL;
110 CREATE DOMAIN dm_session_event_type AS CHAR(1) NOT NULL
111 CHECK ( VALUE IN ('c', 'd') );
112 CREATE DOMAIN dm_char_value AS VARCHAR(64) NOT NULL;
113 CREATE DOMAIN dm_date AS DATE NOT NULL;
118 *****************************************************************************
119 * -= Создание ТАБЛИЦ =-
120 *****************************************************************************
123 CREATE TABLE tb_admins
125 pk_admin dm_id PRIMARY KEY,
126 login dm_login UNIQUE,
128 chg_conf dm_permission_flag,
129 chg_password dm_permission_flag,
130 chg_stat dm_permission_flag,
131 chg_cash dm_permission_flag,
132 usr_add_del dm_permission_flag,
133 chg_tariff dm_permission_flag,
134 chg_admin dm_permission_flag,
135 chg_service dm_permission_flag,
136 chg_corporation dm_permission_flag
139 CREATE TABLE tb_tariffs
141 pk_tariff dm_id PRIMARY KEY,
142 name dm_tariff_name UNIQUE,
145 passive_cost dm_money,
146 traff_type dm_traff_type
149 CREATE TABLE tb_tariffs_params
151 pk_tariff_param dm_id PRIMARY KEY,
154 price_day_a dm_money,
155 price_day_b dm_money,
156 price_night_a dm_money,
157 price_night_b dm_money,
158 threshold dm_traffic_mb,
159 time_day_begins dm_time,
160 time_day_ends dm_time,
162 FOREIGN KEY (fk_tariff) REFERENCES tb_tariffs (pk_tariff)
165 CREATE TABLE tb_corporations
167 pk_corporation dm_id PRIMARY KEY,
168 name dm_corporation_name UNIQUE,
172 CREATE TABLE tb_users
174 pk_user dm_id PRIMARY KEY,
175 fk_tariff dm_null_id,
176 fk_tariff_change dm_null_id,
177 fk_corporation dm_null_id,
178 address dm_user_address,
179 always_online dm_bool,
181 credit_expire dm_credit_moment,
183 disabled_detail_stat dm_bool,
190 name dm_login UNIQUE,
191 real_name dm_user_name,
193 FOREIGN KEY (fk_tariff) REFERENCES tb_tariffs (pk_tariff),
194 FOREIGN KEY (fk_tariff_change) REFERENCES tb_tariffs (pk_tariff),
195 FOREIGN KEY (fk_corporation) REFERENCES tb_corporations (pk_corporation)
198 CREATE TABLE tb_detail_stats
200 pk_detail_stat dm_id PRIMARY KEY,
204 download dm_traffic_byte,
205 upload dm_traffic_byte,
210 FOREIGN KEY (fk_user) REFERENCES tb_users (pk_user)
213 CREATE TABLE tb_services
215 pk_service dm_id PRIMARY KEY,
216 name dm_service_name UNIQUE,
217 comment dm_service_comment,
222 CREATE TABLE tb_users_services
224 pk_user_service dm_id PRIMARY KEY,
228 FOREIGN KEY (fk_user) REFERENCES tb_users (pk_user),
229 FOREIGN KEY (fk_service) REFERENCES tb_services (pk_service)
232 CREATE TABLE tb_messages
234 pk_message dm_id PRIMARY KEY,
237 msg_type dm_message_type,
238 last_send_time dm_period,
239 creation_time dm_period,
242 repeat_period dm_period,
245 FOREIGN KEY (fk_user) REFERENCES tb_users (pk_user)
248 CREATE TABLE tb_stats
250 pk_stat dm_id PRIMARY KEY,
254 last_activity_time dm_moment,
255 last_cash_add dm_money,
256 last_cash_add_time dm_moment,
257 passive_time dm_period,
260 FOREIGN KEY (fk_user) REFERENCES tb_users (pk_user)
263 CREATE TABLE tb_stats_traffic
265 pk_stat_traffic dm_id PRIMARY KEY,
268 download dm_traffic_byte,
269 upload dm_traffic_byte,
271 FOREIGN KEY (fk_stat) REFERENCES tb_stats (pk_stat)
274 CREATE TABLE tb_users_data
276 pk_user_data dm_id PRIMARY KEY,
281 FOREIGN KEY (fk_user) REFERENCES tb_users (pk_user)
284 CREATE TABLE tb_allowed_ip
286 pk_allowed_ip dm_id PRIMARY KEY,
291 FOREIGN KEY (fk_user) REFERENCES tb_users (pk_user)
294 CREATE TABLE tb_sessions_log
296 pk_session_log dm_id PRIMARY KEY,
298 event_time dm_moment,
299 event_type dm_session_event_type,
302 FOREIGN KEY (fk_user) REFERENCES tb_users (pk_user)
305 CREATE TABLE tb_sessions_data
307 pk_session_data dm_id PRIMARY KEY,
308 fk_session_log dm_id,
310 session_upload dm_traffic_byte,
311 session_download dm_traffic_byte,
312 month_upload dm_traffic_byte,
313 month_download dm_traffic_byte,
315 FOREIGN KEY (fk_session_log) REFERENCES tb_sessions_log (pk_session_log)
318 CREATE TABLE tb_parameters
320 pk_parameter dm_id PRIMARY KEY,
321 name dm_parameter_name UNIQUE
324 CREATE TABLE tb_params_log
326 pk_param_log dm_id PRIMARY KEY,
329 event_time dm_moment,
330 from_val dm_char_value,
331 to_val dm_char_value,
332 comment dm_service_comment,
334 FOREIGN KEY (fk_user) REFERENCES tb_users (pk_user),
335 FOREIGN KEY (fk_parameter) REFERENCES tb_parameters (pk_parameter)
340 *****************************************************************************
341 * -= Создание ИНДЕКСОВ =-
342 *****************************************************************************
348 *****************************************************************************
349 * -= Создание ГЕНЕРАТОРОВ =-
350 *****************************************************************************
353 CREATE GENERATOR gn_pk_admin;
354 SET GENERATOR gn_pk_admin TO 0;
355 CREATE GENERATOR gn_pk_tariff;
356 SET GENERATOR gn_pk_tariff TO 0;
357 CREATE GENERATOR gn_pk_tariff_param;
358 SET GENERATOR gn_pk_tariff_param TO 0;
359 CREATE GENERATOR gn_pk_corporation;
360 SET GENERATOR gn_pk_corporation TO 0;
361 CREATE GENERATOR gn_pk_user;
362 SET GENERATOR gn_pk_user TO 0;
363 CREATE GENERATOR gn_pk_detail_stat;
364 SET GENERATOR gn_pk_detail_stat TO 0;
365 CREATE GENERATOR gn_pk_service;
366 SET GENERATOR gn_pk_service TO 0;
367 CREATE GENERATOR gn_pk_user_service;
368 SET GENERATOR gn_pk_user_service TO 0;
369 CREATE GENERATOR gn_pk_message;
370 SET GENERATOR gn_pk_message TO 0;
371 CREATE GENERATOR gn_pk_stat;
372 SET GENERATOR gn_pk_stat TO 0;
373 CREATE GENERATOR gn_pk_stat_traffic;
374 SET GENERATOR gn_pk_stat_traffic TO 0;
375 CREATE GENERATOR gn_pk_user_data;
376 SET GENERATOR gn_pk_user_data TO 0;
377 CREATE GENERATOR gn_pk_allowed_ip;
378 SET GENERATOR gn_pk_allowed_ip TO 0;
379 CREATE GENERATOR gn_pk_session;
380 SET GENERATOR gn_pk_session TO 0;
381 CREATE GENERATOR gn_pk_session_log;
382 SET GENERATOR gn_pk_session_log TO 0;
383 CREATE GENERATOR gn_pk_session_data;
384 SET GENERATOR gn_pk_session_data TO 0;
385 CREATE GENERATOR gn_pk_parameter;
386 SET GENERATOR gn_pk_parameter TO 0;
387 CREATE GENERATOR gn_pk_param_log;
388 SET GENERATOR gn_pk_param_log TO 0;
392 *****************************************************************************
393 * -= Создание ТРИГГЕРОВ =-
394 *****************************************************************************
398 CREATE TRIGGER tr_admin_bi FOR tb_admins
399 ACTIVE BEFORE INSERT POSITION 0
402 IF (new.pk_admin IS NULL)
403 THEN new.pk_admin = GEN_ID(gn_pk_admin, 1);
408 create trigger tr_tariff_param_bi for tb_tariffs_params active
409 before insert position 0
412 if (new.pk_tariff_param is null)
413 then new.pk_tariff_param = gen_id(gn_pk_tariff_param, 1);
418 create trigger tr_corporation_bi for tb_corporations active
419 before insert position 0
422 if (new.pk_corporation is null)
423 then new.pk_corporation = gen_id(gn_pk_corporation, 1);
428 create trigger tr_detail_stat_bi for tb_detail_stats active
429 before insert position 0
432 if (new.pk_detail_stat is null)
433 then new.pk_detail_stat = gen_id(gn_pk_detail_stat, 1);
438 create trigger tr_service_bi for tb_services active
439 before insert position 0
442 if (new.pk_service is null)
443 then new.pk_service = gen_id(gn_pk_service, 1);
448 create trigger tr_user_service_bi for tb_users_services active
449 before insert position 0
452 if (new.pk_user_service is null)
453 then new.pk_user_service = gen_id(gn_pk_user_service, 1);
458 create trigger tr_stat_traffic_bi for tb_stats_traffic active
459 before insert position 0
462 if (new.pk_stat_traffic is null)
463 then new.pk_stat_traffic = gen_id(gn_pk_stat_traffic, 1);
468 create trigger tr_user_data_bi for tb_users_data active
469 before insert position 0
472 if (new.pk_user_data is null)
473 then new.pk_user_data = gen_id(gn_pk_user_data, 1);
478 create trigger tr_allowed_ip_bi for tb_allowed_ip active
479 before insert position 0
482 if (new.pk_allowed_ip is null)
483 then new.pk_allowed_ip = gen_id(gn_pk_allowed_ip, 1);
488 create trigger tr_session_data_bi for tb_sessions_data active
489 before insert position 0
492 if (new.pk_session_data is null)
493 then new.pk_session_data = gen_id(gn_pk_session_data, 1);
498 create trigger tr_parameter_bi for tb_parameters active
499 before insert position 0
502 if (new.pk_parameter is null)
503 then new.pk_parameter = gen_id(gn_pk_parameter, 1);
508 create trigger tr_param_log_bi for tb_params_log active
509 before insert position 0
512 if (new.pk_param_log is null)
513 then new.pk_param_log = gen_id(gn_pk_param_log, 1);
518 *****************************************************************************
519 * -= Создание stored procedure =-
520 *****************************************************************************
524 * Add a message returning it's ID
527 create procedure sp_add_message(pk_message integer, login varchar(32), ver integer, msg_type integer, last_send_time integer, creation_time integer, show_time integer, repeat integer, repeat_period integer, msg_text varchar(256))
531 if (:pk_message is null) then
533 pk_message = gen_id(gn_pk_message, 1);
534 insert into tb_messages values (:pk_message,
535 (select pk_user from tb_users where name = :login),
547 update tb_messages set fk_user = (select pk_user from tb_users where name = :login),
549 msg_type = :msg_type,
550 last_send_time = :last_send_time,
551 creation_time = :creation_time,
552 show_time = :show_time,
553 repeat = :repeat_period,
554 repeat_period = :repeat_period,
556 where pk_message = :pk_message;
563 create procedure sp_delete_service(name varchar(32))
565 declare variable pk_service integer;
567 select pk_service from tb_services where name = :name into pk_service;
568 if (pk_service is not null) then
570 delete from tb_users_services where fk_service = :pk_service;
571 delete from tb_services where pk_service = :pk_service;
577 create procedure sp_add_tariff(name varchar(32), dirs integer)
579 declare variable pk_tariff integer;
581 pk_tariff = gen_id(gn_pk_tariff, 1);
582 insert into tb_tariffs (pk_tariff, name, fee, free, passive_cost, traff_type) values (:pk_tariff, :name, 0, 0, 0, 0);
585 insert into tb_tariffs_params (fk_tariff, dir_num, price_day_a,
586 price_day_b, price_night_a, price_night_b,
587 threshold, time_day_begins, time_day_ends)
588 values (:pk_tariff, :dirs - 1, 0, 0, 0, 0, 0, '0:0', '0:0');
595 create procedure sp_delete_tariff(name varchar(32))
597 declare variable pk_tariff integer;
599 select pk_tariff from tb_tariffs where name = :name into pk_tariff;
600 if (pk_tariff is not null) then
602 delete from tb_tariffs_params where fk_tariff = :pk_tariff;
603 delete from tb_tariffs where pk_tariff = :pk_tariff;
609 create procedure sp_add_user(name varchar(32), dirs integer)
611 declare variable pk_user integer;
612 declare variable pk_stat integer;
614 pk_user = gen_id(gn_pk_user, 1);
615 insert into tb_users(pk_user, fk_tariff, fk_tariff_change, fk_corporation, address, always_online, credit, credit_expire, disabled, disabled_detail_stat, email, grp, note, passive, passwd, phone, name, real_name) values (:pk_user, NULL, NULL, NULL, '', 0, 0, 'now', 0, 0, '', '_', '', 0, '', '', :name, '');
616 pk_stat = gen_id(gn_pk_stat, 1);
617 insert into tb_stats values (:pk_stat, :pk_user, 0, 0, 'now', 0, 'now', 0, 'now');
620 insert into tb_stats_traffic (fk_stat, dir_num, upload, download) values (:pk_stat, :dirs - 1, 0, 0);
627 create procedure sp_delete_user(name varchar(32))
629 declare variable pk_user integer;
631 select pk_user from tb_users where name = :name into pk_user;
632 if (pk_user is not null) then
634 delete from tb_users_services where fk_user = :pk_user;
635 delete from tb_params_log where fk_user = :pk_user;
636 delete from tb_detail_stats where fk_user = :pk_user;
637 delete from tb_stats_traffic where fk_stat in (select pk_stat from tb_stats where fk_user = :pk_user);
638 delete from tb_stats where fk_user = :pk_user;
639 delete from tb_sessions_data where fk_session_log in (select pk_session_log from tb_sessions_log where fk_user = :pk_user);
640 delete from tb_sessions_log where fk_user = :pk_user;
641 delete from tb_allowed_ip where fk_user = :pk_user;
642 delete from tb_users_data where fk_user = :pk_user;
643 delete from tb_messages where fk_user = :pk_user;
644 delete from tb_users where pk_user = :pk_user;
650 create procedure sp_append_session_log(name varchar(32), event_time timestamp, event_type char(1), ip integer)
651 returns(pk_session_log integer)
654 pk_session_log = gen_id(gn_pk_session_log, 1);
655 insert into tb_sessions_log (pk_session_log, fk_user, event_time, event_type, ip) values (:pk_session_log, (select pk_user from tb_users where name = :name), :event_time, :event_type, :ip);
660 create procedure sp_add_stat(name varchar(32), cash numeric(10,6), free_mb numeric(10,6), last_activity_time timestamp, last_cash_add numeric(10,6), last_cash_add_time timestamp, passive_time integer, stats_date date)
661 returns(pk_stat integer)
664 pk_stat = gen_id(gn_pk_stat, 1);
665 insert into tb_stats (pk_stat, fk_user, cash, free_mb, last_activity_time, last_cash_add, last_cash_add_time, passive_time, stats_date) values (:pk_stat, (select pk_user from tb_users where name = :name), :cash, :free_mb, :last_activity_time, :last_cash_add, :last_cash_add_time, :passive_time, :stats_date);
670 *****************************************************************************
671 * -= Создание администратора =-
672 *****************************************************************************
675 insert into tb_admins values(0, 'admin', 'geahonjehjfofnhammefahbbbfbmpkmkmmefahbbbfbmpkmkmmefahbbbfbmpkmk', 1, 1, 1, 1, 1, 1, 1, 1, 1);