From a8899cd1fc935e679307b06176e9617986ccdb5e Mon Sep 17 00:00:00 2001 From: lazedo Date: Sat, 16 Mar 2019 00:01:27 +0000 Subject: [PATCH] db changes --- kamailio/db_queries_kazoo.cfg | 2 +- .../db_scripts/db_init_watcher_triggers.sql | 14 ++++++ kamailio/db_scripts/db_kazoo-specific | 45 +++++++++++++++---- .../db_scripts/vw_w_keepalive_contact.sql | 8 ++-- 4 files changed, 56 insertions(+), 13 deletions(-) create mode 100644 kamailio/db_scripts/db_init_watcher_triggers.sql diff --git a/kamailio/db_queries_kazoo.cfg b/kamailio/db_queries_kazoo.cfg index 9135825..41f5f4d 100644 --- a/kamailio/db_queries_kazoo.cfg +++ b/kamailio/db_queries_kazoo.cfg @@ -1,6 +1,6 @@ ####### Database queries ######## #!substdef "!KZQ_CHECK_MEDIA_SERVER_INSERT!insert into dispatcher (setid, destination, flags, attrs, description) select \$var(SetId), \"\$var(MediaUrl)\", \$var(flags), \"\$var(attrs)\", \"added by nodes role\" where not exists(select * from dispatcher where destination = \"\$var(MediaUrl)\")!g" -#!substdef "!KZQ_COUNT_ALL_SUBSCRIBERS!select a.event, count(distinct watcher_username || \"@\" || watcher_domain) count_unique, count(*) count from event_list a, active_watchers b where b.event = a.event group by a.event!g" +#!substdef "!KZQ_COUNT_ALL_SUBSCRIBERS!select a.event, count(distinct watcher_uri) count_unique, count(*) count from event_list a left outer join active_watchers b on a.event = b.event group by a.event!g" #!substdef "!KZQ_COUNT_PRESENTITIES!select event, (select count(*) from presentity b where username = \"\$(var(payload){kz.json,From}{uri.user})\" and domain = \"\$(var(payload){kz.json,From}{uri.domain})\" and b.event = a.event) count from event_list a!g" #!substdef "!KZQ_COUNT_SUBSCRIBERS!select event, (select count(*) from active_watchers b where presentity_uri = \"\$var(presentity)\" and b.event = a.event) count from event_list a union select \"self\", count(distinct callid) from presentities where presentity_uri = \"\$var(presentity)\" and state in('early', 'confirmed', 'onthephone', 'busy')!g" diff --git a/kamailio/db_scripts/db_init_watcher_triggers.sql b/kamailio/db_scripts/db_init_watcher_triggers.sql new file mode 100644 index 0000000..8e5a202 --- /dev/null +++ b/kamailio/db_scripts/db_init_watcher_triggers.sql @@ -0,0 +1,14 @@ +CREATE TRIGGER if not exists active_watchers_watcher_uri_insert +AFTER INSERT ON active_watchers +FOR EACH ROW +BEGIN + UPDATE active_watchers SET watcher_uri = "sip:" || NEW.watcher_username || "@" || NEW.watcher_domain where id = NEW.id; +END; + +CREATE TRIGGER if not exists active_watchers_watcher_uri_update +AFTER UPDATE ON active_watchers +FOR EACH ROW +WHEN OLD.watcher_username <> NEW.watcher_username OR OLD.watcher_domain <> NEW.watcher_domain +BEGIN + UPDATE active_watchers SET watcher_uri = "sip:" || NEW.watcher_username || "@" || NEW.watcher_domain where id = NEW.id; +END; diff --git a/kamailio/db_scripts/db_kazoo-specific b/kamailio/db_scripts/db_kazoo-specific index c67b5ca..800bb26 100644 --- a/kamailio/db_scripts/db_kazoo-specific +++ b/kamailio/db_scripts/db_kazoo-specific @@ -46,6 +46,7 @@ INSERT INTO version (table_name, table_version) values ('active_watchers_log','1 CREATE TABLE keepalive ( id INTEGER PRIMARY KEY NOT NULL, contact VARCHAR(2048) NOT NULL COLLATE NOCASE, + received VARCHAR(32) NOT NULL COLLATE NOCASE, sockinfo VARCHAR(128) NOT NULL COLLATE NOCASE, time_inserted timestamp DEFAULT CURRENT_TIMESTAMP, time_sent timestamp DEFAULT CURRENT_TIMESTAMP, @@ -53,17 +54,45 @@ CREATE TABLE keepalive ( selected INTEGER DEFAULT 0, failed INTEGER DEFAULT 0, CONSTRAINT keepalive_idx UNIQUE (contact), - CONSTRAINT keepalive_idx_2 UNIQUE (slot, selected, time_sent, contact) - CONSTRAINT keepalive_idx_3 UNIQUE (slot, failed, contact) + CONSTRAINT keepalive_idx_2 UNIQUE (slot, failed, contact) ); - -INSERT INTO version (table_name, table_version) values ('keepalive','3'); + +CREATE INDEX keepalive_idx_3 ON keepalive (slot, selected, time_sent); +CREATE INDEX keepalive_idx_4 ON keepalive (received, selected); + +INSERT INTO version (table_name, table_version) values ('keepalive','4'); + +ALTER TABLE active_watchers ADD COLUMN watcher_uri varchar(64) NOT NULL DEFAULT "sip:no_watcher@no_domain"; + +CREATE TRIGGER active_watchers_watcher_uri_insert +AFTER INSERT ON active_watchers +FOR EACH ROW +BEGIN + UPDATE active_watchers SET watcher_uri = "sip:" || NEW.watcher_username || "@" || NEW.watcher_domain where id = NEW.id; +END; + +CREATE TRIGGER active_watchers_watcher_uri_update +AFTER UPDATE ON active_watchers +FOR EACH ROW +WHEN OLD.watcher_username <> NEW.watcher_username OR OLD.watcher_domain <> NEW.watcher_domain +BEGIN + UPDATE active_watchers SET watcher_uri = "sip:" || NEW.watcher_username || "@" || NEW.watcher_domain where id = NEW.id; +END; CREATE UNIQUE INDEX active_watchers_contact ON active_watchers (contact, id); +CREATE INDEX active_watchers_event_watcher_uri ON active_watchers (event, watcher_uri); + + +CREATE INDEX location_attrs_ruid ON location_attrs (ruid); +CREATE UNIQUE INDEX location_ruid ON location (ruid); create table auth_cache as select * from htable; INSERT INTO version (table_name, table_version) select 'auth_cache', table_version from version where table_name = 'htable'; +create table block_cache as select * from htable; +INSERT INTO version (table_name, table_version) select 'block_cache', table_version from version where table_name = 'htable'; + + create view presentities as select id, cast(printf("sip:%s@%s",username,domain) as varchar(64)) presentity_uri , username, domain, event, cast(substr(etag, instr(etag,"@")+1) as varchar(64)) callid, datetime(received_time, 'unixepoch') as received, @@ -94,10 +123,10 @@ INSERT INTO version (table_name, table_version) select 'auth_cache', table_versi CREATE VIEW w_keepalive_contact as -SELECT id, slot, failed, case when instr(contact,";") > 0 - then substr(contact, 1, instr(contact,";")-1) - else contact - end as contact +SELECT id, slot, selected, failed, case when instr(contact,";") > 0 + then substr(contact, 1, instr(contact,";")-1) + else contact + end as contact from keepalive; CREATE VIEW w_location_contact as diff --git a/kamailio/db_scripts/vw_w_keepalive_contact.sql b/kamailio/db_scripts/vw_w_keepalive_contact.sql index ce12ec5..1639650 100644 --- a/kamailio/db_scripts/vw_w_keepalive_contact.sql +++ b/kamailio/db_scripts/vw_w_keepalive_contact.sql @@ -1,6 +1,6 @@ CREATE VIEW w_keepalive_contact as - select id, slot, failed, case when instr(contact,";") > 0 - then substr(contact, 1, instr(contact,";")-1) - else contact - end as contact + select id, slot, selected, failed, case when instr(contact,";") > 0 + then substr(contact, 1, instr(contact,";")-1) + else contact + end as contact from keepalive