Initial db-schema package

This is broken as hell. You've been warned.

From: Michael Prokop <mprokop@sipwise.com>
0.1
Michael Prokop 13 years ago
commit 30ceca8ca7

@ -0,0 +1,750 @@
-- step out of our billing DB
USE mysql;
-- drop database if it allready exists
-- this will drop all tables and triggers
DROP DATABASE IF EXISTS billing;
-- create DB with utf8 default charset, so we don't have to
-- specify charset for each table
CREATE DATABASE billing CHARACTER SET 'utf8';
USE billing;
-- create reseller helper table
CREATE TABLE `resellers` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`contract_id` int(11) UNSIGNED NOT NULL REFERENCES `contracts` (`id`),
`name` varchar(63) NOT NULL,
`status` enum('active','locked','terminated') NOT NULL DEFAULT 'active',
PRIMARY KEY (`id`),
UNIQUE KEY `contractid_idx` (`contract_id`),
UNIQUE KEY `name_idx` (`name`)
) ENGINE=InnoDB;
-- create domains and reseller mapping tables
CREATE TABLE `domains` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`domain` varchar(127) NOT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `domain_idx` (`domain`)
) ENGINE=InnoDB;
CREATE TABLE `domain_resellers` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`domain_id` int(11) UNSIGNED NOT NULL REFERENCES `domains` (`id`),
`reseller_id` int(11) UNSIGNED NOT NULL REFERENCES `resellers` (`id`),
PRIMARY KEY (`id`),
KEY `domainid_idx` (`domain_id`),
CONSTRAINT `dr_domainid_ref` FOREIGN KEY (`domain_id`)
REFERENCES `domains` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `resellerid_idx` (`reseller_id`),
CONSTRAINT `dr_resellerid_ref` FOREIGN KEY (`reseller_id`)
REFERENCES `resellers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- create admins table that contains root user as well as reseller admins
CREATE TABLE `admins` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`reseller_id` int(11) UNSIGNED NULL REFERENCES `resellers` (`id`),
`login` varchar(31) NOT NULL,
`md5pass` char(32),
`is_master` boolean NOT NULL default FALSE,
`is_superuser` boolean NOT NULL default FALSE,
`is_active` boolean NOT NULL default TRUE,
`read_only` boolean NOT NULL default FALSE,
`show_passwords` boolean NOT NULL default TRUE,
`call_data` boolean NOT NULL default FALSE,
`lawful_intercept` boolean NOT NULL default FALSE,
PRIMARY KEY (`id`),
UNIQUE KEY `login_idx` (`login`),
KEY `resellerid_idx` (`reseller_id`),
CONSTRAINT `a_resellerid_ref` FOREIGN KEY (`reseller_id`)
REFERENCES `resellers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- create billing tables
CREATE TABLE `billing_profiles` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`reseller_id` int(11) UNSIGNED NULL REFERENCES `resellers` (`id`),
`handle` varchar(63) NOT NULL,
`name` varchar(31) NOT NULL,
`prepaid` bool NOT NULL DEFAULT FALSE,
`interval_charge` double NOT NULL DEFAULT 0,
`interval_free_time` int(5) NOT NULL DEFAULT 0,
`interval_free_cash` double NOT NULL DEFAULT 0,
`interval_unit` enum('week','month') NOT NULL DEFAULT 'month',
`interval_count` tinyint(3) UNSIGNED NOT NULL DEFAULT 1,
`fraud_interval_limit` int(11) UNSIGNED NULL DEFAULT NULL,
`fraud_interval_lock` tinyint(3) UNSIGNED NOT NULL DEFAULT 0,
`fraud_interval_notify` varchar(255) NULL DEFAULT NULL,
`currency` varchar(31) NULL DEFAULT NULL,
`vat_rate` tinyint(3) UNSIGNED NULL DEFAULT NULL,
`vat_included` bool NOT NULL DEFAULT TRUE,
PRIMARY KEY (`id`),
UNIQUE KEY `resnam_idx` (`reseller_id`, `name`),
UNIQUE KEY `reshand_idx` (`reseller_id`, `handle`),
KEY `resellerid_idx` (`reseller_id`),
CONSTRAINT `b_p_resellerid_ref` FOREIGN KEY (`reseller_id`)
REFERENCES `resellers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `billing_zones` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`billing_profile_id` int(11) UNSIGNED NOT NULL REFERENCES `billing_profiles` (`id`),
`zone` varchar(127) NOT NULL, -- a zone name for internal use: admin interface, etc.
`detail` varchar(127) NULL, -- will be printed on invoices, etc.
PRIMARY KEY (`id`),
UNIQUE KEY `profnamdes_idx` (`billing_profile_id`, `zone`, `detail`),
CONSTRAINT `b_z_profileid_ref` FOREIGN KEY (`billing_profile_id`)
REFERENCES `billing_profiles` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `billing_zones_history` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`bz_id` int(11) UNSIGNED,
`billing_profile_id` int(11) UNSIGNED NOT NULL,
`zone` varchar(127) NOT NULL,
`detail` varchar(127) NULL,
PRIMARY KEY (`id`),
KEY `bzid_idx` (`bz_id`),
CONSTRAINT `b_z_h_bzid_ref` FOREIGN KEY (`bz_id`)
REFERENCES `billing_zones` (`id`)
ON DELETE SET NULL ON UPDATE NO ACTION
) ENGINE=InnoDB;
DELIMITER |
CREATE TRIGGER bill_zones_crepl_trig AFTER INSERT ON billing_zones
FOR EACH ROW BEGIN
INSERT INTO billing_zones_history
VALUES(NULL, NEW.id, NEW.billing_profile_id, NEW.zone, NEW.detail);
END;
|
CREATE TRIGGER bill_zones_urepl_trig AFTER UPDATE ON billing_zones
FOR EACH ROW BEGIN
UPDATE billing_zones_history
SET bz_id = NEW.id, billing_profile_id = NEW.billing_profile_id,
zone = NEW.zone, detail = NEW.detail
WHERE bz_id = OLD.id;
END;
|
DELIMITER ;
CREATE TABLE `billing_fees` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`billing_profile_id` int(11) UNSIGNED NOT NULL REFERENCES `billing_profiles` (`id`),
`billing_zone_id` int(11) UNSIGNED NULL REFERENCES `billing_zones` (`id`),
`destination` varchar(255) NOT NULL,
`type` enum('call', 'sms') NOT NULL DEFAULT 'call',
`onpeak_init_rate` double NOT NULL DEFAULT 0,
`onpeak_init_interval` int(5) UNSIGNED NOT NULL DEFAULT 0,
`onpeak_follow_rate` double NOT NULL DEFAULT 0,
`onpeak_follow_interval` int(5) UNSIGNED NOT NULL DEFAULT 0,
`offpeak_init_rate` double NOT NULL DEFAULT 0,
`offpeak_init_interval` int(5) UNSIGNED NOT NULL DEFAULT 0,
`offpeak_follow_rate` double NOT NULL DEFAULT 0,
`offpeak_follow_interval` int(5) UNSIGNED NOT NULL DEFAULT 0,
`use_free_time` bool NOT NULL DEFAULT FALSE,
PRIMARY KEY (`id`),
KEY `profileid_idx` (`billing_profile_id`),
CONSTRAINT `b_f_bilprofid_ref` FOREIGN KEY (`billing_profile_id`)
REFERENCES `billing_profiles` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `zoneid_idx` (`billing_zone_id`),
CONSTRAINT `b_f_zoneid_ref` FOREIGN KEY (`billing_zone_id`)
REFERENCES `billing_zones` (`id`)
ON DELETE RESTRICT ON UPDATE CASCADE,
UNIQUE KEY `profdestype_idx` (`billing_profile_id`, `destination`, `type`)
) ENGINE=InnoDB;
CREATE TABLE `billing_fees_history` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`bf_id` int(11) UNSIGNED,
`billing_profile_id` int(11) UNSIGNED NOT NULL,
`billing_zones_history_id` int(11) UNSIGNED NULL,
`destination` varchar(255) NOT NULL,
`type` enum('call', 'sms') NOT NULL DEFAULT 'call',
`onpeak_init_rate` double NOT NULL DEFAULT 0,
`onpeak_init_interval` int(5) UNSIGNED NOT NULL DEFAULT 0,
`onpeak_follow_rate` double NOT NULL DEFAULT 0,
`onpeak_follow_interval` int(5) UNSIGNED NOT NULL DEFAULT 0,
`offpeak_init_rate` double NOT NULL DEFAULT 0,
`offpeak_init_interval` int(5) UNSIGNED NOT NULL DEFAULT 0,
`offpeak_follow_rate` double NOT NULL DEFAULT 0,
`offpeak_follow_interval` int(5) UNSIGNED NOT NULL DEFAULT 0,
`use_free_time` bool NOT NULL DEFAULT FALSE,
PRIMARY KEY (`id`),
KEY `bfid_idx` (`bf_id`),
CONSTRAINT `b_f_h_bfid_ref` FOREIGN KEY (`bf_id`)
REFERENCES `billing_fees` (`id`)
ON DELETE SET NULL ON UPDATE NO ACTION,
KEY `zonehid_idx` (`billing_zones_history_id`),
CONSTRAINT `b_f_h_bzhid_ref` FOREIGN KEY (`billing_zones_history_id`)
REFERENCES `billing_zones_history` (`id`)
ON DELETE RESTRICT ON UPDATE CASCADE
) ENGINE=InnoDB;
DELIMITER |
CREATE TRIGGER bill_fees_crepl_trig AFTER INSERT ON billing_fees
FOR EACH ROW BEGIN
DECLARE my_bzh_id int UNSIGNED;
SELECT id INTO my_bzh_id FROM billing_zones_history WHERE bz_id = NEW.billing_zone_id;
INSERT INTO billing_fees_history
VALUES(NULL, NEW.id, NEW.billing_profile_id, my_bzh_id, NEW.destination,
NEW.type, NEW.onpeak_init_rate, NEW.onpeak_init_interval, NEW.onpeak_follow_rate,
NEW.onpeak_follow_interval, NEW.offpeak_init_rate, NEW.offpeak_init_interval,
NEW.offpeak_follow_rate, NEW.offpeak_follow_interval, NEW.use_free_time);
END;
|
CREATE TRIGGER bill_fees_urepl_trig AFTER UPDATE ON billing_fees
FOR EACH ROW BEGIN
DECLARE my_bzh_id int UNSIGNED;
SELECT id INTO my_bzh_id FROM billing_zones_history WHERE bz_id = NEW.billing_zone_id;
UPDATE billing_fees_history
SET bf_id = NEW.id, billing_profile_id = NEW.billing_profile_id,
billing_zones_history_id = my_bzh_id, destination = NEW.destination, type = NEW.type,
onpeak_init_rate = NEW.onpeak_init_rate, onpeak_init_interval = NEW.onpeak_init_interval,
onpeak_follow_rate = NEW.onpeak_follow_rate, onpeak_follow_interval = NEW.onpeak_follow_interval,
offpeak_init_rate = NEW.offpeak_init_rate, offpeak_init_interval = NEW.offpeak_init_interval,
offpeak_follow_rate = NEW.offpeak_follow_rate, offpeak_follow_interval = NEW.offpeak_follow_interval,
use_free_time = NEW.use_free_time
WHERE bf_id = OLD.id;
END;
|
DELIMITER ;
CREATE TABLE `billing_peaktime_weekdays` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`billing_profile_id` int(11) UNSIGNED NOT NULL REFERENCES `billing_profiles` (`id`),
`weekday` tinyint(3) UNSIGNED NOT NULL,
`start` time,
`end` time,
PRIMARY KEY (`id`),
KEY `profileid_idx` (`billing_profile_id`),
CONSTRAINT `b_p_w_bilprofid_ref` FOREIGN KEY (`billing_profile_id`)
REFERENCES `billing_profiles` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `billing_peaktime_special` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`billing_profile_id` int(11) UNSIGNED NOT NULL REFERENCES `billing_profiles` (`id`),
`start` datetime,
`end` datetime,
PRIMARY KEY (`id`),
KEY `profileid_idx` (`billing_profile_id`),
CONSTRAINT `b_p_s_bilprofid_ref` FOREIGN KEY (`billing_profile_id`)
REFERENCES `billing_profiles` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- create LNP tables
CREATE TABLE `lnp_providers` (
`id` int(11) UNSIGNED NOT NULL,
`name` varchar(255),
PRIMARY KEY (`id`)
) ENGINE=InnoDB;
CREATE TABLE `lnp_numbers` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`number` varchar(31) NOT NULL,
`lnp_provider_id` int(11) UNSIGNED NOT NULL REFERENCES `lnp_providers` (`id`),
`start` datetime NULL DEFAULT NULL,
`end` datetime NULL DEFAULT NULL,
PRIMARY KEY (`id`),
CONSTRAINT `l_n_lnpproid_ref` FOREIGN KEY (`lnp_provider_id`)
REFERENCES `lnp_providers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- create NCOS tables
CREATE TABLE `ncos_levels` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`reseller_id` int(11) UNSIGNED REFERENCES `resellers` (`id`),
`level` varchar(31) NOT NULL,
`mode` enum('blacklist', 'whitelist') NOT NULL default 'blacklist',
`local_ac` bool NOT NULL DEFAULT FALSE,
`description` text,
PRIMARY KEY (`id`),
UNIQUE KEY `reslev_idx` (`reseller_id`, `level`),
CONSTRAINT `c_l_resellerid_ref` FOREIGN KEY (`reseller_id`)
REFERENCES `resellers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `ncos_pattern_list` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`ncos_level_id` int(11) UNSIGNED NOT NULL REFERENCES `ncos_levels` (`id`),
`pattern` varchar(255) NOT NULL,
`description` text,
PRIMARY KEY (`id`),
UNIQUE KEY `levpat_idx` (`ncos_level_id`, `pattern`),
CONSTRAINT `c_p_l_ncoslevid_ref` FOREIGN KEY (`ncos_level_id`)
REFERENCES `ncos_levels` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `ncos_lnp_list` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`ncos_level_id` int(11) UNSIGNED NOT NULL REFERENCES `ncos_levels` (`id`),
`lnp_provider_id` int(11) UNSIGNED NOT NULL REFERENCES `lnp_providers` (`id`),
`description` text,
PRIMARY KEY (`id`),
UNIQUE KEY `levpro_idx` (`ncos_level_id`, `lnp_provider_id`),
CONSTRAINT `c_l_l_ncoslevid_ref` FOREIGN KEY (`ncos_level_id`)
REFERENCES `ncos_levels` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `c_l_l_lnpproid_ref` FOREIGN KEY (`lnp_provider_id`)
REFERENCES `lnp_providers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- create contact information table
CREATE TABLE `contacts` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`gender` enum('male','female'),
`firstname` varchar(127),
`lastname` varchar(127),
`comregnum` varchar(31),
`company` varchar(127),
`street` varchar(127),
`postcode` int(6),
`city` varchar(127),
`country` char(2),
`phonenumber` varchar(31),
`mobilenumber` varchar(31),
`email` varchar(255),
`newsletter` bool NOT NULL DEFAULT FALSE,
`modify_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
`create_timestamp` timestamp,
PRIMARY KEY (`id`)
) ENGINE=InnoDB;
-- create customer tables
CREATE TABLE `customers` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`reseller_id` int(11) UNSIGNED NULL REFERENCES `resellers` (`id`),
`shopuser` varchar(31) NULL,
`shoppass` varchar(31) NULL,
`business` bool NOT NULL DEFAULT FALSE,
`contact_id` int(11) UNSIGNED NULL REFERENCES `contacts` (`id`),
`tech_contact_id` int(11) UNSIGNED NULL REFERENCES `contacts` (`id`),
`comm_contact_id` int(11) UNSIGNED NULL REFERENCES `contacts` (`id`),
`external_id` varchar(255) NULL default NULL,
`modify_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
`create_timestamp` timestamp,
PRIMARY KEY (`id`),
UNIQUE KEY (`reseller_id`, `shopuser`),
KEY `resellerid_idx` (`reseller_id`),
CONSTRAINT `cu_resellerid_ref` FOREIGN KEY (`reseller_id`)
REFERENCES `resellers` (`id`)
ON DELETE RESTRICT ON UPDATE CASCADE,
KEY `contactid_idx` (`contact_id`),
CONSTRAINT `cu_contactid_ref` FOREIGN KEY (`contact_id`)
REFERENCES `contacts` (`id`)
ON DELETE RESTRICT ON UPDATE CASCADE,
KEY `commcontactid_idx` (`comm_contact_id`),
CONSTRAINT `cu_commcontactid_ref` FOREIGN KEY (`comm_contact_id`)
REFERENCES `contacts` (`id`)
ON DELETE RESTRICT ON UPDATE CASCADE,
KEY `techcontact_idx` (`tech_contact_id`),
CONSTRAINT `cu_techcontact_ref` FOREIGN KEY (`tech_contact_id`)
REFERENCES `contacts` (`id`)
ON DELETE RESTRICT ON UPDATE CASCADE,
KEY `externalid_idx` (`external_id`)
) ENGINE=InnoDB;
CREATE TABLE `customer_registers` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`customer_id` int(11) UNSIGNED NOT NULL REFERENCES `customers` (`id`),
`actor` varchar(15),
`type` varchar(31) NOT NULL,
`data` text,
PRIMARY KEY (`id`),
KEY `customerid_idx` (`customer_id`),
CONSTRAINT `c_r_customerid_ref` FOREIGN KEY (`customer_id`)
REFERENCES `customers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `products` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`reseller_id` int(11) UNSIGNED NULL REFERENCES `resellers` (`id`),
`class` enum('sippeering', 'pstnpeering', 'reseller', 'voip', 'hardware', 'auxiliary') NOT NULL,
`handle` varchar(63) NOT NULL,
`name` varchar(127) NOT NULL,
`on_sale` bool NOT NULL DEFAULT FALSE,
`price` double,
`weight` mediumint(9) UNSIGNED,
`billing_profile_id` int(11) UNSIGNED NULL REFERENCES `billing_profiles` (`id`),
PRIMARY KEY (`id`),
UNIQUE KEY `resnam_idx` (`reseller_id`, `name`),
UNIQUE KEY `reshand_idx` (`reseller_id`, `handle`),
KEY `resellerid_idx` (`reseller_id`),
CONSTRAINT `p_resellerid_ref` FOREIGN KEY (`reseller_id`)
REFERENCES `resellers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `profileid_idx` (`billing_profile_id`),
CONSTRAINT `p_bilprofid_ref` FOREIGN KEY (`billing_profile_id`)
REFERENCES `billing_profiles` (`id`)
ON DELETE RESTRICT ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `invoices` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`year` smallint(4) UNSIGNED NOT NULL,
`month` tinyint(2) UNSIGNED NOT NULL,
`serial` int(5) UNSIGNED NOT NULL,
`data` blob,
PRIMARY KEY (`id`),
UNIQUE KEY `yms_idx` (`year`,`month`,`serial`)
) ENGINE=InnoDB;
CREATE TABLE `orders` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`reseller_id` int(11) UNSIGNED REFERENCES `resellers` (`id`),
`customer_id` int(11) UNSIGNED REFERENCES `customers` (`id`),
`delivery_contact_id` int(11) UNSIGNED REFERENCES `contacts` (`id`),
`type` varchar(31),
`state` enum('init','transact','failed','success') NOT NULL DEFAULT 'init',
`value` int(11),
`shipping_costs` int(11),
`invoice_id` int(11) UNSIGNED REFERENCES `invoices` (`id`),
`modify_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
`create_timestamp` timestamp,
`complete_timestamp` timestamp,
PRIMARY KEY (`id`),
KEY `customerid_idx` (`customer_id`),
CONSTRAINT `o_customerid_ref` FOREIGN KEY (`customer_id`)
REFERENCES `customers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `resellerid_idx` (`reseller_id`),
CONSTRAINT `o_resellerid_ref` FOREIGN KEY (`reseller_id`)
REFERENCES `resellers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `contactid_idx` (`delivery_contact_id`),
CONSTRAINT `o_contactid_ref` FOREIGN KEY (`delivery_contact_id`)
REFERENCES `contacts` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `invoiceid_idx` (`invoice_id`),
CONSTRAINT `o_invoiceid_ref` FOREIGN KEY (`invoice_id`)
REFERENCES `invoices` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- create payment table
CREATE TABLE `payments` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`amount` int(11),
`type` varchar(31),
`state` enum('init','transact','failed','success'),
`mpaytid` int(11) UNSIGNED,
`status` varchar(31),
`errno` int(11),
`returncode` varchar(63),
`externalstatus` text,
`modify_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
`create_timestamp` timestamp,
PRIMARY KEY (`id`),
KEY `state_idx` (`state`),
KEY `mpaytid_idx` (`mpaytid`),
KEY `status_idx` (`status`)
) ENGINE=InnoDB;
-- create mapping table between orders and payments
CREATE TABLE `order_payments` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`order_id` int(11) UNSIGNED NOT NULL REFERENCES `orders` (`id`),
`payment_id` int(11) UNSIGNED NOT NULL REFERENCES `payments` (`id`),
PRIMARY KEY (`id`),
KEY `orderid_idx` (`order_id`),
CONSTRAINT `op_orderid_ref` FOREIGN KEY (`order_id`)
REFERENCES `orders` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `paymentid_idx` (`payment_id`),
CONSTRAINT `op_paymentid_ref` FOREIGN KEY (`payment_id`)
REFERENCES `payments` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- create contract tables
CREATE TABLE `contracts` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`customer_id` int(11) UNSIGNED NULL REFERENCES `customers` (`id`),
`reseller_id` int(11) UNSIGNED NULL REFERENCES `resellers` (`id`),
`contact_id` int(11) UNSIGNED NULL REFERENCES `contacts` (`id`),
`order_id` int(11) UNSIGNED NULL REFERENCES `orders` (`id`),
`status` enum('pending','active','locked','terminated') NOT NULL DEFAULT 'active',
`external_id` varchar(255) NULL default NULL,
`modify_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
`create_timestamp` timestamp NOT NULL,
`activate_timestamp` timestamp NULL,
`terminate_timestamp` timestamp NULL,
PRIMARY KEY (`id`),
KEY `contactid_idx` (`contact_id`),
CONSTRAINT `co_contactid_ref` FOREIGN KEY (`contact_id`)
REFERENCES `contacts` (`id`)
ON DELETE SET NULL ON UPDATE CASCADE,
KEY `customerid_idx` (`customer_id`),
CONSTRAINT `c_customerid_ref` FOREIGN KEY (`customer_id`)
REFERENCES `customers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `resellerid_idx` (`reseller_id`),
CONSTRAINT `co_resellerid_ref` FOREIGN KEY (`reseller_id`)
REFERENCES `resellers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `orderid_idx` (`order_id`),
CONSTRAINT `co_orderid_ref` FOREIGN KEY (`order_id`)
REFERENCES `orders` (`id`)
ON DELETE SET NULL ON UPDATE CASCADE,
KEY `externalid_idx` (`external_id`)
) ENGINE=InnoDB;
-- create resellers->contracts foreign key
ALTER TABLE resellers
ADD CONSTRAINT `r_contractid_ref`
FOREIGN KEY (`contract_id`)
REFERENCES `contracts` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
;
CREATE TABLE `contract_registers` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`contract_id` int(11) UNSIGNED NOT NULL REFERENCES `contracts` (`id`),
`actor` varchar(15),
`type` varchar(31) NOT NULL,
`data` text,
PRIMARY KEY (`id`),
KEY `contractid_idx` (`contract_id`),
CONSTRAINT `c_r_contractid_ref` FOREIGN KEY (`contract_id`)
REFERENCES `contracts` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `voip_subscribers` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`contract_id` int(11) UNSIGNED NOT NULL REFERENCES `contracts` (`id`),
`uuid` char(36) NOT NULL,
`username` varchar(127) NOT NULL,
`domain_id` int(11) UNSIGNED NOT NULL REFERENCES `domains` (`id`),
`status` enum('active','locked','terminated') NOT NULL DEFAULT 'active',
`primary_number_id` int(11) unsigned default NULL,
`external_id` varchar(255) NULL default NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `uuid_idx` (uuid),
KEY `username_idx` (`username`),
KEY `contractid_idx` (`contract_id`),
CONSTRAINT `v_s_contractid_ref` FOREIGN KEY (`contract_id`)
REFERENCES `contracts` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `domainid_idx` (`domain_id`),
CONSTRAINT `v_s_domainid_ref` FOREIGN KEY (`domain_id`)
REFERENCES `domains` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `pnumid_idx` (`primary_number_id`),
KEY `externalid_idx` (`external_id`)
) ENGINE=InnoDB;
-- create table that stores all known E.164 numbers
CREATE TABLE `voip_numbers` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`cc` int(4) UNSIGNED NOT NULL,
`ac` varchar(7) NOT NULL,
`sn` varchar(31) NOT NULL,
`reseller_id` int(11) UNSIGNED NULL REFERENCES `resellers` (`id`),
`subscriber_id` int(11) UNSIGNED NULL REFERENCES `voip_subscribers` (`id`),
`status` enum('active','reserved','locked','deported') NOT NULL DEFAULT 'active',
`ported` bool NOT NULL DEFAULT FALSE,
`list_timestamp` timestamp,
PRIMARY KEY (`id`),
KEY `listts_idx` (`list_timestamp`),
UNIQUE KEY `number_idx` (`cc`,`ac`,`sn`),
KEY `resellerid_idx` (`reseller_id`),
CONSTRAINT `v_n_resellerid_ref` FOREIGN KEY (`reseller_id`)
REFERENCES `resellers` (`id`)
ON DELETE SET NULL ON UPDATE CASCADE,
KEY `subscriberid_idx` (`subscriber_id`),
CONSTRAINT `v_n_subscriberid_ref` FOREIGN KEY (`subscriber_id`)
REFERENCES `voip_subscribers` (`id`)
ON DELETE SET NULL ON UPDATE CASCADE
) ENGINE=InnoDB;
-- define local number blocks
CREATE TABLE `voip_number_blocks` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`cc` int(4) UNSIGNED NOT NULL,
`ac` varchar(7) NOT NULL,
`sn_prefix` varchar(31) NOT NULL,
`sn_length` tinyint(2) UNSIGNED NOT NULL,
`allocable` bool NOT NULL DEFAULT FALSE,
`authoritative` bool NOT NULL DEFAULT FALSE,
PRIMARY KEY (`id`),
UNIQUE KEY `prefix_idx` (`cc`, `ac`, `sn_prefix`)
) ENGINE=InnoDB;
CREATE TABLE `voip_number_block_resellers` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`number_block_id` int(11) UNSIGNED NOT NULL REFERENCES `voip_number_blocks` (`id`),
`reseller_id` int(11) UNSIGNED NOT NULL REFERENCES `resellers` (`id`),
PRIMARY KEY (`id`),
KEY `numblockid_idx` (`number_block_id`),
CONSTRAINT `vnbr_numblockid_ref` FOREIGN KEY (`number_block_id`)
REFERENCES `voip_number_blocks` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `resellerid_idx` (`reseller_id`),
CONSTRAINT `vnbr_resellerid_ref` FOREIGN KEY (`reseller_id`)
REFERENCES `resellers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- create subscribers->primary-number foreign key
ALTER TABLE voip_subscribers
ADD CONSTRAINT `v_s_pnumid_ref`
FOREIGN KEY (`primary_number_id`)
REFERENCES `voip_numbers` (`id`)
ON DELETE SET NULL ON UPDATE CASCADE
;
-- create account status table
CREATE TABLE `contract_balances` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`contract_id` int(11) UNSIGNED NOT NULL REFERENCES `contracts` (`id`),
`cash_balance` double,
`cash_balance_interval` double NOT NULL DEFAULT 0,
`free_time_balance` int(11),
`free_time_balance_interval` int(11) NOT NULL DEFAULT 0,
`start` datetime NOT NULL,
`end` datetime NOT NULL,
`invoice_id` int(11) UNSIGNED REFERENCES `invoices` (`id`),
PRIMARY KEY (`id`),
KEY `contractid_idx` (`contract_id`),
CONSTRAINT `c_b_contractid_ref` FOREIGN KEY (`contract_id`)
REFERENCES `contracts` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `invoiceid_idx` (`invoice_id`),
CONSTRAINT `cb_invoiceid_ref` FOREIGN KEY (`invoice_id`)
REFERENCES `invoices` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- create table that holds credits and debits
CREATE TABLE `contract_credits` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`balance_id` int(11) UNSIGNED NOT NULL REFERENCES `contract_balances` (`id`),
`state` enum('init','transact','charged','failed','success') NOT NULL DEFAULT 'init',
`amount` double,
`reason` text,
`modify_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
`create_timestamp` timestamp,
PRIMARY KEY (`id`),
KEY `balanceid_idx` (`balance_id`),
CONSTRAINT `cc_balanceid_ref` FOREIGN KEY (`balance_id`)
REFERENCES `contract_balances` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- create mapping table between orders and payments
CREATE TABLE `credit_payments` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`credit_id` int(11) UNSIGNED NOT NULL REFERENCES `contract_credits` (`id`),
`payment_id` int(11) UNSIGNED NOT NULL REFERENCES `payments` (`id`),
PRIMARY KEY (`id`),
KEY `creditid_idx` (`credit_id`),
CONSTRAINT `cp_creditid_ref` FOREIGN KEY (`credit_id`)
REFERENCES `contract_credits` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `paymentid_idx` (`payment_id`),
CONSTRAINT `cp_paymentid_ref` FOREIGN KEY (`payment_id`)
REFERENCES `payments` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- create mapping table between contracts and billing_profiles, billing_groups and products
CREATE TABLE `billing_mappings` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`start_date` datetime,
`end_date` datetime,
`billing_profile_id` int(11) UNSIGNED REFERENCES `billing_profiles` (`id`),
`contract_id` int(11) UNSIGNED NOT NULL REFERENCES `contracts` (`id`),
`product_id` int(11) UNSIGNED REFERENCES `products` (`id`),
PRIMARY KEY (`id`),
KEY `profileid_idx` (`billing_profile_id`),
CONSTRAINT `b_m_bilprofid_ref` FOREIGN KEY (`billing_profile_id`)
REFERENCES `billing_profiles` (`id`)
ON DELETE RESTRICT ON UPDATE CASCADE,
KEY `contractid_idx` (`contract_id`),
CONSTRAINT `b_m_contractid_ref` FOREIGN KEY (`contract_id`)
REFERENCES `contracts` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `productid_idx` (`product_id`),
CONSTRAINT `b_m_productid_ref` FOREIGN KEY (`product_id`)
REFERENCES `products` (`id`)
ON DELETE RESTRICT ON UPDATE CASCADE
) ENGINE=InnoDB;
-- lawful intercept table
CREATE TABLE `voip_intercept` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`reseller_id` int(11) UNSIGNED NULL REFERENCES `resellers` (`id`),
`LIID` int(11) UNSIGNED,
`number` varchar(63),
`cc_required` bool NOT NULL DEFAULT FALSE,
`delivery_host` varchar(15),
`delivery_port` smallint(5) UNSIGNED,
`delivery_user` text NULL,
`delivery_pass` text NULL,
`modify_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
`create_timestamp` timestamp NOT NULL,
`deleted` bool NOT NULL DEFAULT FALSE,
PRIMARY KEY (`id`),
KEY `resellerid_idx` (`reseller_id`),
CONSTRAINT `vi_resellerid_ref` FOREIGN KEY (`reseller_id`)
REFERENCES `resellers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `number_idx` (`number`),
KEY `deleted_idx` (`deleted`)
) ENGINE=InnoDB;
-- insert some data to get rating and the web interface working
-- system internal products
INSERT INTO `products` (id,class,handle,name,on_sale)
VALUES (1,'pstnpeering','PSTN_PEERING','PSTN Peering',1),
(2,'sippeering','SIP_PEERING','SIP Peering',1),
(3,'reseller','VOIP_RESELLER','VoIP Reseller',1);
-- the default reseller contract, will be the only one unless multitenancy is enabled
INSERT INTO `contracts` (id,status,modify_timestamp,create_timestamp,activate_timestamp) VALUES (1,'active',now(),now(),now());
INSERT INTO `resellers` (id,contract_id,name,status) VALUES (1,1,'default','active');
INSERT INTO `billing_mappings` (id,start_date,end_date,contract_id,product_id) VALUES (1,NULL,NULL,1,3);
-- first administrative account, change password after first login
INSERT INTO `admins` (id,reseller_id,login,md5pass,is_master,is_superuser,call_data,lawful_intercept)
VALUES (1,1,'administrator',md5('administrator'),1,1,1,1);
-- default billing profile creation
INSERT INTO `billing_profiles` (id,reseller_id,handle,name,interval_unit,interval_count)
VALUES(1,1,'default','Default Billing Profile','month',1);
INSERT INTO `billing_zones` (id,billing_profile_id,zone,detail) VALUES (1,1,'Free Default Zone','All Destinations');
INSERT INTO `billing_fees` (id,billing_profile_id,billing_zone_id,destination,type,
onpeak_init_rate,onpeak_init_interval,onpeak_follow_rate,onpeak_follow_interval,
offpeak_init_rate,offpeak_init_interval,offpeak_follow_rate,offpeak_follow_interval)
VALUES (1,1,1,'.*','call',0,600,0,600,0,600,0,600);

@ -0,0 +1,591 @@
-- step out of our provisioning DB
USE mysql;
-- drop database if it allready exists
-- this will drop all tables and triggers
DROP DATABASE IF EXISTS provisioning;
-- create DB with utf8 default charset, so we don't have to
-- specify charset for each table
CREATE DATABASE IF NOT EXISTS provisioning CHARACTER SET 'utf8';
USE provisioning;
-- create domain table
CREATE TABLE `voip_domains` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`domain` varchar(127) NOT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `domain_idx` (`domain`)
) ENGINE=InnoDB;
-- create subscriber table
CREATE TABLE `voip_subscribers` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`username` varchar(127) NOT NULL,
`domain_id` int(11) UNSIGNED NOT NULL REFERENCES `voip_domains` (`id`),
`uuid` char(36) NOT NULL,
`password` varchar(40) default NULL,
`admin` bool NOT NULL DEFAULT FALSE,
`account_id` int(11) UNSIGNED NULL DEFAULT NULL,
`webusername` varchar(127) default NULL,
`webpassword` varchar(40) default NULL,
`autoconf_displayname` varchar(255) default NULL,
`autoconf_group_id` int(11) unsigned default NULL,
`modify_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
`create_timestamp` timestamp NOT NULL default '0000-00-00 00:00:00',
PRIMARY KEY (`id`),
UNIQUE KEY `user_dom_idx` (`username`,`domain_id`),
UNIQUE KEY `uuid_idx` (`uuid`),
KEY `accountid_idx` (`account_id`),
KEY `domainid_idx` (`domain_id`),
CONSTRAINT `v_s_domainid_ref` FOREIGN KEY (`domain_id`)
REFERENCES `voip_domains` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- create alias table
CREATE TABLE `voip_dbaliases` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`username` varchar(127) NOT NULL,
`domain_id` int(11) UNSIGNED NOT NULL REFERENCES `voip_domains` (`id`),
`subscriber_id` int(11) UNSIGNED NOT NULL REFERENCES `voip_subscribers` (`id`),
PRIMARY KEY (`id`),
UNIQUE KEY `user_dom_idx` (`username`,`domain_id`),
KEY `domainid_idx` (`domain_id`),
KEY `subscriberid_idx` (`subscriber_id`),
CONSTRAINT `v_da_subscriberid_ref` FOREIGN KEY (`subscriber_id`)
REFERENCES `voip_subscribers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `v_da_domainid_ref` FOREIGN KEY (`domain_id`)
REFERENCES `voip_domains` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- sip peering tables
CREATE TABLE `voip_peer_groups` (
`id` int(11) unsigned NOT NULL auto_increment,
`name` varchar(127) NOT NULL,
`priority` tinyint(3) NOT NULL default '1',
`description` varchar(255),
`peering_contract_id` int(11) unsigned,
PRIMARY KEY (`id`),
UNIQUE KEY `name` (`name`)
) ENGINE=InnoDB;
CREATE TABLE `voip_peer_rules` (
`id` int(11) unsigned NOT NULL auto_increment,
`group_id` int(11) unsigned NOT NULL,
`callee_prefix` varchar(64) NOT NULL default '',
`caller_prefix` varchar(64) default NULL,
`description` varchar(255) NOT NULL,
PRIMARY KEY (`id`),
KEY `grpidx` (`group_id`),
CONSTRAINT `v_pg_groupid_ref` FOREIGN KEY (`group_id`) REFERENCES `voip_peer_groups` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `voip_peer_hosts` (
`id` int(11) unsigned NOT NULL auto_increment,
`group_id` int(11) unsigned NOT NULL,
`name` varchar(64) NOT NULL default '',
`ip` varchar(64) NOT NULL,
`host` varchar(64) DEFAULT NULL,
`port` int(5) NOT NULL default '5060',
`weight` tinyint(3) NOT NULL default '0',
`via_lb` tinyint(1) NOT NULL default '0',
PRIMARY KEY (`id`),
UNIQUE KEY `grpname` (`group_id`,`name`),
KEY `grpidx` (`group_id`),
CONSTRAINT `v_ps_groupid_ref` FOREIGN KEY (`group_id`) REFERENCES `voip_peer_groups` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- create voip_preferences table
CREATE TABLE `voip_preferences` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`attribute` varchar(31) NOT NULL,
`type` tinyint(3) NOT NULL default 0,
`max_occur` tinyint(3) UNSIGNED NOT NULL,
`usr_pref` bool NOT NULL default FALSE,
`dom_pref` bool NOT NULL default FALSE,
`peer_pref` bool NOT NULL default FALSE,
`modify_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
`internal` tinyint(1) NOT NULL default 0,
`data_type` enum('boolean','int','string') NOT NULL default 'string',
`read_only` bool NOT NULL default FALSE,
`description` text,
PRIMARY KEY (`id`),
UNIQUE KEY `attribute_idx` (`attribute`)
) ENGINE=InnoDB;
-- create subscriber preferences table
CREATE TABLE `voip_usr_preferences` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`subscriber_id` int(11) UNSIGNED NOT NULL REFERENCES `voip_subscribers` (`id`),
`attribute_id` int(11) UNSIGNED NOT NULL REFERENCES `voip_preferences` (`id`),
`value` varchar(128) NOT NULL,
`modify_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
PRIMARY KEY (`id`),
KEY `subidattrid_idx` (`subscriber_id`,`attribute_id`),
KEY `subscriberid_idx` (`subscriber_id`),
KEY `attributeid_idx` (`attribute_id`),
CONSTRAINT `v_u_p_subscriberid_ref` FOREIGN KEY (`subscriber_id`)
REFERENCES `voip_subscribers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `v_u_p_attributeid_ref` FOREIGN KEY (`attribute_id`)
REFERENCES `voip_preferences` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- create domain preferences table
CREATE TABLE `voip_dom_preferences` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`domain_id` int(11) UNSIGNED NOT NULL REFERENCES `voip_domains` (`id`),
`attribute_id` int(11) UNSIGNED NOT NULL REFERENCES `voip_preferences` (`id`),
`value` varchar(128) NOT NULL,
`modify_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
PRIMARY KEY (`id`),
KEY `domidattrid_idx` (`domain_id`,`attribute_id`),
KEY `domainid_idx` (`domain_id`),
KEY `attributeid_idx` (`attribute_id`),
CONSTRAINT `v_d_p_domainid_ref` FOREIGN KEY (`domain_id`)
REFERENCES `voip_domains` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `v_d_p_attributeid_ref` FOREIGN KEY (`attribute_id`)
REFERENCES `voip_preferences` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- create peer host preferences table
CREATE TABLE `voip_peer_preferences` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`peer_host_id` int(11) UNSIGNED NOT NULL REFERENCES `voip_peer_hosts` (`id`),
`attribute_id` int(11) UNSIGNED NOT NULL REFERENCES `voip_preferences` (`id`),
`value` varchar(255) NOT NULL,
`modify_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
PRIMARY KEY (`id`),
KEY `peerhostid_idx` (`peer_host_id`),
KEY `attributeid_idx` (`attribute_id`),
CONSTRAINT `v_p_p_peerhostid_ref` FOREIGN KEY (`peer_host_id`)
REFERENCES `voip_peer_hosts` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `v_p_p_attributeid_ref` FOREIGN KEY (`attribute_id`)
REFERENCES `voip_preferences` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- create preliminary address book table
-- this should be moved to LDAP at some time
CREATE TABLE `voip_contacts` (
`id` int(11) unsigned NOT NULL auto_increment,
`subscriber_id` int(11) unsigned NOT NULL REFERENCES `voip_subscribers` (`id`),
`firstname` varchar(127),
`lastname` varchar(127),
`company` varchar(127),
`phonenumber` varchar(31),
`homephonenumber` varchar(31),
`mobilenumber` varchar(31),
`faxnumber` varchar(31),
`email` varchar(255),
`homepage` varchar(255),
PRIMARY KEY (`id`),
KEY `subscriberid_idx` (`subscriber_id`),
CONSTRAINT `v_c_subscriberid_ref` FOREIGN KEY (`subscriber_id`)
REFERENCES `voip_subscribers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `voip_speed_dial` (
`id` int(11) UNSIGNED NOT NULL PRIMARY KEY auto_increment,
`subscriber_id` int(11) UNSIGNED NOT NULL,
`slot` varchar(64) NOT NULL,
`destination` varchar(192) NOT NULL,
UNIQUE KEY `subscriberid_slot_idx` (`subscriber_id`,`slot`),
CONSTRAINT `v_sd_subscriberid_ref` FOREIGN KEY (`subscriber_id`)
REFERENCES `voip_subscribers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) engine=InnoDB;
CREATE TABLE `voip_reminder` (
`id` int(11) unsigned NOT NULL auto_increment,
`subscriber_id` int(11) unsigned NOT NULL,
`time` time NOT NULL,
`recur` enum('never','weekdays','always') NOT NULL default 'never',
PRIMARY KEY (`id`),
UNIQUE KEY `subscriber_id` (`subscriber_id`),
CONSTRAINT `v_rem_subscriberid_ref` FOREIGN KEY (`subscriber_id`)
REFERENCES `voip_subscribers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- create IP groups table containing IPs where users may connect from
-- IP networks are combined to groups to keep usr_preferences a bit smaller
CREATE TABLE `voip_allowed_ip_groups` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`group_id` int(10) unsigned NOT NULL,
`ipnet` varchar(18) NOT NULL,
PRIMARY KEY (`id`),
KEY `groupid_idx` (`group_id`),
KEY `ipnet_idx` (`ipnet`),
UNIQUE KEY `groupnet_idx` (`group_id`,`ipnet`)
) ENGINE=InnoDB;
-- this is a sequencer for `group_id` in `voip_allowed_ip_groups` above
CREATE TABLE `voip_aig_sequence` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
PRIMARY KEY (`id`)
) ENGINE=InnoDB;
-- create fax tables
CREATE TABLE `voip_fax_preferences` (
`id` int(11) unsigned NOT NULL auto_increment,
`subscriber_id` int(11) unsigned NOT NULL REFERENCES `voip_subscribers` (`id`),
`password` varchar(64),
`name` varchar(64),
`active` bool NOT NULL default FALSE,
`send_status` bool NOT NULL default TRUE,
`send_copy` bool NOT NULL default TRUE,
PRIMARY KEY (`id`),
UNIQUE KEY `subscriberid_idx` (`subscriber_id`),
CONSTRAINT `v_f_p_subscriberid_ref` FOREIGN KEY (`subscriber_id`)
REFERENCES `voip_subscribers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `voip_fax_destinations` (
`id` int(11) unsigned NOT NULL auto_increment,
`subscriber_id` int(11) unsigned NOT NULL REFERENCES `voip_subscribers` (`id`),
`destination` varchar(255) NOT NULL,
`filetype` enum('PS','TIFF','PDF','PDF14') NOT NULL default 'TIFF',
`cc` bool NOT NULL default FALSE,
`incoming` bool NOT NULL default TRUE,
`outgoing` bool NOT NULL default FALSE,
`status` bool NOT NULL default FALSE,
PRIMARY KEY (`id`),
UNIQUE KEY `subdest_idx` (`subscriber_id`, `destination`),
CONSTRAINT `v_f_d_subscriberid_ref` FOREIGN KEY (`subscriber_id`)
REFERENCES `voip_subscribers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- audio files for IVR, auto-attendant, etc.
CREATE TABLE `voip_audio_files` (
`id` int(11) unsigned NOT NULL auto_increment,
`subscriber_id` int(11) unsigned REFERENCES `voip_subscribers` (`id`),
`domain_id` int(11) unsigned REFERENCES `voip_domains` (`id`),
`handle` varchar(63) NOT NULL,
`description` text,
`audio` longblob,
PRIMARY KEY (`id`),
UNIQUE KEY `subhand_idx` (`subscriber_id`, `handle`),
UNIQUE KEY `domhand_idx` (`domain_id`, `handle`),
CONSTRAINT `v_a_f_subscriberid_ref` FOREIGN KEY (`subscriber_id`)
REFERENCES `voip_subscribers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `v_a_f_domainid_ref` FOREIGN KEY (`domain_id`)
REFERENCES `voip_domains` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- VSC table
CREATE TABLE `voip_vscs` (
`id` int(11) unsigned NOT NULL auto_increment,
`domain_id` int(11) unsigned REFERENCES `voip_domains` (`id`),
`digits` char(2),
`action` varchar(31) NOT NULL,
`audio_id` int(11) unsigned NOT NULL REFERENCES `voip_audio_files` (`id`),
`description` text,
PRIMARY KEY (`id`),
UNIQUE KEY `domdig_idx` (`domain_id`, `digits`),
UNIQUE KEY `domaction_idx` (`domain_id`, `action`),
KEY `audioid_idx` (`audio_id`),
CONSTRAINT `v_v_domainid_ref` FOREIGN KEY (`domain_id`)
REFERENCES `voip_domains` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `v_v_audioid_ref` FOREIGN KEY (`audio_id`)
REFERENCES `voip_audio_files` (`id`)
ON DELETE RESTRICT ON UPDATE CASCADE
) ENGINE=InnoDB;
-- language strings for error messages
CREATE TABLE language_strings (
`id` int(11) unsigned NOT NULL auto_increment,
`code` varchar(63) NOT NULL,
`language` char(2) NOT NULL,
`string` text,
PRIMARY KEY (`id`),
UNIQUE KEY `codelang_idx` (code, language)
) ENGINE=InnoDB;
-- xmlrpc dispatcher tables
CREATE TABLE `xmlqueue` (
`id` int(10) unsigned NOT NULL auto_increment,
`target` varchar(255) NOT NULL,
`body` text NOT NULL,
`ctime` int(10) unsigned NOT NULL,
`atime` int(10) unsigned NOT NULL,
`tries` int(10) unsigned NOT NULL,
`next_try` int(10) unsigned NOT NULL,
PRIMARY KEY (`id`),
KEY `next_try` (`next_try`,`id`)
) ENGINE=InnoDB;
CREATE TABLE `xmlhosts` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`ip` varchar(15) NOT NULL,
`port` int(5) unsigned NOT NULL,
`path` varchar(64) NOT NULL DEFAULT '/',
`sip_port` int(5) unsigned DEFAULT NULL,
`description` varchar(255) DEFAULT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB;
CREATE TABLE `xmlgroups` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`name` varchar(32) NOT NULL,
PRIMARY KEY (`id`),
KEY `gname` (`name`)
) ENGINE=InnoDB;
CREATE TABLE `xmlhostgroups` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`group_id` int(11) unsigned NOT NULL,
`host_id` int(11) unsigned NOT NULL,
PRIMARY KEY (`id`),
KEY `gidx` (`group_id`),
KEY `xhg_hostid_ref` (`host_id`),
CONSTRAINT `xhg_groupid_ref` FOREIGN KEY (`group_id`)
REFERENCES `xmlgroups` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `xhg_hostid_ref` FOREIGN KEY (`host_id`)
REFERENCES `xmlhosts` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `voip_rewrite_rule_sets` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`name` varchar(32) NOT NULL,
`description` varchar(255) DEFAULT NULL,
`caller_in_dpid` int(11) unsigned DEFAULT NULL,
`callee_in_dpid` int(11) unsigned DEFAULT NULL,
`caller_out_dpid` int(11) unsigned DEFAULT NULL,
`callee_out_dpid` int(11) unsigned DEFAULT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `name_idx` (`name`)
) ENGINE=InnoDB;
-- this is a sequencer for the dpids in `voip_rewrite_rule_sets` above
CREATE TABLE `voip_rwrs_sequence` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
PRIMARY KEY (`id`)
) ENGINE=InnoDB;
CREATE TABLE `voip_rewrite_rules` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`set_id` int(11) unsigned NOT NULL,
`match_pattern` varchar(64) NOT NULL DEFAULT '',
`replace_pattern` varchar(64) NOT NULL,
`description` varchar(127) NOT NULL DEFAULT '',
`direction` enum('in','out') NOT NULL DEFAULT 'in',
`field` enum('caller','callee') NOT NULL DEFAULT 'caller',
`priority` int(11) unsigned NOT NULL DEFAULT '50',
PRIMARY KEY (`id`),
KEY `setidx` (`set_id`),
KEY `dirfieldidx` (`direction`,`field`),
CONSTRAINT `v_rwr_setid_ref` FOREIGN KEY (`set_id`) REFERENCES `voip_rewrite_rule_sets` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- call forward tables
CREATE TABLE `voip_cf_destination_sets` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`subscriber_id` int(11) unsigned DEFAULT NULL,
`name` varchar(255) NOT NULL,
PRIMARY KEY (`id`),
KEY `sub_idx` (`subscriber_id`),
KEY `name_idx` (`name`),
CONSTRAINT `v_s_subid_ref` FOREIGN KEY (`subscriber_id`) REFERENCES `voip_subscribers` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `voip_cf_destinations` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`destination_set_id` int(11) unsigned NOT NULL,
`destination` varchar(255) NOT NULL,
`priority` int(3) unsigned DEFAULT NULL,
`timeout` int(11) unsigned NOT NULL DEFAULT 300,
PRIMARY KEY (`id`),
KEY `dset_idx` (`destination_set_id`),
KEY `destination_idx` (`destination`),
CONSTRAINT `v_cf_dsetid_ref` FOREIGN KEY (`destination_set_id`) REFERENCES `voip_cf_destination_sets` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `voip_cf_time_sets` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`subscriber_id` int(11) unsigned DEFAULT NULL,
`name` varchar(255) NOT NULL,
PRIMARY KEY (`id`),
KEY `sub_idx` (`subscriber_id`),
KEY `name_idx` (`name`),
CONSTRAINT `v_cf_ts_subid_ref` FOREIGN KEY (`subscriber_id`) REFERENCES
`voip_subscribers` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `voip_cf_periods` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`time_set_id` int(11) unsigned NOT NULL,
`year` varchar(255) DEFAULT NULL,
`month` varchar(255) DEFAULT NULL,
`mday` varchar(255) DEFAULT NULL,
`wday` varchar(255) DEFAULT NULL,
`hour` varchar(255) DEFAULT NULL,
`minute` varchar(255) DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `tset_idx` (`time_set_id`),
CONSTRAINT `v_cf_tsetid_ref` FOREIGN KEY (`time_set_id`) REFERENCES
`voip_cf_time_sets` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `voip_cf_mappings` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`subscriber_id` int(11) unsigned NOT NULL,
`type` enum('cfu','cfb','cfna','cft') NOT NULL DEFAULT 'cfu',
`destination_set_id` int(11) unsigned DEFAULT NULL,
`time_set_id` int(11) unsigned DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `sub_idx` (`subscriber_id`),
KEY `type_idx` (`type`),
CONSTRAINT `v_cfmap_subid_ref` FOREIGN KEY (`subscriber_id`) REFERENCES `voip_subscribers` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `cfmap_time_ref` FOREIGN KEY (`time_set_id`) REFERENCES `voip_cf_time_sets` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `cfmap_dest_ref` FOREIGN KEY (`destination_set_id`) REFERENCES `voip_cf_destination_sets` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
-- INSERT default data
-- localization language strings
LOAD DATA LOCAL INFILE 'language_strings.txt' INTO TABLE language_strings;
-- xmlrpc dispatcher
INSERT INTO xmlgroups (id, name) VALUES(1, 'proxy');
INSERT INTO xmlgroups (id, name) VALUES(2, 'registrar');
INSERT INTO xmlgroups (id, name) VALUES(3, 'presence');
INSERT INTO xmlgroups (id, name) VALUES(4, 'loadbalancer');
INSERT INTO xmlgroups (id, name) VALUES(5, 'appserver');
-- TODO: SR interface hack to work around rpc/mi discrepancies
INSERT INTO xmlgroups (id, name) VALUES(6, 'proxy-ng');
INSERT INTO xmlhosts (id, ip, port, path, sip_port, description) VALUES (1,'127.0.0.1','8000','/RPC2', '5062', 'Kamailio');
INSERT INTO xmlhosts (id, ip, port, path, description) VALUES (2,'127.0.0.1','8090','/','Sems');
-- TODO: SR interface hack to work around rpc/mi discrepancies
INSERT INTO xmlhosts (id, ip, port, path, description) VALUES (3,'127.0.0.1','5062','/','Kamailio-SR');
INSERT INTO xmlhostgroups (id, group_id, host_id) VALUES (1,1,1);
INSERT INTO xmlhostgroups (id, group_id, host_id) VALUES (2,5,2);
INSERT INTO xmlhostgroups (id, group_id, host_id) VALUES (3,6,3);
-- regular kamailio preferences
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, read_only, description)
VALUES('lock', 0, 1, 'string', 1, 1, 'See "lock_voip_account_subscriber" for a list of possible values. A lock value of "none" will not be returned to the caller. Read-only setting.');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('block_in_mode', 1, 1, 'boolean', 1, 'Specifies the operational mode of the incoming block list. If unset or set to a false value, it is a blacklist (accept all calls except from numbers listed in the block list), with a true value it is a whitelist (reject all calls except from numbers listed in the block list).');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('block_in_list', 0, 1, 'string', 0, 'Contains wildcarded E.164 numbers that are (not) allowed to call the subscriber. "*", "?" and "[x-y]" with "x" and "y" representing numbers from 0 to 9 may be used as wildcards like in shell patterns.');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('block_in_clir', 1, 1, 'boolean', 1, 'Incoming anonymous calls (with calling line identification restriction) are blocked if set to true.');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('block_out_mode', 1, 1, 'boolean', 1, 'Specifies the operational mode of the outgoing block list. If unset or set to a false value, it is a blacklist (allow all calls except to numbers listed in the block list), with a true value it is a whitelist (deny all calls except to numbers listed in the block list).');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('block_out_list', 0, 1, 'string', 0, 'Contains wildcarded E.164 numbers that are (not) allowed to be called by the subscriber. "*", "?" and "[x-y]" with "x" and "y" representing numbers from 0 to 9 may be used as wildcards like in shell patterns.');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('adm_block_in_mode', 1, 1, 'boolean', 1, 'Same as "block_in_mode" but may only be set by administrators.');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('adm_block_in_list', 0, 1, 'string', 0, 'Same as "block_in_list" but may only be set by administrators and is applied prior to the user setting.');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('adm_block_in_clir', 1, 1, 'boolean', 1, 'Same as "block_in_clir" but may only be set by administrators and is applied prior to the user setting.');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('adm_block_out_mode', 1, 1, 'boolean', 1, 'Same as "block_out_mode" but may only be set by administrators.');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('adm_block_out_list', 0, 1, 'string', 0, 'Same as "block_out_list" but may only be set by administrators and is applied prior to the user setting.');
INSERT INTO voip_preferences (internal, read_only, attribute, type, usr_pref, data_type, max_occur, description)
VALUES(1, 1, 'cfu', 1, 1, 'int', 0, 'The id pointing to the "Call Forward Unconditional" entry in the voip_cf_mappings table');
INSERT INTO voip_preferences (internal, read_only, attribute, type, usr_pref, data_type, max_occur, description)
VALUES(1, 1, 'cfb', 1, 1, 'int', 0, 'The id pointing to the "Call Forward Busy" entry in the voip_cf_mappings table');
INSERT INTO voip_preferences (internal, read_only, attribute, type, usr_pref, data_type, max_occur, description)
VALUES(1, 1, 'cfna', 1, 1, 'int', 0, 'The id pointing to the "Call Forward Unavailable" entry in the voip_cf_mappings table');
INSERT INTO voip_preferences (internal, read_only, attribute, type, usr_pref, data_type, max_occur, description)
VALUES(1, 1, 'cft', 1, 1, 'int', 0, 'The id pointing to the "Call Forward Timeout" entry in the voip_cf_mappings table');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('ringtimeout', 1, 1, 'int', 1, 'Specifies how many seconds the system should wait before redirecting the call if "cft" is set.');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('cli', 0, 1, 'string', 1, 'E.164 number or complete SIP URI. "network-provided calling line identification" - specifies the source E.164 number or SIP username that is used for outgoing calls in the SIP "From" and "P-Asserted-Identity" headers (as user- and network-provided calling numbers). The content of the "From" header may be overridden by the "user_cli" preference and client (if allowed by the "allowed_clis" preference) SIP signalling. Automatically set to the primary E.164 number specified in the subscriber details.');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('user_cli', 0, 1, 'string', 1, 'E.164 number or complete SIP URI. "user-provided calling line identification" - specifies the source E.164 number or SIP username that is used for outgoing calls. If set, this is put in the SIP "From" header (as user-provided calling number) if a client sends a CLI which is not allowed by "allowed_clis" or "allowed_clis" is not set.');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('clir', 1, 1, 'boolean', 1, '"Calling line identification restriction" - if set to true, the CLI is not displayed on outgoing calls.');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('cc', 0, 1, 'string', 1, 'The country code that will be used for routing of dialed numbers without a country code. Defaults to the country code of the E.164 number if the subscriber has one.');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('ac', 0, 1, 'string', 1, 'The area code that will be used for routing of dialed numbers without an area code. Defaults to the area code of the E.164 number if the subscriber has one.');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('svc_ac', 0, 1, 'string', 1, 'The area code that will be used for routing of dialed service numbers without an area code. Defaults to "ac".');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('emerg_ac', 0, 1, 'string', 1, 'The area code that will be used for routing of dialed emergency numbers without an area code. Defaults to "ac".');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('block_out_override_pin', 0, 1, 'string', 1, 'A PIN code which may be used in a VSC to disable the outgoing user block list and NCOS level for a call.');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('adm_block_out_override_pin', 0, 1, 'string', 1, 'Same as "block_out_override_pin" but additionally disables the administrative block list and NCOS level.');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('allowed_clis', 0, 1, 'string', 0, 'A list of shell patterns specifying which CLIs are allowed to be set by the subscriber. "*", "?" and "[x-y]" with "x" and "y" representing numbers from 0 to 9 may be used as wildcards as usual in shell patterns.');
INSERT INTO voip_preferences (attribute, type, dom_pref, usr_pref, data_type, max_occur, description) VALUES('e164_to_ruri', 1, 0, 1, 'boolean', 1, 'Send the E164 number instead of SIP AOR as request username when sending INVITE to the subscriber. If a 404 is received the SIP AOR is sent as request URI as fallback.');
-- "external" kamailio preferences - only used for documentation and provisioning parameter checks
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, internal, description)
VALUES('ncos', 0, 1, 'string', 1, -1, 'Specifies the NCOS level that applies to the user.');
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, internal, description)
VALUES('adm_ncos', 0, 1, 'string', 1, -1, 'Same as "ncos", but may only be set by administrators and is applied prior to the user setting.');
-- "internal" kamailio preferences - not directly accessible via provisioning (often mapped to an "external" preference somehow)
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, internal) VALUES('ncos_id', 1, 1, 'int', 1, 1);
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, internal) VALUES('adm_ncos_id', 1, 1, 'int', 1, 1);
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, internal) VALUES('account_id', 1, 1, 'int', 1, 1);
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, internal) VALUES('ext_contract_id', 0, 1, 'string', 1, 1);
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, internal) VALUES('ext_subscriber_id', 0, 1, 'string', 1, 1);
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, internal) VALUES('prepaid', 1, 1, 'boolean', 1, 1);
-- domain preferences
INSERT INTO voip_preferences (attribute, type, dom_pref, data_type, max_occur, description) VALUES('unauth_inbound_calls', 1, 1, 'boolean', 1, 'Allow unauthenticated inbound calls from FOREIGN domain to users within this domain. Use with care - it allows to flood your users with voice spam.');
-- peer preferences
INSERT INTO voip_preferences (attribute, type, usr_pref, peer_pref, data_type, max_occur, description)
VALUES('peer_auth_user', 0, 1, 1, 'string', 1, 'A username used for authentication against a peer host.');
INSERT INTO voip_preferences (attribute, type, usr_pref, peer_pref, data_type, max_occur, description)
VALUES('peer_auth_pass', 0, 1, 1, 'string', 1, 'A password used for authentication against a peer host.');
INSERT INTO voip_preferences (attribute, type, usr_pref, peer_pref, data_type, max_occur, description)
VALUES('peer_auth_realm', 0, 1, 1, 'string', 1, 'A realm (hostname) used to identify and for authentication against a peer host.');
INSERT INTO voip_preferences (attribute, type, dom_pref, usr_pref, peer_pref, data_type, max_occur, description) VALUES('find_subscriber_by_auth_user', 1, 0, 0, 1, 'boolean', 1, 'For incoming calls from this peer, find the destination subscriber also using its auth_username used for outbound registration.');
-- user + domain preferences
INSERT INTO voip_preferences (attribute, type, dom_pref, usr_pref, data_type, max_occur, description) VALUES('omit_outbound_displayname', 1, 1, 1, 'boolean', 1, 'Suppress the caller display-name that is put in the SIP "From" header on outgoing calls.');
INSERT INTO voip_preferences (attribute, type, dom_pref, usr_pref, data_type, max_occur, description) VALUES('force_inbound_calls_to_peer', 1, 1, 1, 'boolean', 1, 'Force calls to this user to be treated as if the user was not local. This helps in migration scenarios.');
-- user + domain + peer preferences
INSERT INTO voip_preferences (attribute, type, dom_pref, usr_pref, peer_pref, data_type, max_occur, description) VALUES('always_use_rtpproxy', 1, 1, 1, 1, 'boolean', 1, 'Force rtp relay for this peer/domain/user.');
INSERT INTO voip_preferences (attribute, type, dom_pref, usr_pref, peer_pref, data_type, max_occur, description) VALUES('never_use_rtpproxy', 1, 1, 1, 1, 'boolean', 1, 'Do not use rtp relay for this peer/domain/user. Rtp will be relayed if other participants have always_use_rtpproxy preference enabled.');
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, description) VALUES('peer_auth_register', 1, 1, 1, 1, 'boolean', 1, 'Specifies whether registration at the peer host is desired.');
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, description) VALUES('concurrent_max', 1, 1, 1, 1, 'int', 1, 'Maximum number of concurrent sessions (calls) for a subscriber or peer.');
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, description) VALUES('concurrent_max_out', 1, 1, 1, 1, 'int', 1, 'Maximum number of concurrent outgoing sessions (calls) coming from a subscriber or going to a peer.');
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, description) VALUES('force_outbound_calls_to_peer', 1, 1, 1, 1, 'boolean', 1, 'Force calls from this user/domain/peer to be routed to PSTN even if the callee is local. Use with caution, as this setting may increase your costs! When enabling this option in a peer, make sure you trust it, as the NGCP will become an open relay for it!');
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, internal, description)
VALUES('rewrite_rule_set', 1, 1, 1, 1, 'int', 1, -1, 'Specifies the list of caller and callee rewrite rules which should be applied for incoming and outgoing calls.');
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, internal)
VALUES('rewrite_caller_in_dpid', 1, 1, 1, 1, 'int', 1, 1);
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, internal)
VALUES('rewrite_callee_in_dpid', 1, 1, 1, 1, 'int', 1, 1);
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, internal)
VALUES('rewrite_caller_out_dpid', 1, 1, 1, 1, 'int', 1, 1);
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, internal)
VALUES('rewrite_callee_out_dpid', 1, 1, 1, 1, 'int', 1, 1);
INSERT INTO voip_preferences (attribute, type, dom_pref, usr_pref, peer_pref, data_type, max_occur, description) VALUES('always_use_ipv4_for_rtpproxy', 1, 1, 1, 1, 'boolean', 1, 'Always force the IPv4 address for the RTP relay, regardless of what is autodetected on SIP/SDP level. This is mutually exclusive with always_use_ipv6_for_rtpproxy.');
INSERT INTO voip_preferences (attribute, type, dom_pref, usr_pref, peer_pref, data_type, max_occur, description) VALUES('always_use_ipv6_for_rtpproxy', 1, 1, 1, 1, 'boolean', 1, 'Always force the IPv6 address for the RTP relay, regardless of what is autodetected on SIP/SDP level. This is mutually exclusive with always_use_ipv4_for_rtpproxy.');

@ -0,0 +1,390 @@
USE mysql;
DROP DATABASE IF EXISTS kamailio;
CREATE DATABASE IF NOT EXISTS kamailio CHARACTER SET 'utf8';
USE kamailio;
CREATE TABLE `acc` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`method` varchar(16) NOT NULL DEFAULT '',
`from_tag` varchar(64) NOT NULL DEFAULT '',
`to_tag` varchar(64) NOT NULL DEFAULT '',
`callid` varchar(255) NOT NULL DEFAULT '',
`sip_code` varchar(3) NOT NULL DEFAULT '',
`sip_reason` varchar(128) NOT NULL DEFAULT '',
`time` datetime NOT NULL,
`time_hires` decimal(13,3) NOT NULL,
`src_leg` varchar(2048) default NULL,
`dst_leg` varchar(2048) default NULL,
`dst_user` varchar(64) NOT NULL default '',
`dst_ouser` varchar(64) NOT NULL default '',
`dst_domain` varchar(128) NOT NULL default '',
`src_user` varchar(64) NOT NULL default '',
`src_domain` varchar(128) NOT NULL default '',
PRIMARY KEY (`id`),
KEY `callid_idx` (`callid`)
) ENGINE=InnoDB;
CREATE TABLE `dbaliases` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`alias_username` varchar(64) NOT NULL DEFAULT '',
`alias_domain` varchar(64) NOT NULL DEFAULT '',
`username` varchar(64) NOT NULL DEFAULT '',
`domain` varchar(64) NOT NULL DEFAULT '',
PRIMARY KEY (`id`),
UNIQUE KEY `alias_idx` (`alias_username`,`alias_domain`),
KEY `target_idx` (`username`,`domain`)
) ENGINE=InnoDB;
CREATE TABLE `dialog` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`hash_entry` int(10) unsigned NOT NULL,
`hash_id` int(10) unsigned NOT NULL,
`callid` varchar(255) NOT NULL,
`from_uri` varchar(128) NOT NULL,
`from_tag` varchar(64) NOT NULL,
`to_uri` varchar(128) NOT NULL,
`to_tag` varchar(64) NOT NULL,
`caller_cseq` varchar(7) NOT NULL,
`callee_cseq` varchar(7) NOT NULL,
`caller_route_set` varchar(512) DEFAULT NULL,
`callee_route_set` varchar(512) DEFAULT NULL,
`caller_contact` varchar(128) NOT NULL,
`callee_contact` varchar(128) NOT NULL,
`caller_sock` varchar(64) NOT NULL,
`callee_sock` varchar(64) NOT NULL,
`state` int(10) unsigned NOT NULL,
`start_time` int(10) unsigned NOT NULL,
`timeout` int(10) unsigned NOT NULL DEFAULT '0',
`sflags` int(10) unsigned NOT NULL DEFAULT '0',
`toroute` int(10) unsigned NOT NULL DEFAULT '0',
`req_uri` varchar(128) NOT NULL,
PRIMARY KEY (`id`),
KEY `hash_idx` (`hash_entry`,`hash_id`)
) ENGINE=InnoDB;
CREATE TABLE `dialplan` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`dpid` int(11) NOT NULL,
`pr` int(11) NOT NULL,
`match_op` int(11) NOT NULL,
`match_exp` varchar(64) NOT NULL,
`match_len` int(11) NOT NULL,
`subst_exp` varchar(64) NOT NULL,
`repl_exp` varchar(64) NOT NULL,
`attrs` varchar(32) NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB;
CREATE TABLE `dispatcher` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`setid` int(11) NOT NULL DEFAULT '0',
`destination` varchar(192) NOT NULL DEFAULT '',
`flags` int(11) NOT NULL DEFAULT '0',
`priority` int(11) NOT NULL DEFAULT '0',
`description` varchar(64) NOT NULL DEFAULT '',
PRIMARY KEY (`id`)
) ENGINE=InnoDB;
CREATE TABLE `domain` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`domain` varchar(64) NOT NULL DEFAULT '',
`last_modified` datetime NOT NULL DEFAULT '1900-01-01 00:00:01',
PRIMARY KEY (`id`),
UNIQUE KEY `domain_idx` (`domain`)
) ENGINE=InnoDB;
CREATE TABLE `lcr_gw` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`lcr_id` smallint(5) unsigned NOT NULL,
`gw_name` varchar(128) NOT NULL,
`ip_addr` varchar(64) NOT NULL,
`hostname` varchar(64) DEFAULT NULL,
`port` smallint(5) unsigned DEFAULT NULL,
`params` varchar(64) DEFAULT NULL,
`uri_scheme` tinyint(3) unsigned DEFAULT NULL,
`transport` tinyint(3) unsigned DEFAULT NULL,
`strip` tinyint(3) unsigned DEFAULT NULL,
`tag` varchar(16) DEFAULT NULL,
`flags` int(10) unsigned NOT NULL DEFAULT '0',
`defunct` int(10) unsigned DEFAULT NULL,
`group_id` int(11) unsigned NOT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `lcr_id_gw_name_idx` (`lcr_id`,`gw_name`),
UNIQUE KEY `lcr_id_ip_addr_idx` (`lcr_id`,`ip_addr`)
) ENGINE=InnoDB;
CREATE TABLE `lcr_rule` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`lcr_id` smallint(5) unsigned NOT NULL,
`prefix` varchar(16) DEFAULT NULL,
`from_uri` varchar(64) DEFAULT NULL,
`stopper` int(10) unsigned NOT NULL DEFAULT '0',
`enabled` int(10) unsigned NOT NULL DEFAULT '1',
`group_id` int(11) unsigned NOT NULL,
PRIMARY KEY (`id`),
KEY `lcr_id_idx` (`lcr_id`)
) ENGINE=InnoDB;
CREATE TABLE `lcr_rule_target` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`lcr_id` smallint(5) unsigned NOT NULL,
`rule_id` int(10) unsigned NOT NULL,
`gw_id` int(10) unsigned NOT NULL,
`priority` tinyint(3) unsigned NOT NULL,
`weight` int(10) unsigned NOT NULL DEFAULT '1',
PRIMARY KEY (`id`),
UNIQUE KEY `rule_id_gw_id_idx` (`rule_id`,`gw_id`),
KEY `lcr_id_idx` (`lcr_id`),
KEY `gw_id_idx` (`gw_id`),
CONSTRAINT `l_r_t_ruleid_ref` FOREIGN KEY (`rule_id`)
REFERENCES `lcr_rule` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `l_r_t_gwid_ref` FOREIGN KEY (`gw_id`)
REFERENCES `lcr_gw` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `location` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`username` varchar(64) NOT NULL DEFAULT '',
`domain` varchar(64) DEFAULT NULL,
`contact` varchar(255) NOT NULL DEFAULT '',
`received` varchar(128) DEFAULT NULL,
`path` varchar(128) DEFAULT NULL,
`expires` datetime NOT NULL DEFAULT '2020-05-28 21:32:15',
`q` float(10,2) NOT NULL DEFAULT '1.00',
`callid` varchar(255) NOT NULL DEFAULT 'Default-Call-ID',
`cseq` int(11) NOT NULL DEFAULT '13',
`last_modified` datetime NOT NULL DEFAULT '1900-01-01 00:00:01',
`flags` int(11) NOT NULL DEFAULT '0',
`cflags` int(11) NOT NULL DEFAULT '0',
`user_agent` varchar(255) NOT NULL DEFAULT '',
`socket` varchar(64) DEFAULT NULL,
`methods` int(11) DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `account_contact_idx` (`username`,`domain`,`contact`)
) ENGINE=InnoDB;
CREATE TABLE `speed_dial` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`username` varchar(64) NOT NULL DEFAULT '',
`domain` varchar(64) NOT NULL DEFAULT '',
`sd_username` varchar(64) NOT NULL DEFAULT '',
`sd_domain` varchar(64) NOT NULL DEFAULT '',
`new_uri` varchar(128) NOT NULL DEFAULT '',
`fname` varchar(64) NOT NULL DEFAULT '',
`lname` varchar(64) NOT NULL DEFAULT '',
`description` varchar(64) NOT NULL DEFAULT '',
PRIMARY KEY (`id`),
UNIQUE KEY `speed_dial_idx` (`username`,`domain`,`sd_domain`,`sd_username`)
) ENGINE=InnoDB;
CREATE TABLE `subscriber` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`username` varchar(64) NOT NULL DEFAULT '',
`domain` varchar(64) NOT NULL DEFAULT '',
`password` varchar(40) NOT NULL DEFAULT '',
`email_address` varchar(64) NOT NULL DEFAULT '',
`ha1` varchar(64) NOT NULL DEFAULT '',
`ha1b` varchar(64) NOT NULL DEFAULT '',
`rpid` varchar(64) DEFAULT NULL,
`uuid` char(36) NOT NULL,
`timezone` varchar(64) NOT NULL DEFAULT '',
`datetime_created` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
PRIMARY KEY (`id`),
UNIQUE KEY `account_idx` (`username`,`domain`),
KEY `username_idx` (`username`)
) ENGINE=InnoDB;
CREATE TABLE `trusted` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`src_ip` varchar(50) NOT NULL,
`proto` varchar(4) NOT NULL,
`from_pattern` varchar(64) DEFAULT NULL,
`tag` varchar(64) DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `peer_idx` (`src_ip`)
) ENGINE=InnoDB;
CREATE TABLE `usr_preferences` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`uuid` char(36) NOT NULL,
`username` varchar(128) NOT NULL DEFAULT '0',
`domain` varchar(64) NOT NULL DEFAULT '',
`attribute` varchar(32) NOT NULL DEFAULT '',
`type` int(11) NOT NULL DEFAULT '0',
`value` varchar(128) NOT NULL DEFAULT '',
`last_modified` datetime NOT NULL DEFAULT '1900-01-01 00:00:01',
PRIMARY KEY (`id`),
KEY `ua_idx` (`uuid`,`attribute`),
KEY `uda_idx` (`username`,`domain`,`attribute`)
) ENGINE=InnoDB;
CREATE TABLE `dom_preferences` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`uuid` char(36) NOT NULL,
`username` varchar(128) NOT NULL DEFAULT '0',
`domain` varchar(64) NOT NULL DEFAULT '',
`attribute` varchar(32) NOT NULL DEFAULT '',
`type` int(11) NOT NULL DEFAULT '0',
`value` varchar(128) NOT NULL DEFAULT '',
`last_modified` datetime NOT NULL DEFAULT '1900-01-01 00:00:01',
PRIMARY KEY (`id`),
KEY `ua_idx` (`uuid`,`attribute`),
KEY `uda_idx` (`username`,`domain`,`attribute`)
) ENGINE=InnoDB;
CREATE TABLE `peer_preferences` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`uuid` varchar(36) NOT NULL,
`username` varchar(128) NOT NULL DEFAULT '0',
`domain` varchar(64) NOT NULL DEFAULT '',
`attribute` varchar(32) NOT NULL DEFAULT '',
`type` int(11) NOT NULL DEFAULT '0',
`value` varchar(128) NOT NULL DEFAULT '',
`last_modified` datetime NOT NULL DEFAULT '1900-01-01 00:00:01',
PRIMARY KEY (`id`),
KEY `ua_idx` (`uuid`,`attribute`)
-- not used -- KEY `uda_idx` (`username`,`domain`,`attribute`)
) ENGINE=InnoDB;
CREATE TABLE `address` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`grp` smallint(5) unsigned NOT NULL DEFAULT '0',
`ip_addr` varchar(15) NOT NULL,
`mask` tinyint(4) NOT NULL DEFAULT '32',
`port` smallint(5) unsigned NOT NULL DEFAULT '0',
`tag` VARCHAR(64),
PRIMARY KEY (`id`)
) ENGINE=InnoDB;
CREATE TABLE `version` (
`table_name` varchar(32) NOT NULL,
`table_version` int(10) unsigned NOT NULL DEFAULT '0'
) ENGINE=InnoDB;
CREATE TABLE `voicemail_users` (
`uniqueid` int(10) unsigned NOT NULL AUTO_INCREMENT,
`customer_id` char(36) NOT NULL DEFAULT '',
`context` varchar(63) NOT NULL DEFAULT 'default',
`mailbox` varchar(31) NOT NULL,
`password` varchar(31) NOT NULL DEFAULT '0',
`fullname` varchar(255) NOT NULL DEFAULT '',
`email` varchar(255) NOT NULL DEFAULT '',
`pager` varchar(255) NOT NULL DEFAULT '',
`tz` varchar(10) NOT NULL DEFAULT 'central',
`attach` varchar(4) NOT NULL DEFAULT 'yes',
`saycid` varchar(4) NOT NULL DEFAULT 'yes',
`dialout` varchar(10) NOT NULL DEFAULT '',
`callback` varchar(10) NOT NULL DEFAULT '',
`review` varchar(4) NOT NULL DEFAULT 'no',
`operator` varchar(4) NOT NULL DEFAULT 'no',
`envelope` varchar(4) NOT NULL DEFAULT 'no',
`sayduration` varchar(4) NOT NULL DEFAULT 'no',
`saydurationm` tinyint(4) NOT NULL DEFAULT '1',
`sendvoicemail` varchar(4) NOT NULL DEFAULT 'no',
`delete` varchar(4) NOT NULL DEFAULT 'no',
`nextaftercmd` varchar(4) NOT NULL DEFAULT 'yes',
`forcename` varchar(4) NOT NULL DEFAULT 'no',
`forcegreetings` varchar(4) NOT NULL DEFAULT 'no',
`hidefromdir` varchar(4) NOT NULL DEFAULT 'yes',
`stamp` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
PRIMARY KEY (`uniqueid`),
KEY `customer_idx` (`customer_id`),
KEY `mailbox_context` (`mailbox`,`context`)
) ENGINE=InnoDB;
CREATE TABLE `voicemail_spool` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`msgnum` int(11) NOT NULL DEFAULT '0',
`dir` varchar(127) DEFAULT '',
`context` varchar(63) DEFAULT '',
`macrocontext` varchar(63) DEFAULT '',
`callerid` varchar(255) DEFAULT '',
`origtime` varchar(16) DEFAULT '',
`duration` varchar(16) DEFAULT '',
`mailboxuser` varchar(255) DEFAULT '',
`mailboxcontext` varchar(63) DEFAULT '',
`recording` longblob,
PRIMARY KEY (`id`),
KEY `dir` (`dir`),
KEY `mailboxuser_idx` (`mailboxuser`),
CONSTRAINT `v_s_mailboxuser_ref` FOREIGN KEY (`mailboxuser`) REFERENCES `voicemail_users` (`customer_id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `fax_preferences` (
`subscriber_id` int(10) unsigned NOT NULL,
`password` varchar(64) default NULL,
`name` varchar(64) default NULL,
`active` enum('true','false') NOT NULL default 'true',
`send_status` enum('true','false') NOT NULL default 'false',
`send_copy` enum('true','false') NOT NULL default 'false',
`send_copy_cc` enum('true','false') NOT NULL default 'false',
PRIMARY KEY (`subscriber_id`)
) ENGINE=InnoDB;
CREATE TABLE `fax_destinations` (
`id` int(10) unsigned NOT NULL auto_increment,
`subscriber_id` int(10) unsigned NOT NULL,
`destination` varchar(64) NOT NULL,
`filetype` enum('ps','tiff','pdf','pdf14') NOT NULL default 'tiff',
`cc` enum('true','false') NOT NULL default 'false',
`incoming` enum('true','false') NOT NULL default 'true',
`outgoing` enum('true','false') NOT NULL default 'false',
`status` enum('true','false') NOT NULL default 'false',
PRIMARY KEY (`id`),
KEY `subscriber_id` (`subscriber_id`)
) ENGINE=InnoDB;
CREATE TABLE `sems_registrations` (
`subscriber_id` int(11) NOT NULL,
`registration_status` tinyint(1) NOT NULL DEFAULT '0',
`last_registration` datetime DEFAULT NULL,
`expiry` datetime DEFAULT NULL,
`last_code` smallint(2) DEFAULT NULL,
`last_reason` varchar(256) DEFAULT NULL,
`contacts` varchar(512) DEFAULT NULL,
PRIMARY KEY (`subscriber_id`)
) ENGINE=InnoDB;
CREATE TABLE `fax_journal` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`subscriber_id` int(10) unsigned NOT NULL DEFAULT '0',
`the_timestamp` int(11) unsigned NOT NULL DEFAULT '0',
`duration` int(11) unsigned NOT NULL DEFAULT '0',
`direction` enum('in','out') NOT NULL DEFAULT 'in',
`peer_number` varchar(255) NOT NULL DEFAULT '',
`peer_name` varchar(255) NOT NULL DEFAULT '',
`pages` int(10) unsigned NOT NULL DEFAULT '0',
`reason` varchar(255) NOT NULL,
`status` varchar(255) NOT NULL DEFAULT '',
`signal_rate` int(10) unsigned NOT NULL DEFAULT '0',
`quality` varchar(255) NOT NULL DEFAULT '',
`filename` varchar(255) NOT NULL DEFAULT '',
PRIMARY KEY (`id`),
KEY `selkey` (`subscriber_id`,`direction`)
) ENGINE=InnoDB;
INSERT INTO `version` VALUES
('acc',4),
('lcr_gw',1),
('lcr_rule_target',1),
('lcr_rule',1),
('domain',1),
('trusted',5),
('location',1004),
('dbaliases',1),
('speed_dial',2),
('usr_preferences',2),
('subscriber',6),
('dialog',4),
('dispatcher',3),
('address',4),
('dialplan',1);
INSERT INTO `dispatcher` VALUES ('1','2','sip:127.0.0.1:5070','0','0','Voicemail servers');
INSERT INTO `dispatcher` VALUES ('2','3','sip:127.0.0.1:5080','0','0','Application servers');
INSERT INTO `dispatcher` VALUES ('3','4','sip:127.0.0.1:5090','0','0','Fax2Mail servers');

@ -0,0 +1,930 @@
USE provisioning;
-- create triggers that populate kamailio tables
DELIMITER |
CREATE TRIGGER voip_sub_crepl_trig AFTER INSERT ON voip_subscribers
FOR EACH ROW BEGIN
DECLARE subscriber_domain varchar(127);
SELECT domain INTO subscriber_domain FROM voip_domains where id = NEW.domain_id;
INSERT INTO kamailio.subscriber (username, domain, uuid, password, datetime_created, ha1, ha1b)
VALUES(NEW.username, subscriber_domain, NEW.uuid, NEW.password, now(),
MD5(CONCAT(NEW.username, ':', subscriber_domain, ':', NEW.password)),
MD5(CONCAT(NEW.username, '@', subscriber_domain, ':', subscriber_domain, ':', NEW.password)));
END;
|
CREATE TRIGGER voip_sub_urepl_trig AFTER UPDATE ON voip_subscribers
FOR EACH ROW BEGIN
DECLARE old_subscriber_domain varchar(127);
DECLARE new_subscriber_domain varchar(127);
SELECT domain INTO old_subscriber_domain FROM voip_domains where id = OLD.domain_id;
SELECT domain INTO new_subscriber_domain FROM voip_domains where id = NEW.domain_id;
UPDATE kamailio.subscriber SET username = NEW.username, domain = new_subscriber_domain,
uuid = NEW.uuid, password = NEW.password,
ha1 = MD5(CONCAT(NEW.username, ':', new_subscriber_domain, ':', NEW.password)),
ha1b = MD5(CONCAT(NEW.username, '@', new_subscriber_domain, ':', new_subscriber_domain, ':', NEW.password))
WHERE username = OLD.username
AND domain = old_subscriber_domain;
END;
|
CREATE TRIGGER voip_sub_drepl_trig BEFORE DELETE ON voip_subscribers
FOR EACH ROW BEGIN
DECLARE subscriber_domain varchar(127);
DECLARE os_subscriber_id int(10) UNSIGNED;
SELECT domain INTO subscriber_domain FROM voip_domains where id = OLD.domain_id;
SELECT id INTO os_subscriber_id FROM kamailio.subscriber
WHERE username = OLD.username AND domain = subscriber_domain;
DELETE FROM kamailio.subscriber WHERE username = OLD.username
AND domain = subscriber_domain;
-- should be implemented via a provisioning.voicemail_users table
-- and a foreign key to voip_subscribers
DELETE FROM kamailio.voicemail_users WHERE customer_id = OLD.uuid;
-- work around MySQL bug. the cascaded delete should trigger our
-- delete actions on the provisioning tables, but doesn't
DELETE FROM kamailio.usr_preferences WHERE username = OLD.username
AND domain = subscriber_domain;
DELETE FROM kamailio.dbaliases WHERE username = OLD.username
AND domain = subscriber_domain;
DELETE FROM kamailio.speed_dial WHERE username = OLD.username
AND domain = subscriber_domain;
DELETE FROM kamailio.fax_preferences WHERE subscriber_id = os_subscriber_id;
DELETE FROM kamailio.fax_destinations WHERE subscriber_id = os_subscriber_id;
END;
|
CREATE TRIGGER voip_dba_crepl_trig AFTER INSERT ON voip_dbaliases
FOR EACH ROW BEGIN
DECLARE dbalias_domain varchar(127);
DECLARE target_username varchar(127);
DECLARE target_domain varchar(127);
SELECT domain INTO dbalias_domain FROM voip_domains where id = NEW.domain_id;
SELECT a.username, b.domain INTO target_username, target_domain
FROM voip_subscribers a, voip_domains b
WHERE a.id = NEW.subscriber_id
AND b.id = a.domain_id;
INSERT INTO kamailio.dbaliases (alias_username, alias_domain, username, domain)
VALUES(NEW.username, dbalias_domain, target_username, target_domain);
END;
|
CREATE TRIGGER voip_dba_urepl_trig AFTER UPDATE ON voip_dbaliases
FOR EACH ROW BEGIN
DECLARE old_dbalias_domain varchar(127);
DECLARE new_dbalias_domain varchar(127);
DECLARE target_username varchar(127);
DECLARE target_domain varchar(127);
SELECT domain INTO old_dbalias_domain FROM voip_domains where id = OLD.domain_id;
SELECT domain INTO new_dbalias_domain FROM voip_domains where id = NEW.domain_id;
SELECT a.username, b.domain INTO target_username, target_domain
FROM voip_subscribers a, voip_domains b
WHERE a.id = NEW.subscriber_id
AND b.id = a.domain_id;
UPDATE kamailio.dbaliases SET alias_username = NEW.username, alias_domain = new_dbalias_domain,
username = target_username, domain = target_domain
WHERE alias_username = OLD.username
AND alias_domain = old_dbalias_domain;
END;
|
CREATE TRIGGER voip_dba_drepl_trig BEFORE DELETE ON voip_dbaliases
FOR EACH ROW BEGIN
DECLARE dbalias_domain varchar(127);
SELECT domain INTO dbalias_domain FROM voip_domains where id = OLD.domain_id;
DELETE FROM kamailio.dbaliases WHERE alias_username = OLD.username
AND alias_domain = dbalias_domain;
END;
|
CREATE TRIGGER voip_prul_crepl_trig AFTER INSERT ON voip_peer_rules
FOR EACH ROW BEGIN
INSERT INTO kamailio.lcr_rule (lcr_id, prefix, from_uri, stopper, enabled, group_id)
VALUES(1, NEW.callee_prefix, NEW.caller_prefix,
0, 1, NEW.group_id);
INSERT INTO kamailio.lcr_rule_target (lcr_id, rule_id, gw_id, priority, weight)
SELECT gw.lcr_id, LAST_INSERT_ID(), gw.id, vpg.priority, vph.weight
FROM kamailio.lcr_gw gw
INNER JOIN provisioning.voip_peer_hosts vph ON vph.ip = gw.ip_addr
AND gw.lcr_id = 1
AND vph.group_id = gw.group_id
INNER JOIN provisioning.voip_peer_groups vpg ON vpg.id = vph.group_id
WHERE vph.group_id = NEW.group_id;
END;
|
CREATE TRIGGER voip_prul_urepl_trig AFTER UPDATE ON voip_peer_rules
FOR EACH ROW BEGIN
UPDATE kamailio.lcr_rule
SET prefix = NEW.callee_prefix, from_uri = NEW.caller_prefix
WHERE prefix = OLD.callee_prefix
AND from_uri = OLD.caller_prefix
AND group_id = OLD.group_id;
END;
|
CREATE TRIGGER voip_prul_drepl_trig AFTER DELETE ON voip_peer_rules
FOR EACH ROW BEGIN
DELETE FROM kamailio.lcr_rule
WHERE prefix = OLD.callee_prefix
AND from_uri = OLD.caller_prefix
AND group_id = OLD.group_id;
-- foreign key will delete from kamailio.lcr_rule_target
END;
|
CREATE TRIGGER voip_pgrp_urepl_trig AFTER UPDATE ON voip_peer_groups
FOR EACH ROW BEGIN
UPDATE kamailio.lcr_rule_target rt, kamailio.lcr_gw gw
SET rt.priority = NEW.priority
WHERE gw.id = rt.gw_id
AND gw.lcr_id = 1
AND gw.group_id = NEW.id;
END;
|
CREATE TRIGGER voip_pgrp_drepl_trig AFTER DELETE ON voip_peer_groups
FOR EACH ROW BEGIN
DELETE FROM kamailio.lcr_rule WHERE group_id = OLD.id;
DELETE FROM kamailio.lcr_gw WHERE group_id = OLD.id;
END;
|
CREATE TRIGGER voip_phost_crepl_trig AFTER INSERT ON voip_peer_hosts
FOR EACH ROW BEGIN
INSERT INTO kamailio.lcr_gw (lcr_id, gw_name, ip_addr, hostname, port, uri_scheme, transport, strip, flags, group_id)
VALUES(1, NEW.name, NEW.ip, NEW.host, NEW.port, 1, 1, 0, NEW.id, NEW.group_id);
INSERT INTO kamailio.lcr_rule_target (lcr_id, rule_id, gw_id, priority, weight)
SELECT rule.lcr_id, rule.id, LAST_INSERT_ID(), vpg.priority, NEW.weight
FROM kamailio.lcr_rule rule
INNER JOIN provisioning.voip_peer_groups vpg ON vpg.id = rule.group_id
WHERE vpg.id = NEW.group_id;
END;
|
CREATE TRIGGER voip_phost_urepl_trig AFTER UPDATE ON voip_peer_hosts
FOR EACH ROW BEGIN
UPDATE kamailio.lcr_gw
SET gw_name = NEW.name, ip_addr = NEW.ip, hostname = NEW.host, port = NEW.port, flags = NEW.id
WHERE lcr_id = 1 AND ip_addr = OLD.ip;
UPDATE kamailio.lcr_rule_target rt, kamailio.lcr_gw gw
SET rt.weight = NEW.weight
WHERE gw.id = rt.gw_id
AND gw.lcr_id = 1
AND gw.group_id = NEW.group_id
AND gw.ip_addr = NEW.ip;
END;
|
CREATE TRIGGER voip_phost_drepl_trig AFTER DELETE ON voip_peer_hosts
FOR EACH ROW BEGIN
DELETE FROM kamailio.lcr_gw
WHERE lcr_id = 1
AND group_id = OLD.group_id
AND ip_addr = OLD.ip;
-- foreign key will delete from kamailio.lcr_rule_target
END;
|
CREATE TRIGGER voip_peerpref_crepl_trig AFTER INSERT ON voip_peer_preferences
FOR EACH ROW BEGIN
INSERT INTO kamailio.peer_preferences
(id, uuid, attribute, type, value, last_modified)
SELECT NEW.id, NEW.peer_host_id, attribute, type, NEW.value, NOW()
FROM provisioning.voip_preferences
WHERE id = NEW.attribute_id;
END;
|
CREATE TRIGGER voip_peerpref_urepl_trig AFTER UPDATE ON voip_peer_preferences
FOR EACH ROW BEGIN
UPDATE kamailio.peer_preferences pp, provisioning.voip_preferences vp
SET pp.id = NEW.id, pp.uuid = NEW.peer_host_id, pp.type = vp.type,
pp.attribute = vp.attribute, pp.value = NEW.value, pp.last_modified = NOW()
WHERE pp.id = OLD.id
AND vp.id = NEW.attribute_id;
END;
|
CREATE TRIGGER voip_peerpref_drepl_trig BEFORE DELETE ON voip_peer_preferences
FOR EACH ROW BEGIN
DELETE FROM kamailio.peer_preferences
WHERE id = OLD.id;
END;
|
CREATE TRIGGER voip_usrpref_crepl_trig AFTER INSERT ON voip_usr_preferences
FOR EACH ROW BEGIN
DECLARE subscriber_username varchar(127);
DECLARE subscriber_domain varchar(127);
DECLARE subscriber_uuid char(36);
DECLARE attribute_name varchar(31);
DECLARE attribute_type tinyint(3);
SELECT a.username, b.domain, a.uuid INTO subscriber_username, subscriber_domain, subscriber_uuid
FROM voip_subscribers a, voip_domains b
WHERE a.id = NEW.subscriber_id
AND a.domain_id = b.id;
SELECT attribute, type INTO attribute_name, attribute_type
FROM voip_preferences
WHERE id = NEW.attribute_id;
INSERT INTO kamailio.usr_preferences (uuid, username, domain, attribute, type, value)
VALUES(subscriber_uuid, subscriber_username, subscriber_domain,
attribute_name, attribute_type, NEW.value);
END;
|
CREATE TRIGGER voip_usrpref_urepl_trig AFTER UPDATE ON voip_usr_preferences
FOR EACH ROW BEGIN
DECLARE old_subscriber_username varchar(127);
DECLARE new_subscriber_username varchar(127);
DECLARE old_subscriber_domain varchar(127);
DECLARE new_subscriber_domain varchar(127);
DECLARE old_attribute_name varchar(31);
DECLARE new_attribute_name varchar(31);
SELECT a.username, b.domain INTO old_subscriber_username, old_subscriber_domain
FROM voip_subscribers a, voip_domains b
WHERE a.id = OLD.subscriber_id
AND a.domain_id = b.id;
SELECT a.username, b.domain INTO new_subscriber_username, new_subscriber_domain
FROM voip_subscribers a, voip_domains b
WHERE a.id = NEW.subscriber_id
AND a.domain_id = b.id;
SELECT attribute INTO old_attribute_name
FROM voip_preferences
WHERE id = OLD.attribute_id;
SELECT attribute INTO new_attribute_name
FROM voip_preferences
WHERE id = NEW.attribute_id;
UPDATE kamailio.usr_preferences SET username = new_subscriber_username, domain = new_subscriber_domain,
attribute = new_attribute_name, value = NEW.value
WHERE username = old_subscriber_username
AND domain = old_subscriber_domain
AND attribute = old_attribute_name
AND value = OLD.value;
END;
|
CREATE TRIGGER voip_usrpref_drepl_trig BEFORE DELETE ON voip_usr_preferences
FOR EACH ROW BEGIN
DECLARE subscriber_username varchar(127);
DECLARE subscriber_domain varchar(127);
DECLARE attribute_name varchar(31);
SELECT a.username, b.domain INTO subscriber_username, subscriber_domain
FROM voip_subscribers a, voip_domains b
WHERE a.id = OLD.subscriber_id
AND a.domain_id = b.id;
SELECT attribute INTO attribute_name
FROM voip_preferences
WHERE id = OLD.attribute_id;
DELETE FROM kamailio.usr_preferences WHERE username = subscriber_username
AND domain = subscriber_domain
AND attribute = attribute_name
AND value = OLD.value;
END;
|
CREATE TRIGGER voip_rwrules_crepl_trig AFTER INSERT ON voip_rewrite_rules
FOR EACH ROW BEGIN
DECLARE new_set_id int(11) unsigned;
SELECT IF(NEW.direction = 'in', IF(NEW.field = 'caller', caller_in_dpid, callee_in_dpid), IF(NEW.field = 'caller', caller_out_dpid, callee_out_dpid))
INTO new_set_id FROM voip_rewrite_rule_sets WHERE id = NEW.set_id;
INSERT INTO kamailio.dialplan (dpid,pr,match_op,match_exp,match_len,subst_exp,repl_exp,attrs)
VALUES(new_set_id,NEW.priority,1,NEW.match_pattern,0,NEW.match_pattern,NEW.replace_pattern,'');
END;
|
CREATE TRIGGER voip_rwrules_urepl_trig AFTER UPDATE ON voip_rewrite_rules
FOR EACH ROW BEGIN
DECLARE old_set_id int(11) unsigned;
DECLARE new_set_id int(11) unsigned;
SELECT IF(OLD.direction = 'in', IF(OLD.field = 'caller', caller_in_dpid, callee_in_dpid), IF(OLD.field = 'caller', caller_out_dpid, callee_out_dpid))
INTO old_set_id FROM voip_rewrite_rule_sets WHERE id = OLD.set_id;
SELECT IF(NEW.direction = 'in', IF(NEW.field = 'caller', caller_in_dpid, callee_in_dpid), IF(NEW.field = 'caller', caller_out_dpid, callee_out_dpid))
INTO new_set_id FROM voip_rewrite_rule_sets WHERE id = NEW.set_id;
UPDATE kamailio.dialplan
SET dpid = new_set_id,
pr = NEW.priority,
match_exp = NEW.match_pattern,
subst_exp = NEW.match_pattern,
repl_exp = NEW.replace_pattern
WHERE dpid = old_set_id
AND pr = OLD.priority
AND match_exp = OLD.match_pattern
AND subst_exp = OLD.match_pattern
AND repl_exp = OLD.replace_pattern;
END;
|
CREATE TRIGGER voip_rwrules_drepl_trig BEFORE DELETE ON voip_rewrite_rules
FOR EACH ROW BEGIN
DECLARE old_set_id int(11) unsigned;
SELECT IF(OLD.direction = 'in', IF(OLD.field = 'caller', caller_in_dpid, callee_in_dpid), IF(OLD.field = 'caller', caller_out_dpid, callee_out_dpid))
INTO old_set_id FROM voip_rewrite_rule_sets WHERE id = OLD.set_id;
DELETE FROM kamailio.dialplan
WHERE dpid = old_set_id
AND pr = OLD.priority
AND match_exp = OLD.match_pattern
AND subst_exp = OLD.match_pattern
AND repl_exp = OLD.replace_pattern;
END;
|
CREATE TRIGGER voip_rwrulesets_crepl_trig BEFORE INSERT ON voip_rewrite_rule_sets
FOR EACH ROW BEGIN
IF NEW.caller_in_dpid IS NULL THEN
INSERT INTO voip_rwrs_sequence VALUES();
SET NEW.caller_in_dpid = (SELECT LAST_INSERT_ID());
END IF;
IF NEW.callee_in_dpid IS NULL THEN
INSERT INTO voip_rwrs_sequence VALUES();
SET NEW.callee_in_dpid = (SELECT LAST_INSERT_ID());
END IF;
IF NEW.caller_out_dpid IS NULL THEN
INSERT INTO voip_rwrs_sequence VALUES();
SET NEW.caller_out_dpid = (SELECT LAST_INSERT_ID());
END IF;
IF NEW.callee_out_dpid IS NULL THEN
INSERT INTO voip_rwrs_sequence VALUES();
SET NEW.callee_out_dpid = (SELECT LAST_INSERT_ID());
END IF;
DELETE a FROM voip_rwrs_sequence a, voip_rwrs_sequence b WHERE a.id < b.id;
END;
|
CREATE TRIGGER voip_rwrulesets_urepl_trig AFTER UPDATE ON voip_rewrite_rule_sets
FOR EACH ROW BEGIN
IF NEW.caller_in_dpid != OLD.caller_in_dpid THEN
UPDATE kamailio.dialplan SET dpid = NEW.caller_in_dpid WHERE dpid = OLD.caller_in_dpid;
UPDATE voip_usr_preferences a, voip_preferences b
SET a.value = NEW.caller_in_dpid
WHERE b.attribute = 'rewrite_caller_in_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.caller_in_dpid;
UPDATE voip_dom_preferences a, voip_preferences b
SET a.value = NEW.caller_in_dpid
WHERE b.attribute = 'rewrite_caller_in_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.caller_in_dpid;
UPDATE voip_peer_preferences a, voip_preferences b
SET a.value = NEW.caller_in_dpid
WHERE b.attribute = 'rewrite_caller_in_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.caller_in_dpid;
END IF;
IF NEW.callee_in_dpid != OLD.callee_in_dpid THEN
UPDATE kamailio.dialplan SET dpid = NEW.callee_in_dpid WHERE dpid = OLD.callee_in_dpid;
UPDATE voip_usr_preferences a, voip_preferences b
SET a.value = NEW.callee_in_dpid
WHERE b.attribute = 'rewrite_callee_in_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.callee_in_dpid;
UPDATE voip_dom_preferences a, voip_preferences b
SET a.value = NEW.callee_in_dpid
WHERE b.attribute = 'rewrite_callee_in_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.callee_in_dpid;
UPDATE voip_peer_preferences a, voip_preferences b
SET a.value = NEW.callee_in_dpid
WHERE b.attribute = 'rewrite_callee_in_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.callee_in_dpid;
END IF;
IF NEW.caller_out_dpid != OLD.caller_out_dpid THEN
UPDATE kamailio.dialplan SET dpid = NEW.caller_out_dpid WHERE dpid = OLD.caller_out_dpid;
UPDATE voip_usr_preferences a, voip_preferences b
SET a.value = NEW.caller_out_dpid
WHERE b.attribute = 'rewrite_caller_out_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.caller_out_dpid;
UPDATE voip_dom_preferences a, voip_preferences b
SET a.value = NEW.caller_out_dpid
WHERE b.attribute = 'rewrite_caller_out_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.caller_out_dpid;
UPDATE voip_peer_preferences a, voip_preferences b
SET a.value = NEW.caller_out_dpid
WHERE b.attribute = 'rewrite_caller_out_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.caller_out_dpid;
END IF;
IF NEW.callee_out_dpid != OLD.callee_out_dpid THEN
UPDATE kamailio.dialplan SET dpid = NEW.callee_out_dpid WHERE dpid = OLD.callee_out_dpid;
UPDATE voip_usr_preferences a, voip_preferences b
SET a.value = NEW.callee_out_dpid
WHERE b.attribute = 'rewrite_callee_out_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.callee_out_dpid;
UPDATE voip_dom_preferences a, voip_preferences b
SET a.value = NEW.callee_out_dpid
WHERE b.attribute = 'rewrite_callee_out_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.callee_out_dpid;
UPDATE voip_peer_preferences a, voip_preferences b
SET a.value = NEW.callee_out_dpid
WHERE b.attribute = 'rewrite_callee_out_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.callee_out_dpid;
END IF;
END;
|
CREATE TRIGGER voip_rwrulesets_drepl_trig BEFORE DELETE ON voip_rewrite_rule_sets
FOR EACH ROW BEGIN
DELETE a FROM voip_usr_preferences a, voip_preferences b
WHERE b.attribute = 'rewrite_caller_in_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.caller_in_dpid;
DELETE a FROM voip_usr_preferences a, voip_preferences b
WHERE b.attribute = 'rewrite_callee_in_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.callee_in_dpid;
DELETE a FROM voip_usr_preferences a, voip_preferences b
WHERE b.attribute = 'rewrite_caller_out_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.caller_out_dpid;
DELETE a FROM voip_usr_preferences a, voip_preferences b
WHERE b.attribute = 'rewrite_callee_out_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.callee_out_dpid;
DELETE a FROM voip_dom_preferences a, voip_preferences b
WHERE b.attribute = 'rewrite_caller_in_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.caller_in_dpid;
DELETE a FROM voip_dom_preferences a, voip_preferences b
WHERE b.attribute = 'rewrite_callee_in_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.callee_in_dpid;
DELETE a FROM voip_dom_preferences a, voip_preferences b
WHERE b.attribute = 'rewrite_caller_out_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.caller_out_dpid;
DELETE a FROM voip_dom_preferences a, voip_preferences b
WHERE b.attribute = 'rewrite_callee_out_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.callee_out_dpid;
DELETE a FROM voip_peer_preferences a, voip_preferences b
WHERE b.attribute = 'rewrite_caller_in_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.caller_in_dpid;
DELETE a FROM voip_peer_preferences a, voip_preferences b
WHERE b.attribute = 'rewrite_callee_in_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.callee_in_dpid;
DELETE a FROM voip_peer_preferences a, voip_preferences b
WHERE b.attribute = 'rewrite_caller_out_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.caller_out_dpid;
DELETE a FROM voip_peer_preferences a, voip_preferences b
WHERE b.attribute = 'rewrite_callee_out_dpid'
AND a.attribute_id = b.id
AND a.value = OLD.callee_out_dpid;
-- work around MySQL bug. the cascaded delete should trigger our
-- voip_dom_preferences delete action, but doesn't
DELETE FROM kamailio.dialplan WHERE dpid = OLD.caller_in_dpid;
DELETE FROM kamailio.dialplan WHERE dpid = OLD.callee_in_dpid;
DELETE FROM kamailio.dialplan WHERE dpid = OLD.caller_out_dpid;
DELETE FROM kamailio.dialplan WHERE dpid = OLD.callee_out_dpid;
END;
|
CREATE TRIGGER voip_pref_urepl_trig AFTER UPDATE ON voip_preferences
FOR EACH ROW BEGIN
IF OLD.attribute != NEW.attribute THEN
UPDATE kamailio.usr_preferences
SET attribute = NEW.attribute
WHERE attribute = OLD.attribute;
UPDATE kamailio.dom_preferences
SET attribute = NEW.attribute
WHERE attribute = OLD.attribute;
UPDATE kamailio.peer_preferences
SET attribute = NEW.attribute
WHERE attribute = OLD.attribute;
END IF;
END;
|
CREATE TRIGGER voip_pref_drepl_trig BEFORE DELETE ON voip_preferences
FOR EACH ROW BEGIN
-- work around MySQL bug. the cascaded delete should trigger our
-- voip_*_preferences delete action, but doesn't
DELETE FROM voip_usr_preferences WHERE attribute_id = OLD.id;
DELETE FROM voip_dom_preferences WHERE attribute_id = OLD.id;
DELETE FROM voip_peer_preferences WHERE attribute_id = OLD.id;
END;
|
CREATE TRIGGER voip_dom_crepl_trig AFTER INSERT ON voip_domains
FOR EACH ROW BEGIN
INSERT INTO kamailio.domain (domain) VALUES(NEW.domain);
END;
|
CREATE TRIGGER voip_dom_drepl_trig BEFORE DELETE ON voip_domains
FOR EACH ROW BEGIN
DELETE FROM kamailio.domain WHERE domain = OLD.domain;
-- work around MySQL bug. the cascaded delete should trigger our
-- voip_dom_preferences delete action, but doesn't
DELETE FROM kamailio.dom_preferences WHERE domain = OLD.domain;
-- this will trigger the delete action for each subscriber
DELETE FROM provisioning.voip_subscribers WHERE domain_id = OLD.id;
END;
|
CREATE TRIGGER voip_dompref_crepl_trig AFTER INSERT ON voip_dom_preferences
FOR EACH ROW BEGIN
DECLARE domain_name varchar(127);
DECLARE attribute_name varchar(31);
DECLARE attribute_type tinyint(3);
SELECT domain INTO domain_name
FROM voip_domains
WHERE id = NEW.domain_id;
SELECT attribute, type INTO attribute_name, attribute_type
FROM voip_preferences
WHERE id = NEW.attribute_id;
INSERT INTO kamailio.dom_preferences (domain, attribute, type, value)
VALUES(domain_name, attribute_name, attribute_type, NEW.value);
END;
|
CREATE TRIGGER voip_dompref_urepl_trig AFTER UPDATE ON voip_dom_preferences
FOR EACH ROW BEGIN
DECLARE old_domain_name varchar(127);
DECLARE new_domain_name varchar(127);
DECLARE old_attribute_name varchar(31);
DECLARE new_attribute_name varchar(31);
SELECT domain INTO old_domain_name
FROM voip_domains
WHERE id = OLD.domain_id;
SELECT domain INTO new_domain_name
FROM voip_domains
WHERE id = NEW.domain_id;
SELECT attribute INTO old_attribute_name
FROM voip_preferences
WHERE id = OLD.attribute_id;
SELECT attribute INTO new_attribute_name
FROM voip_preferences
WHERE id = NEW.attribute_id;
UPDATE kamailio.dom_preferences SET domain = new_domain_name,
attribute = new_attribute_name,
value = NEW.value
WHERE domain = old_domain_name
AND attribute = old_attribute_name
AND value = OLD.value;
END;
|
CREATE TRIGGER voip_dompref_drepl_trig BEFORE DELETE ON voip_dom_preferences
FOR EACH ROW BEGIN
DECLARE domain_name varchar(127);
DECLARE attribute_name varchar(31);
SELECT domain INTO domain_name
FROM voip_domains
WHERE id = OLD.domain_id;
SELECT attribute INTO attribute_name
FROM voip_preferences
WHERE id = OLD.attribute_id;
DELETE FROM kamailio.dom_preferences WHERE domain = domain_name
AND attribute = attribute_name
AND value = OLD.value;
END;
|
CREATE TRIGGER voip_sd_crepl_trig AFTER INSERT ON voip_speed_dial
FOR EACH ROW BEGIN
DECLARE target_username varchar(64);
DECLARE target_domain varchar(64);
SELECT a.username, b.domain INTO target_username, target_domain
FROM voip_subscribers a, voip_domains b
WHERE a.id = NEW.subscriber_id
AND b.id = a.domain_id;
INSERT INTO kamailio.speed_dial (username, domain, sd_username, sd_domain,
new_uri, fname, lname, description)
VALUES(target_username, target_domain,
NEW.slot, target_domain,
NEW.destination, '', '', '');
END;
|
CREATE TRIGGER voip_sd_urepl_trig AFTER UPDATE ON voip_speed_dial
FOR EACH ROW BEGIN
DECLARE old_username varchar(127);
DECLARE old_domain varchar(127);
DECLARE new_username varchar(127);
DECLARE new_domain varchar(127);
SELECT a.username, b.domain INTO old_username, old_domain
FROM voip_subscribers a, voip_domains b
WHERE a.id = OLD.subscriber_id
AND b.id = a.domain_id;
SELECT a.username, b.domain INTO new_username, new_domain
FROM voip_subscribers a, voip_domains b
WHERE a.id = NEW.subscriber_id
AND b.id = a.domain_id;
UPDATE kamailio.speed_dial SET username = new_username, domain = new_domain,
sd_username = NEW.slot, sd_domain = new_domain,
new_uri = NEW.destination
WHERE username = old_username
AND domain = old_domain
AND sd_username = OLD.slot;
END;
|
CREATE TRIGGER voip_sd_drepl_trig BEFORE DELETE ON voip_speed_dial
FOR EACH ROW BEGIN
DECLARE old_username varchar(127);
DECLARE old_domain varchar(127);
SELECT a.username, b.domain INTO old_username, old_domain
FROM voip_subscribers a, voip_domains b
WHERE a.id = OLD.subscriber_id
AND b.id = a.domain_id;
DELETE FROM kamailio.speed_dial WHERE username = old_username
AND domain = old_domain
AND sd_username = OLD.slot;
END;
|
CREATE TRIGGER voip_faxp_crepl_trig AFTER INSERT ON voip_fax_preferences
FOR EACH ROW BEGIN
DECLARE subscriber_username varchar(127);
DECLARE subscriber_domain varchar(127);
DECLARE os_subscriber_id int(10) UNSIGNED;
SELECT a.username, b.domain INTO subscriber_username, subscriber_domain
FROM voip_subscribers a, voip_domains b
WHERE a.id = NEW.subscriber_id
AND b.id = a.domain_id;
SELECT id INTO os_subscriber_id FROM kamailio.subscriber
WHERE username = subscriber_username AND domain = subscriber_domain;
INSERT INTO kamailio.fax_preferences
(subscriber_id, password, name, active, send_status, send_copy)
VALUES(os_subscriber_id, NEW.password, NEW.name, IF(NEW.active, 'true', 'false'),
IF(NEW.send_status, 'true', 'false'), IF(NEW.send_copy, 'true', 'false'));
END;
|
CREATE TRIGGER voip_faxp_urepl_trig AFTER UPDATE ON voip_fax_preferences
FOR EACH ROW BEGIN
DECLARE subscriber_username varchar(127);
DECLARE subscriber_domain varchar(127);
DECLARE os_subscriber_id int(10) UNSIGNED;
DECLARE old_subscriber_username varchar(127);
DECLARE old_subscriber_domain varchar(127);
DECLARE old_os_subscriber_id int(10) UNSIGNED;
SELECT a.username, b.domain INTO subscriber_username, subscriber_domain
FROM voip_subscribers a, voip_domains b
WHERE a.id = NEW.subscriber_id
AND b.id = a.domain_id;
SELECT id INTO os_subscriber_id FROM kamailio.subscriber
WHERE username = subscriber_username AND domain = subscriber_domain;
SELECT a.username, b.domain INTO old_subscriber_username, old_subscriber_domain
FROM voip_subscribers a, voip_domains b
WHERE a.id = OLD.subscriber_id
AND b.id = a.domain_id;
SELECT id INTO old_os_subscriber_id FROM kamailio.subscriber
WHERE username = old_subscriber_username AND domain = old_subscriber_domain;
UPDATE kamailio.fax_preferences SET subscriber_id = os_subscriber_id, password = NEW.password,
name = NEW.name, active = IF(NEW.active, 'true', 'false'),
send_status = IF(NEW.send_status, 'true', 'false'),
send_copy = IF(NEW.send_copy, 'true', 'false')
WHERE subscriber_id = old_os_subscriber_id;
END;
|
CREATE TRIGGER voip_faxp_drepl_trig BEFORE DELETE ON voip_fax_preferences
FOR EACH ROW BEGIN
DECLARE old_subscriber_username varchar(127);
DECLARE old_subscriber_domain varchar(127);
DECLARE old_os_subscriber_id int(10) UNSIGNED;
SELECT a.username, b.domain INTO old_subscriber_username, old_subscriber_domain
FROM voip_subscribers a, voip_domains b
WHERE a.id = OLD.subscriber_id
AND b.id = a.domain_id;
SELECT id INTO old_os_subscriber_id FROM kamailio.subscriber
WHERE username = old_subscriber_username AND domain = old_subscriber_domain;
DELETE FROM kamailio.fax_preferences WHERE subscriber_id = old_os_subscriber_id;
END;
|
CREATE TRIGGER voip_faxd_crepl_trig AFTER INSERT ON voip_fax_destinations
FOR EACH ROW BEGIN
DECLARE subscriber_username varchar(127);
DECLARE subscriber_domain varchar(127);
DECLARE os_subscriber_id int(10) UNSIGNED;
SELECT a.username, b.domain INTO subscriber_username, subscriber_domain
FROM voip_subscribers a, voip_domains b
WHERE a.id = NEW.subscriber_id
AND b.id = a.domain_id;
SELECT id INTO os_subscriber_id FROM kamailio.subscriber
WHERE username = subscriber_username AND domain = subscriber_domain;
INSERT INTO kamailio.fax_destinations (subscriber_id, destination, filetype,
cc, incoming, outgoing, status)
VALUES(os_subscriber_id, NEW.destination, NEW.filetype,
IF(NEW.cc, 'true', 'false'), IF(NEW.incoming, 'true', 'false'),
IF(NEW.outgoing, 'true', 'false'), IF(NEW.status, 'true', 'false'));
END;
|
CREATE TRIGGER voip_faxd_urepl_trig AFTER UPDATE ON voip_fax_destinations
FOR EACH ROW BEGIN
DECLARE subscriber_username varchar(127);
DECLARE subscriber_domain varchar(127);
DECLARE os_subscriber_id int(10) UNSIGNED;
DECLARE old_subscriber_username varchar(127);
DECLARE old_subscriber_domain varchar(127);
DECLARE old_os_subscriber_id int(10) UNSIGNED;
SELECT a.username, b.domain INTO subscriber_username, subscriber_domain
FROM voip_subscribers a, voip_domains b
WHERE a.id = NEW.subscriber_id
AND b.id = a.domain_id;
SELECT id INTO os_subscriber_id FROM kamailio.subscriber
WHERE username = subscriber_username AND domain = subscriber_domain;
SELECT a.username, b.domain INTO old_subscriber_username, old_subscriber_domain
FROM voip_subscribers a, voip_domains b
WHERE a.id = OLD.subscriber_id
AND b.id = a.domain_id;
SELECT id INTO old_os_subscriber_id FROM kamailio.subscriber
WHERE username = old_subscriber_username AND domain = old_subscriber_domain;
UPDATE kamailio.fax_destinations SET subscriber_id = os_subscriber_id, destination = NEW.destination,
filetype = NEW.filetype, cc = IF(NEW.cc, 'true', 'false'),
incoming = IF(NEW.incoming, 'true', 'false'),
outgoing = IF(NEW.outgoing, 'true', 'false'),
status = IF(NEW.status, 'true', 'false')
WHERE subscriber_id = old_os_subscriber_id
AND destination = OLD.destination;
END;
|
CREATE TRIGGER voip_faxd_drepl_trig BEFORE DELETE ON voip_fax_destinations
FOR EACH ROW BEGIN
DECLARE old_subscriber_username varchar(127);
DECLARE old_subscriber_domain varchar(127);
DECLARE old_os_subscriber_id int(10) UNSIGNED;
SELECT a.username, b.domain INTO old_subscriber_username, old_subscriber_domain
FROM voip_subscribers a, voip_domains b
WHERE a.id = OLD.subscriber_id
AND b.id = a.domain_id;
SELECT id INTO old_os_subscriber_id FROM kamailio.subscriber
WHERE username = old_subscriber_username AND domain = old_subscriber_domain;
DELETE FROM kamailio.fax_destinations WHERE subscriber_id = old_os_subscriber_id
AND destination = OLD.destination;
END;
|
CREATE TRIGGER voip_aig_crepl_trig AFTER INSERT ON voip_allowed_ip_groups
FOR EACH ROW BEGIN
INSERT INTO kamailio.address (id, grp, ip_addr, mask)
VALUES(NEW.id, NEW.group_id,
IF(LOCATE('/', NEW.ipnet), SUBSTRING_INDEX(NEW.ipnet, '/', 1), NEW.ipnet),
IF(LOCATE('/', NEW.ipnet), SUBSTRING_INDEX(NEW.ipnet, '/', -1), 32));
END;
|
CREATE TRIGGER voip_aig_urepl_trig AFTER UPDATE ON voip_allowed_ip_groups
FOR EACH ROW BEGIN
UPDATE kamailio.address SET id = NEW.id, grp = NEW.group_id,
ip_addr = IF(LOCATE('/', NEW.ipnet), SUBSTRING_INDEX(NEW.ipnet, '/', 1), NEW.ipnet),
mask = IF(LOCATE('/', NEW.ipnet), SUBSTRING_INDEX(NEW.ipnet, '/', -1), 32)
WHERE id = OLD.id;
END;
|
CREATE TRIGGER voip_aig_drepl_trig BEFORE DELETE ON voip_allowed_ip_groups
FOR EACH ROW BEGIN
DELETE FROM kamailio.address WHERE id = OLD.id;
END;
|
DELIMITER ;
-- internal domain and subscribers
INSERT INTO voip_domains (domain) VALUES('voip.sipwise.local');
INSERT INTO voip_subscribers (username, domain_id, uuid, password, create_timestamp)
SELECT 'no_such_number', id, '9bcb88b6-541a-43da-8fdc-816f5557ff93', MD5(RAND()), NOW()
FROM voip_domains WHERE domain = 'voip.sipwise.local';
INSERT INTO voip_subscribers (username, domain_id, uuid, password, create_timestamp)
SELECT 'nagios', id, 'ac1697cf-6933-45ef-9abf-b1278054ded0', 'nagios4Sipwise!', NOW()
FROM voip_domains WHERE domain = 'voip.sipwise.local';

@ -0,0 +1,90 @@
-- step out of our provisioning DB
USE mysql;
-- drop database if it allready exists
-- this will drop all tables and triggers
DROP DATABASE IF EXISTS accounting;
-- create DB with utf8 default charset, so we don't have to
-- specify charset for each table
CREATE DATABASE IF NOT EXISTS accounting CHARACTER SET 'utf8';
USE accounting;
-- create accounting tables
CREATE TABLE `acc` like kamailio.acc;
CREATE TABLE `cdr` (
`id` int(10) unsigned NOT NULL auto_increment,
`update_time` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
`source_user_id` char(36) NOT NULL,
`source_provider_id` varchar(255) NOT NULL,
`source_external_subscriber_id` varchar(255) DEFAULT NULL,
`source_external_contract_id` varchar(255) DEFAULT NULL,
`source_account_id` int(11) unsigned NOT NULL DEFAULT '0',
`source_user` varchar(255) NOT NULL,
`source_domain` varchar(255) NOT NULL,
`source_cli` varchar(64) NOT NULL,
`source_clir` tinyint(1) NOT NULL default '0',
`destination_user_id` char(36) NOT NULL,
`destination_provider_id` varchar(255) NOT NULL,
`destination_external_subscriber_id` varchar(255) DEFAULT NULL,
`destination_external_contract_id` varchar(255) DEFAULT NULL,
`destination_account_id` int(11) unsigned NOT NULL DEFAULT '0',
`destination_user` varchar(255) NOT NULL,
`destination_domain` varchar(255) NOT NULL,
`destination_user_dialed` varchar(255) NOT NULL,
`destination_user_in` varchar(255) NOT NULL,
`destination_domain_in` varchar(255) NOT NULL,
`peer_auth_user` varchar(255) DEFAULT NULL,
`peer_auth_realm` varchar(255) DEFAULT NULL,
`call_type` enum('call','cfu','cft','cfb','cfna') NOT NULL default 'call',
`call_status` enum('ok','busy','noanswer','cancel','offline','timeout','other') NOT NULL default 'ok',
`call_code` char(3) NOT NULL,
`init_time` decimal(13,3) NOT NULL,
`start_time` decimal(13,3) NOT NULL,
`duration` decimal(13,3) NOT NULL,
`call_id` varchar(255) NOT NULL,
`carrier_cost` decimal(10,2) default NULL,
`reseller_cost` decimal(10,2) default NULL,
`customer_cost` decimal(10,2) default NULL,
`carrier_free_time` int(10) unsigned DEFAULT NULL,
`reseller_free_time` int(10) unsigned DEFAULT NULL,
`customer_free_time` int(10) unsigned DEFAULT NULL,
`carrier_billing_fee_id` int(11) unsigned default NULL,
`reseller_billing_fee_id` int(11) unsigned default NULL,
`customer_billing_fee_id` int(11) unsigned default NULL,
`carrier_billing_zone_id` int(11) unsigned default NULL,
`reseller_billing_zone_id` int(11) unsigned default NULL,
`customer_billing_zone_id` int(11) unsigned default NULL,
`frag_carrier_onpeak` tinyint(1) default NULL,
`frag_reseller_onpeak` tinyint(1) default NULL,
`frag_customer_onpeak` tinyint(1) default NULL,
`is_fragmented` tinyint(1) default NULL,
`rated_at` datetime default NULL,
`rating_status` enum('unrated','ok','failed') NOT NULL default 'unrated',
PRIMARY KEY (`id`),
KEY `suid` (`source_user_id`),
KEY `duid` (`destination_user_id`),
KEY `suri` (`source_user`,`source_domain`,`source_cli`),
KEY `duri` (`destination_user`,`destination_domain`),
KEY `sprov` (`source_provider_id`),
KEY `dprov` (`destination_provider_id`),
KEY `kcid` (`call_id`)
) ENGINE=InnoDB;
CREATE TABLE `mark` (
`id` int(10) unsigned NOT NULL auto_increment,
`collector` varchar(255) NOT NULL,
`acc_id` int(10) unsigned NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB;
CREATE TABLE `prepaid_costs` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`call_id` varchar(255) NOT NULL,
`cost` double NOT NULL,
`free_time_used` int(10) unsigned NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB;

@ -0,0 +1,99 @@
-- step out of our provisioning DB
USE mysql;
-- drop database if it allready exists
-- this will drop all tables and triggers
DROP DATABASE IF EXISTS syslog;
-- create DB with utf8 default charset, so we don't have to
-- specify charset for each table
CREATE DATABASE IF NOT EXISTS syslog CHARACTER SET 'utf8';
USE syslog;
CREATE TABLE `se1` (
`ID` bigint(20) UNSIGNED NOT NULL AUTO_INCREMENT,
`CustomerID` bigint(20) DEFAULT NULL,
`ReceivedAt` datetime DEFAULT NULL,
`DeviceReportedTime` datetime DEFAULT NULL,
`Facility` smallint(6) DEFAULT NULL,
`Priority` smallint(6) DEFAULT NULL,
`FromHost` varchar(60) DEFAULT NULL,
`Message` text,
`NTSeverity` int(11) DEFAULT NULL,
`Importance` int(11) DEFAULT NULL,
`EventSource` varchar(60) DEFAULT NULL,
`EventUser` varchar(60) DEFAULT NULL,
`EventCategory` int(11) DEFAULT NULL,
`EventID` int(11) DEFAULT NULL,
`EventBinaryData` text,
`MaxAvailable` int(11) DEFAULT NULL,
`CurrUsage` int(11) DEFAULT NULL,
`MinUsage` int(11) DEFAULT NULL,
`MaxUsage` int(11) DEFAULT NULL,
`InfoUnitID` int(11) DEFAULT NULL,
`SysLogTag` varchar(60) DEFAULT NULL,
`EventLogType` varchar(60) DEFAULT NULL,
`GenericFileName` varchar(60) DEFAULT NULL,
`SystemID` int(11) DEFAULT NULL,
PRIMARY KEY (`ID`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
CREATE TABLE `se2` like `se1`;
CREATE TABLE `se3` like `se1`;
CREATE TABLE `se4` like `se1`;
CREATE TABLE `se5` like `se1`;
CREATE TABLE `se6` like `se1`;
CREATE TABLE `se7` like `se1`;
CREATE TABLE `se8` like `se1`;
CREATE TABLE `se9` like `se1`;
CREATE TABLE `se10` like `se1`;
CREATE TABLE `se11` like `se1`;
CREATE TABLE `se12` like `se1`;
CREATE TABLE `se13` like `se1`;
CREATE TABLE `se14` like `se1`;
CREATE TABLE `se15` like `se1`;
CREATE TABLE `se16` like `se1`;
CREATE TABLE `se17` like `se1`;
CREATE TABLE `se18` like `se1`;
CREATE TABLE `se19` like `se1`;
CREATE TABLE `se20` like `se1`;
CREATE TABLE `se21` like `se1`;
CREATE TABLE `se22` like `se1`;
CREATE TABLE `se23` like `se1`;
CREATE TABLE `se24` like `se1`;
CREATE TABLE `se25` like `se1`;
CREATE TABLE `se26` like `se1`;
CREATE TABLE `se27` like `se1`;
CREATE TABLE `se28` like `se1`;
CREATE TABLE `SystemEvents` (
`ID` bigint(20) UNSIGNED NOT NULL AUTO_INCREMENT,
`CustomerID` bigint(20) DEFAULT NULL,
`ReceivedAt` datetime DEFAULT NULL,
`DeviceReportedTime` datetime DEFAULT NULL,
`Facility` smallint(6) DEFAULT NULL,
`Priority` smallint(6) DEFAULT NULL,
`FromHost` varchar(60) DEFAULT NULL,
`Message` text,
`NTSeverity` int(11) DEFAULT NULL,
`Importance` int(11) DEFAULT NULL,
`EventSource` varchar(60) DEFAULT NULL,
`EventUser` varchar(60) DEFAULT NULL,
`EventCategory` int(11) DEFAULT NULL,
`EventID` int(11) DEFAULT NULL,
`EventBinaryData` text,
`MaxAvailable` int(11) DEFAULT NULL,
`CurrUsage` int(11) DEFAULT NULL,
`MinUsage` int(11) DEFAULT NULL,
`MaxUsage` int(11) DEFAULT NULL,
`InfoUnitID` int(11) DEFAULT NULL,
`SysLogTag` varchar(60) DEFAULT NULL,
`EventLogType` varchar(60) DEFAULT NULL,
`GenericFileName` varchar(60) DEFAULT NULL,
`SystemID` int(11) DEFAULT NULL,
PRIMARY KEY (`ID`)
) ENGINE=MRG_MyISAM DEFAULT CHARSET=utf8 INSERT_METHOD=FIRST UNION=(`se1`,`se2`,`se3`,`se4`,`se5`,`se6`,`se7`,`se8`,`se9`,`se10`,`se11`,`se12`,`se13`,`se14`,`se15`,`se16`,`se17`,`se18`,`se19`,`se20`,`se21`,`se22`,`se23`,`se24`,`se25`,`se26`,`se27`,`se28`);

@ -0,0 +1,38 @@
USE mysql;
DROP DATABASE IF EXISTS sipstats;
CREATE DATABASE IF NOT EXISTS sipstats CHARACTER SET 'utf8';
USE sipstats;
-- create packets tables
CREATE TABLE `packets` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`timestamp` decimal(17,6) NOT NULL,
`src_mac` binary(6) NOT NULL,
`dst_mac` binary(6) NOT NULL,
`protocol` enum('IPv4','IPv6') NOT NULL,
`src_ip` varchar(39) NOT NULL,
`dst_ip` varchar(39) NOT NULL,
`src_port` smallint(5) unsigned NOT NULL,
`dst_port` smallint(5) unsigned NOT NULL,
`header` blob NOT NULL,
`payload` blob NOT NULL,
`trailer` blob NOT NULL,
`method` varchar(20) NOT NULL,
`cseq_method` varchar(16) NOT NULL,
`call_id` varchar(255) NOT NULL,
`request_uri` varchar(255) NOT NULL,
`from_uri` varchar(255) NOT NULL,
`caller_uuid` varchar(255) NOT NULL,
`callee_uuid` varchar(255) NOT NULL,
`was_fragmented` tinyint(3) unsigned NOT NULL,
PRIMARY KEY (`id`,`timestamp`),
KEY `call_id_idx` (`call_id`),
KEY `caller_uuid_idx` (`caller_uuid`),
KEY `callee_uuid_idx` (`callee_uuid`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8
PARTITION BY RANGE (FLOOR(`timestamp`))
(PARTITION pmax VALUES LESS THAN MAXVALUE ENGINE = MyISAM);

@ -0,0 +1,104 @@
-- step out of our billing DB
USE mysql;
-- drop database if it allready exists
-- this will drop all tables and triggers
DROP DATABASE IF EXISTS carrier;
-- create DB with utf8 default charset, so we don't have to
-- specify charset for each table
CREATE DATABASE carrier CHARACTER SET 'utf8';
USE carrier;
CREATE TABLE `customers` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`external_id` varchar(255) NULL default NULL,
`url` varchar(31) NOT NULL,
`shopuser` varchar(31) NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `externalid_idx` (`external_id`),
UNIQUE KEY `shopuser_idx` (`shopuser`)
) ENGINE=InnoDB;
CREATE TABLE `orders` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`customer_id` int(11) UNSIGNED NOT NULL REFERENCES `customers` (`id`),
PRIMARY KEY (`id`),
KEY `customerid_idx` (`customer_id`),
CONSTRAINT `o_customerid_ref` FOREIGN KEY (`customer_id`)
REFERENCES `customers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `contracts` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`external_id` varchar(255) NULL default NULL,
`url` varchar(31) NULL default NULL,
`customer_id` int(11) UNSIGNED NULL REFERENCES `customers` (`id`),
`sip_uri` varchar(127) NULL default NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `externalid_idx` (`external_id`),
KEY `customerid_idx` (`customer_id`),
CONSTRAINT `c_customerid_ref` FOREIGN KEY (`customer_id`)
REFERENCES `customers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `credits` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`contract_id` int(11) UNSIGNED NOT NULL REFERENCES `contracts` (`id`),
PRIMARY KEY (`id`),
KEY `contractid_idx` (`contract_id`),
CONSTRAINT `c_contractid_ref` FOREIGN KEY (`contract_id`)
REFERENCES `contracts` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `payments` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`order_id` int(11) UNSIGNED NULL REFERENCES `orders` (`id`),
`credit_id` int(11) UNSIGNED NULL REFERENCES `credits` (`id`),
PRIMARY KEY (`id`),
KEY `orderid_idx` (`order_id`),
CONSTRAINT `p_orderid_ref` FOREIGN KEY (`order_id`)
REFERENCES `orders` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `creditid_idx` (`credit_id`),
CONSTRAINT `p_creditid_ref` FOREIGN KEY (`credit_id`)
REFERENCES `credits` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `subscribers` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`external_id` varchar(255) NULL default NULL,
`username` varchar(127) NOT NULL,
`domain` varchar(127) NOT NULL,
`webusername` varchar(127) default NULL,
`contract_id` int(11) UNSIGNED NOT NULL REFERENCES `contracts` (`id`),
PRIMARY KEY (`id`),
UNIQUE KEY `externalid_idx` (`external_id`),
UNIQUE KEY `usrdom_idx` (`username`, `domain`),
UNIQUE KEY `domwebuser_idx` (`domain`, `webusername`),
KEY `contractid_idx` (`contract_id`),
CONSTRAINT `s_contractid_ref` FOREIGN KEY (`contract_id`)
REFERENCES `contracts` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `numbers` (
`number` varchar(42) NOT NULL,
`subscriber_id` int(11) UNSIGNED NULL REFERENCES `subscribers` (`id`),
PRIMARY KEY `number_idx` (`number`),
KEY `subscriberid_idx` (`subscriber_id`),
CONSTRAINT `n_subscriberid_ref` FOREIGN KEY (`subscriber_id`)
REFERENCES `subscribers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `interceptions` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`url` varchar(31) NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB;

@ -0,0 +1,8 @@
USE accounting;
create table acc_backup like kamailio.acc;
create table acc_trash like kamailio.acc;
USE kamailio;
create table acc_backup like kamailio.acc;
create table acc_trash like kamailio.acc;

@ -0,0 +1,53 @@
GRANT SELECT ON mysql.* TO 'nagios'@'localhost' IDENTIFIED BY 'PW_CHECKTOOL';
GRANT SELECT ON kamailio.location TO 'nagios'@'localhost' IDENTIFIED BY 'PW_CHECKTOOL';
GRANT SELECT ON provisioning.voip_subscribers TO 'nagios'@'localhost' IDENTIFIED BY 'PW_CHECKTOOL';
GRANT SELECT ON kamailio.* TO 'kamailioro'@'localhost' IDENTIFIED BY 'PW_KAMAILIORW';
GRANT ALL ON kamailio.* TO 'kamailio'@'localhost' IDENTIFIED BY 'PW_KAMAILIORW';
GRANT SELECT ON kamailio.location TO 'natping'@'localhost' IDENTIFIED BY 'PW_NATPING';
#GRANT ALL ON accounting.* TO 'collector'@'localhost' IDENTIFIED BY 'PW_COLLECTOR';
GRANT ALL ON accounting.* TO 'mediator'@'localhost' IDENTIFIED BY 'PW_MEDIATOR';
GRANT SELECT ON provisioning.* TO 'mediator'@'localhost' IDENTIFIED BY 'PW_MEDIATOR';
GRANT SELECT ON billing.* TO 'mediator'@'localhost' IDENTIFIED BY 'PW_MEDIATOR';
GRANT ALL ON accounting.* TO 'soap'@'localhost' IDENTIFIED BY 'PW_SOAP';
GRANT ALL ON billing.* TO 'soap'@'localhost' IDENTIFIED BY 'PW_SOAP';
GRANT ALL PRIVILEGES ON kamailio.voicemail_users TO 'asterisk'@'localhost' IDENTIFIED BY 'PW_ASTERISK';
GRANT ALL PRIVILEGES ON kamailio.voicemail_spool TO 'asterisk'@'localhost' IDENTIFIED BY 'PW_ASTERISK';
GRANT ALL ON provisioning.* TO 'soap'@'localhost' IDENTIFIED BY 'PW_SOAP';
GRANT ALL ON kamailio.* TO 'soap'@'localhost' IDENTIFIED BY 'PW_SOAP';
GRANT ALL ON sipstats.* TO 'soap'@'localhost' IDENTIFIED BY 'PW_SOAP';
GRANT SELECT ON accounting.cdr TO 'exporter'@'localhost' IDENTIFIED BY 'PW_EXPORTER';
GRANT SELECT,INSERT,UPDATE ON accounting.mark TO 'exporter'@'localhost' IDENTIFIED BY 'PW_EXPORTER';
GRANT SELECT ON billing.billing_zones_history TO 'exporter'@'localhost' IDENTIFIED BY 'PW_EXPORTER';
GRANT RELOAD ON *.* TO 'rsyslog'@'localhost' IDENTIFIED BY 'PW_RSYSLOG';
GRANT ALL on syslog.* TO 'rsyslog'@'localhost' IDENTIFIED BY 'PW_RSYSLOG';
GRANT SELECT,INSERT,UPDATE ON accounting.* TO 'rateomat'@'localhost' IDENTIFIED BY 'PW_RATEOMAT';
GRANT DELETE ON accounting.prepaid_costs TO 'rateomat'@'localhost' IDENTIFIED BY 'PW_RATEOMAT';
GRANT SELECT,INSERT,UPDATE ON billing.* TO 'rateomat'@'localhost' IDENTIFIED BY 'PW_RATEOMAT';
GRANT SELECT,INSERT,UPDATE ON accounting.* TO 'sems_prepaid'@'localhost' IDENTIFIED BY 'PW_SEMS_PREPAID';
GRANT SELECT,INSERT,UPDATE ON billing.* TO 'sems_prepaid'@'localhost' IDENTIFIED BY 'PW_SEMS_PREPAID';
GRANT ALL PRIVILEGES ON *.* TO 'sipwise'@'localhost' IDENTIFIED BY 'PW_SIPWISE' WITH GRANT OPTION;
GRANT ALL PRIVILEGES ON kamailio.* to 'dbcleaner'@'localhost' IDENTIFIED BY 'PW_CLEANUP_TOOLS';
GRANT ALL PRIVILEGES ON accounting.* to 'dbcleaner'@'localhost' IDENTIFIED BY 'PW_CLEANUP_TOOLS';
GRANT SELECT ON provisioning.* to 'hylafax'@'localhost' IDENTIFIED BY 'PW_HYLAFAX';
GRANT ALL ON sipstats.* to 'voisniff'@'localhost' IDENTIFIED BY 'PW_VOISNIFF';
GRANT SUPER,REPLICATION CLIENT,REPLICATION SLAVE,RELOAD ON *.* TO 'replicator'@'sp1' IDENTIFIED BY 'PW_REPLICATOR';
GRANT SUPER,REPLICATION CLIENT,REPLICATION SLAVE,RELOAD ON *.* TO 'replicator'@'sp2' IDENTIFIED BY 'PW_REPLICATOR';
GRANT SUPER,REPLICATION CLIENT,REPLICATION SLAVE,RELOAD ON *.* TO 'nagios'@'sp1' IDENTIFIED BY 'PW_CHECKTOOL';
GRANT SUPER,REPLICATION CLIENT,REPLICATION SLAVE,RELOAD ON *.* TO 'nagios'@'sp2' IDENTIFIED BY 'PW_CHECKTOOL';
GRANT SUPER,REPLICATION CLIENT,REPLICATION SLAVE,RELOAD ON *.* TO 'nagios'@'localhost' IDENTIFIED BY 'PW_CHECKTOOL';

@ -0,0 +1,18 @@
GRANT SELECT ON mysql.* TO 'nagios'@'localhost' IDENTIFIED BY 'PW_CHECKTOOL';
GRANT SELECT ON kamailio.location TO 'nagios'@'localhost' IDENTIFIED BY 'PW_CHECKTOOL';
GRANT SELECT ON kamailio.* TO 'kamailioro'@'localhost' IDENTIFIED BY 'PW_KAMAILIORO';
GRANT ALL ON kamailio.* TO 'kamailio'@'localhost' IDENTIFIED BY 'PW_KAMAILIORW';
GRANT SELECT ON provisioning.voip_peer_hosts TO 'kamailio'@'localhost' IDENTIFIED BY 'PW_KAMAILIORW';
GRANT SELECT ON provisioning.voip_cf_destination_sets TO 'kamailio'@'localhost' IDENTIFIED BY 'PW_KAMAILIORW';
GRANT SELECT ON provisioning.voip_cf_destinations TO 'kamailio'@'localhost' IDENTIFIED BY 'PW_KAMAILIORW';
GRANT SELECT ON provisioning.voip_cf_periods TO 'kamailio'@'localhost' IDENTIFIED BY 'PW_KAMAILIORW';
GRANT SELECT ON provisioning.voip_cf_time_sets TO 'kamailio'@'localhost' IDENTIFIED BY 'PW_KAMAILIORW';
GRANT SELECT ON provisioning.voip_cf_mappings TO 'kamailio'@'localhost' IDENTIFIED BY 'PW_KAMAILIORW';
GRANT SELECT ON billing.ncos_levels TO 'kamailio'@'localhost' IDENTIFIED BY 'PW_KAMAILIORW';
GRANT SELECT ON billing.ncos_lnp_list TO 'kamailio'@'localhost' IDENTIFIED BY 'PW_KAMAILIORW';
GRANT SELECT ON billing.ncos_pattern_list TO 'kamailio'@'localhost' IDENTIFIED BY 'PW_KAMAILIORW';
GRANT SELECT ON billing.lnp_numbers TO 'kamailio'@'localhost' IDENTIFIED BY 'PW_KAMAILIORW';
GRANT SELECT ON kamailio.* to 'hylafax'@'localhost' IDENTIFIED BY 'PW_HYLAFAX';
GRANT INSERT ON kamailio.fax_journal to 'hylafax'@'localhost' IDENTIFIED BY 'PW_HYLAFAX';

@ -0,0 +1,2 @@
ALTER TABLE provisioning.voip_preferences MODIFY COLUMN `type` tinyint(3) NOT NULL;
ALTER TABLE provisioning.voip_preferences DROP COLUMN `data_type`;

@ -0,0 +1,18 @@
ALTER TABLE provisioning.voip_preferences MODIFY COLUMN `type` tinyint(3) NOT NULL default 0;
ALTER TABLE provisioning.voip_preferences ADD COLUMN `data_type` enum('bool','int','string') NOT NULL default 'string';
UPDATE provisioning.voip_preferences SET data_type = 'bool' where attribute = 'block_in_mode';
UPDATE provisioning.voip_preferences SET data_type = 'bool' where attribute = 'block_in_clir';
UPDATE provisioning.voip_preferences SET data_type = 'bool' where attribute = 'block_out_mode';
UPDATE provisioning.voip_preferences SET data_type = 'bool' where attribute = 'adm_block_in_mode';
UPDATE provisioning.voip_preferences SET data_type = 'bool' where attribute = 'adm_block_in_clir';
UPDATE provisioning.voip_preferences SET data_type = 'bool' where attribute = 'adm_block_out_mode';
UPDATE provisioning.voip_preferences SET data_type = 'bool' where attribute = 'clir';
UPDATE provisioning.voip_preferences SET data_type = 'int' where attribute = 'lock';
UPDATE provisioning.voip_preferences SET data_type = 'int' where attribute = 'ringtimeout';
UPDATE provisioning.voip_preferences SET data_type = 'int' where attribute = 'ncos_id';
UPDATE provisioning.voip_preferences SET data_type = 'int' where attribute = 'adm_ncos_id';
UPDATE provisioning.voip_preferences SET data_type = 'int' where attribute = 'dp_dom_caller_in';
UPDATE provisioning.voip_preferences SET data_type = 'int' where attribute = 'dp_dom_callee_in';
UPDATE provisioning.voip_preferences SET data_type = 'int' where attribute = 'dp_dom_caller_out';
UPDATE provisioning.voip_preferences SET data_type = 'int' where attribute = 'dp_dom_callee_out';

@ -0,0 +1,39 @@
ALTER TABLE provisioning.voip_domains ADD COLUMN `timezone` varchar(31) default NULL;
ALTER TABLE provisioning.voip_subscribers ADD COLUMN `timezone` varchar(31) default NULL;
DROP TRIGGER provisioning.voip_sub_crepl_trig;
DROP TRIGGER provisioning.voip_sub_urepl_trig;
DELIMITER |
CREATE TRIGGER provisioning.voip_sub_crepl_trig AFTER INSERT ON voip_subscribers
FOR EACH ROW BEGIN
DECLARE subscriber_domain varchar(127);
SELECT domain INTO subscriber_domain FROM voip_domains where id = NEW.domain_id;
INSERT INTO kamailio.subscriber (username, domain, uuid, timezone, password, datetime_created, ha1, ha1b)
VALUES(NEW.username, subscriber_domain, NEW.uuid, NEW.timezone, NEW.password, now(),
MD5(CONCAT(NEW.username, ':', subscriber_domain, ':', NEW.password)),
MD5(CONCAT(NEW.username, '@', subscriber_domain, ':', subscriber_domain, ':', NEW.password)));
END;
|
CREATE TRIGGER provisioning.voip_sub_urepl_trig AFTER UPDATE ON voip_subscribers
FOR EACH ROW BEGIN
DECLARE old_subscriber_domain varchar(127);
DECLARE new_subscriber_domain varchar(127);
SELECT domain INTO old_subscriber_domain FROM voip_domains where id = OLD.domain_id;
SELECT domain INTO new_subscriber_domain FROM voip_domains where id = NEW.domain_id;
UPDATE kamailio.subscriber SET username = NEW.username, domain = new_subscriber_domain,
uuid = NEW.uuid, timezone = NEW.timezone, password = NEW.password,
ha1 = MD5(CONCAT(NEW.username, ':', new_subscriber_domain, ':', NEW.password)),
ha1b = MD5(CONCAT(NEW.username, '@', new_subscriber_domain, ':', new_subscriber_domain, ':', NEW.password))
WHERE username = OLD.username
AND domain = old_subscriber_domain;
END;
|
DELIMITER ;

@ -0,0 +1,40 @@
ALTER TABLE provisioning.voip_domains DROP COLUMN `timezone`;
ALTER TABLE provisioning.voip_subscribers DROP COLUMN `timezone`;
DROP TRIGGER provisioning.voip_sub_crepl_trig;
DROP TRIGGER provisioning.voip_sub_urepl_trig;
DELIMITER |
CREATE TRIGGER provisioning.voip_sub_crepl_trig AFTER INSERT ON voip_subscribers
FOR EACH ROW BEGIN
DECLARE subscriber_domain varchar(127);
SELECT domain INTO subscriber_domain FROM voip_domains where id = NEW.domain_id;
INSERT INTO kamailio.subscriber (username, domain, uuid, password, datetime_created, ha1, ha1b)
VALUES(NEW.username, subscriber_domain, NEW.uuid, NEW.password, now(),
MD5(CONCAT(NEW.username, ':', subscriber_domain, ':', NEW.password)),
MD5(CONCAT(NEW.username, '@', subscriber_domain, ':', subscriber_domain, ':', NEW.password)));
END;
|
CREATE TRIGGER provisioning.voip_sub_urepl_trig AFTER UPDATE ON voip_subscribers
FOR EACH ROW BEGIN
DECLARE old_subscriber_domain varchar(127);
DECLARE new_subscriber_domain varchar(127);
SELECT domain INTO old_subscriber_domain FROM voip_domains where id = OLD.domain_id;
SELECT domain INTO new_subscriber_domain FROM voip_domains where id = NEW.domain_id;
UPDATE kamailio.subscriber SET username = NEW.username, domain = new_subscriber_domain,
uuid = NEW.uuid, password = NEW.password,
ha1 = MD5(CONCAT(NEW.username, ':', new_subscriber_domain, ':', NEW.password)),
ha1b = MD5(CONCAT(NEW.username, '@', new_subscriber_domain, ':', new_subscriber_domain, ':', NEW.password))
WHERE username = OLD.username
AND domain = old_subscriber_domain;
END;
|
DELIMITER ;

@ -0,0 +1,65 @@
ALTER TABLE provisioning.voip_domains ADD COLUMN `local` bool NOT NULL default FALSE;
UPDATE provisioning.voip_domains SET local = TRUE;
DROP TRIGGER provisioning.voip_dom_crepl_trig;
DROP TRIGGER provisioning.voip_dom_drepl_trig;
DELIMITER |
CREATE TRIGGER provisioning.voip_dom_crepl_trig AFTER INSERT ON voip_domains
FOR EACH ROW BEGIN
IF NEW.local IS TRUE THEN
INSERT INTO kamailio.domain (domain) VALUES(NEW.domain);
END IF;
END;
|
CREATE TRIGGER provisioning.voip_dom_urepl_trig AFTER UPDATE ON voip_domains
FOR EACH ROW BEGIN
IF NEW.local IS TRUE AND OLD.local IS FALSE THEN
INSERT INTO kamailio.domain (domain) VALUES(NEW.domain);
ELSEIF NEW.local IS FALSE AND OLD.local IS TRUE THEN
DELETE FROM kamailio.domain WHERE domain = OLD.domain;
END IF;
END;
|
CREATE TRIGGER provisioning.voip_dom_drepl_trig BEFORE DELETE ON voip_domains
FOR EACH ROW BEGIN
DECLARE caller_in_id int(11) unsigned;
DECLARE callee_in_id int(11) unsigned;
DECLARE caller_out_id int(11) unsigned;
DECLARE callee_out_id int(11) unsigned;
SELECT vdp.value INTO caller_in_id FROM voip_dom_preferences vdp, voip_preferences vp
WHERE vp.attribute = 'dp_dom_caller_in' AND vdp.attribute_id = vp.id AND vdp.domain_id = OLD.id;
SELECT vdp.value INTO callee_in_id FROM voip_dom_preferences vdp, voip_preferences vp
WHERE vp.attribute = 'dp_dom_callee_in' AND vdp.attribute_id = vp.id AND vdp.domain_id = OLD.id;
SELECT vdp.value INTO caller_out_id FROM voip_dom_preferences vdp, voip_preferences vp
WHERE vp.attribute = 'dp_dom_caller_out' AND vdp.attribute_id = vp.id AND vdp.domain_id = OLD.id;
SELECT vdp.value INTO callee_out_id FROM voip_dom_preferences vdp, voip_preferences vp
WHERE vp.attribute = 'dp_dom_callee_out' AND vdp.attribute_id = vp.id AND vdp.domain_id = OLD.id;
IF OLD.local IS TRUE THEN
DELETE FROM kamailio.domain WHERE domain = OLD.domain;
END IF;
DELETE FROM kamailio.dialplan WHERE dpid IN
(caller_in_id, callee_in_id, caller_out_id, callee_out_id);
-- work around MySQL bug. the cascaded delete should trigger our
-- voip_dom_preferences delete action, but doesn't
DELETE FROM kamailio.dom_preferences WHERE domain = OLD.domain;
-- this will trigger the delete action for each subscriber
DELETE FROM provisioning.voip_subscribers WHERE domain_id = OLD.id;
END;
|
DELIMITER ;

@ -0,0 +1,50 @@
UPDATE provisioning.voip_domains SET local = TRUE;
ALTER TABLE provisioning.voip_domains DROP COLUMN `local`;
DROP TRIGGER provisioning.voip_dom_crepl_trig;
DROP TRIGGER provisioning.voip_dom_urepl_trig;
DROP TRIGGER provisioning.voip_dom_drepl_trig;
DELIMITER |
CREATE TRIGGER provisioning.voip_dom_crepl_trig AFTER INSERT ON voip_domains
FOR EACH ROW BEGIN
INSERT INTO kamailio.domain (domain) VALUES(NEW.domain);
END;
|
CREATE TRIGGER provisioning.voip_dom_drepl_trig BEFORE DELETE ON voip_domains
FOR EACH ROW BEGIN
DECLARE caller_in_id int(11) unsigned;
DECLARE callee_in_id int(11) unsigned;
DECLARE caller_out_id int(11) unsigned;
DECLARE callee_out_id int(11) unsigned;
SELECT vdp.value INTO caller_in_id FROM voip_dom_preferences vdp, voip_preferences vp
WHERE vp.attribute = 'dp_dom_caller_in' AND vdp.attribute_id = vp.id AND vdp.domain_id = OLD.id;
SELECT vdp.value INTO callee_in_id FROM voip_dom_preferences vdp, voip_preferences vp
WHERE vp.attribute = 'dp_dom_callee_in' AND vdp.attribute_id = vp.id AND vdp.domain_id = OLD.id;
SELECT vdp.value INTO caller_out_id FROM voip_dom_preferences vdp, voip_preferences vp
WHERE vp.attribute = 'dp_dom_caller_out' AND vdp.attribute_id = vp.id AND vdp.domain_id = OLD.id;
SELECT vdp.value INTO callee_out_id FROM voip_dom_preferences vdp, voip_preferences vp
WHERE vp.attribute = 'dp_dom_callee_out' AND vdp.attribute_id = vp.id AND vdp.domain_id = OLD.id;
DELETE FROM kamailio.domain WHERE domain = OLD.domain;
DELETE FROM kamailio.dialplan WHERE dpid IN
(caller_in_id, callee_in_id, caller_out_id, callee_out_id);
-- work around MySQL bug. the cascaded delete should trigger our
-- voip_dom_preferences delete action, but doesn't
DELETE FROM kamailio.dom_preferences WHERE domain = OLD.domain;
-- this will trigger the delete action for each subscriber
DELETE FROM provisioning.voip_subscribers WHERE domain_id = OLD.id;
END;
|
DELIMITER ;

@ -0,0 +1,2 @@
ALTER TABLE provisioning.voip_peer_hosts ADD COLUMN `domain` varchar(64) NOT NULL AFTER `ip`;
UPDATE provisioning.voip_peer_hosts SET domain = 'change-me.example.com';

@ -0,0 +1 @@
ALTER TABLE provisioning.voip_peer_hosts DROP COLUMN `domain`;

@ -0,0 +1,8 @@
DELETE FROM provisioning.voip_preferences WHERE internal = -1;
ALTER TABLE provisioning.voip_preferences DROP COLUMN `read_only`;
ALTER TABLE provisioning.voip_preferences DROP COLUMN `description`;
ALTER TABLE provisioning.voip_preferences MODIFY COLUMN `internal` bool NOT NULL default FALSE;
ALTER TABLE provisioning.voip_preferences MODIFY COLUMN `data_type` enum('bool','int','string') NOT NULL default 'string';
UPDATE provisioning.voip_preferences SET data_type = 'bool' where data_type = '';

@ -0,0 +1,88 @@
ALTER TABLE provisioning.voip_preferences ADD COLUMN `read_only` bool NOT NULL default FALSE;
ALTER TABLE provisioning.voip_preferences ADD COLUMN `description` text;
ALTER TABLE provisioning.voip_preferences MODIFY COLUMN `internal` tinyint(1) NOT NULL default 0;
ALTER TABLE provisioning.voip_preferences MODIFY COLUMN `data_type` enum('boolean','int','string') NOT NULL default 'string';
UPDATE provisioning.voip_preferences SET data_type = 'boolean' where data_type = '';
UPDATE provisioning.voip_preferences
SET read_only = TRUE,
description = 'See "lock_voip_account_subscriber" for a list of possible values. A lock value of "none" will not be returned to the caller. Read-only setting.'
WHERE attribute = 'lock';
UPDATE provisioning.voip_preferences
SET description = 'Specifies the operational mode of the incoming block list. If unset or set to a false value, it is a blacklist (accept all calls except from numbers listed in the block list), with a true value it is a whitelist (reject all calls except from numbers listed in the block list).'
WHERE attribute = 'block_in_mode';
UPDATE provisioning.voip_preferences
SET description = 'Contains wildcarded E.164 numbers that are (not) allowed to call the subscriber. "*", "?" and "[x-y]" with "x" and "y" representing numbers from 0 to 9 may be used as wildcards like in shell patterns.'
WHERE attribute = 'block_in_list';
UPDATE provisioning.voip_preferences
SET description = 'Incoming anonymous calls (with calling line identification restriction) are blocked if set to true.'
WHERE attribute = 'block_in_clir';
UPDATE provisioning.voip_preferences
SET description = 'Specifies the operational mode of the outgoing block list. If unset or set to a false value, it is a blacklist (allow all calls except to numbers listed in the block list), with a true value it is a whitelist (deny all calls except to numbers listed in the block list).'
WHERE attribute = 'block_out_mode';
UPDATE provisioning.voip_preferences
SET description = 'Contains wildcarded E.164 numbers that are (not) allowed to be called by the subscriber. "*", "?" and "[x-y]" with "x" and "y" representing numbers from 0 to 9 may be used as wildcards like in shell patterns.'
WHERE attribute = 'block_out_list';
UPDATE provisioning.voip_preferences
SET description = 'Same as "block_in_mode" but may only be set by administrators.'
WHERE attribute = 'adm_block_in_mode';
UPDATE provisioning.voip_preferences
SET description = 'Same as "block_in_list" but may only be set by administrators and is applied prior to the user setting.'
WHERE attribute = 'adm_block_in_list';
UPDATE provisioning.voip_preferences
SET description = 'Same as "block_in_clir" but may only be set by administrators and is applied prior to the user setting.'
WHERE attribute = 'adm_block_in_clir';
UPDATE provisioning.voip_preferences
SET description = 'Same as "block_out_mode" but may only be set by administrators.'
WHERE attribute = 'adm_block_out_mode';
UPDATE provisioning.voip_preferences
SET description = 'Same as "block_out_list" but may only be set by administrators and is applied prior to the user setting.'
WHERE attribute = 'adm_block_out_list';
UPDATE provisioning.voip_preferences
SET description = 'E.164 number or complete SIP URI. "Call forward unconditional" - if set, all incoming calls are forwarded to this destination. E.164 numbers have to be fully qualified and may be prefixed by a plus sign. E.164 numbers specified in SIP URIs have to be prefixed by a plus sign if they are fully qualified but they must always carry the subscriber\'s own domain, like in "sip:+<E.164number>@<subscriber.domain>".'
WHERE attribute = 'cfu';
UPDATE provisioning.voip_preferences
SET description = 'E.164 number or complete SIP URI. "Call forward busy" - if set, all incoming calls are forwarded to this destination while the subscriber is on a call. Same syntax as for "cfu".'
WHERE attribute = 'cfb';
UPDATE provisioning.voip_preferences
SET description = 'E.164 number or complete SIP URI. "Call forward not available" - if set, all incoming calls are forwarded to this destination if the subscriber is not online and registered. Same syntax as for "cfu".'
WHERE attribute = 'cfna';
UPDATE provisioning.voip_preferences
SET description = 'E.164 number or complete SIP URI. "Call forward timeout" - if set, all incoming calls are forwarded to this destination after a timeout that can be set via "ringtimeout" below. Same syntax as for "cfu".'
WHERE attribute = 'cft';
UPDATE provisioning.voip_preferences
SET description = 'Specifies how many seconds the system should wait before redirecting the call if "cft" is set.'
WHERE attribute = 'ringtimeout';
UPDATE provisioning.voip_preferences
SET description = 'E.164 number or complete SIP URI. "Calling line identification" - specifies the source E.164 number or SIP username that is used for outgoing calls. Automatically set to the primary E.164 number specified in the subscriber details.'
WHERE attribute = 'cli';
UPDATE provisioning.voip_preferences
SET description = '"Calling line identification restriction" - if set to true, the CLI is not displayed on outgoing calls.'
WHERE attribute = 'clir';
UPDATE provisioning.voip_preferences
SET description = 'The country code that will be used for routing of dialed numbers without a country code. Defaults to the country code of the E.164 number if the subscriber has one.'
WHERE attribute = 'cc';
UPDATE provisioning.voip_preferences
SET description = 'The area code that will be used for routing of dialed numbers without an area code. Defaults to the area code of the E.164 number if the subscriber has one.'
WHERE attribute = 'ac';
UPDATE provisioning.voip_preferences
SET description = 'The area code that will be used for routing of dialed service numbers without an area code. Defaults to "ac".'
WHERE attribute = 'svc_ac';
UPDATE provisioning.voip_preferences
SET description = 'The area code that will be used for routing of dialed emergency numbers without an area code. Defaults to "ac".'
WHERE attribute = 'emerg_ac';
UPDATE provisioning.voip_preferences
SET internal = -1,
description = 'Specifies the NCOS level that applies to the user.'
WHERE attribute = 'ncos';
UPDATE provisioning.voip_preferences
SET internal = -1,
description = 'Same as "ncos", but may only be set by administrators and is applied prior to the user setting.'
WHERE attribute = 'adm_ncos';
INSERT INTO provisioning.voip_preferences (attribute, type, data_type, max_occur, internal, description)
VALUES('ncos', 0, 'string', 1, -1, 'Specifies the NCOS level that applies to the user.');
INSERT INTO provisioning.voip_preferences (attribute, type, data_type, max_occur, internal, description)
VALUES('adm_ncos', 0, 'string', 1, -1, 'Same as "ncos", but may only be set by administrators and is applied prior to the user setting.');

@ -0,0 +1 @@
UPDATE provisioning.voip_preferences SET data_type = 'int' where attribute = 'lock';

@ -0,0 +1 @@
UPDATE provisioning.voip_preferences SET data_type = 'string' where attribute = 'lock';

@ -0,0 +1,7 @@
DROP TRIGGER billing.bill_zones_crepl_trig;
DROP TRIGGER billing.bill_zones_urepl_trig;
DROP TRIGGER billing.bill_fees_crepl_trig;
DROP TRIGGER billing.bill_fees_urepl_trig;
DROP TABLE billing.billing_zones_history;
DROP TABLE billing.billing_fees_history;

@ -0,0 +1,100 @@
-- do not run systems between r4085 and r4091, but upgrade further
-- there is no clean upgrade path if data is changed between these revisions
CREATE TABLE `billing`.`billing_zones_history` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`bz_id` int(11) UNSIGNED,
`billing_profile_id` int(11) UNSIGNED NOT NULL,
`zone` varchar(127) NOT NULL,
`detail` varchar(127) NULL,
PRIMARY KEY (`id`),
KEY `bzid_idx` (`bz_id`),
CONSTRAINT `b_z_h_bzid_ref` FOREIGN KEY (`bz_id`)
REFERENCES `billing_zones` (`id`)
ON DELETE SET NULL ON UPDATE NO ACTION
) ENGINE=InnoDB;
DELIMITER |
CREATE TRIGGER billing.bill_zones_crepl_trig AFTER INSERT ON billing_zones
FOR EACH ROW BEGIN
INSERT INTO billing_zones_history
VALUES(NULL, NEW.id, NEW.billing_profile_id, NEW.zone, NEW.detail);
END;
|
CREATE TRIGGER billing.bill_zones_urepl_trig AFTER UPDATE ON billing_zones
FOR EACH ROW BEGIN
UPDATE billing_zones_history
SET bz_id = NEW.id, billing_profile_id = NEW.billing_profile_id,
zone = NEW.zone, detail = NEW.detail
WHERE bz_id = OLD.id;
END;
|
DELIMITER ;
INSERT INTO billing.billing_zones_history
SELECT billing_zones.id, billing_zones.* FROM billing.billing_zones;
CREATE TABLE `billing`.`billing_fees_history` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`bf_id` int(11) UNSIGNED,
`billing_profile_id` int(11) UNSIGNED NOT NULL,
`billing_zone_id` int(11) UNSIGNED NULL,
`destination` varchar(255) NOT NULL,
`type` enum('call', 'sms') NOT NULL DEFAULT 'call',
`onpeak_init_rate` double NOT NULL DEFAULT 0,
`onpeak_init_interval` int(5) UNSIGNED NOT NULL DEFAULT 0,
`onpeak_follow_rate` double NOT NULL DEFAULT 0,
`onpeak_follow_interval` int(5) UNSIGNED NOT NULL DEFAULT 0,
`offpeak_init_rate` double NOT NULL DEFAULT 0,
`offpeak_init_interval` int(5) UNSIGNED NOT NULL DEFAULT 0,
`offpeak_follow_rate` double NOT NULL DEFAULT 0,
`offpeak_follow_interval` int(5) UNSIGNED NOT NULL DEFAULT 0,
`use_free_time` bool NOT NULL DEFAULT FALSE,
PRIMARY KEY (`id`),
KEY `bfid_idx` (`bf_id`),
CONSTRAINT `b_f_h_bfid_ref` FOREIGN KEY (`bf_id`)
REFERENCES `billing_fees` (`id`)
ON DELETE SET NULL ON UPDATE NO ACTION
) ENGINE=InnoDB;
DELIMITER |
CREATE TRIGGER billing.bill_fees_crepl_trig AFTER INSERT ON billing_fees
FOR EACH ROW BEGIN
INSERT INTO billing_fees_history
VALUES(NULL, NEW.id, NEW.billing_profile_id, NEW.billing_zone_id, NEW.destination,
NEW.type, NEW.onpeak_init_rate, NEW.onpeak_init_interval, NEW.onpeak_follow_rate,
NEW.onpeak_follow_interval, NEW.offpeak_init_rate, NEW.offpeak_init_interval,
NEW.offpeak_follow_rate, NEW.offpeak_follow_interval, NEW.use_free_time);
END;
|
CREATE TRIGGER billing.bill_fees_urepl_trig AFTER UPDATE ON billing_fees
FOR EACH ROW BEGIN
UPDATE billing_fees_history
SET bf_id = NEW.id, billing_profile_id = NEW.billing_profile_id,
billing_zone_id = NEW.billing_zone_id, destination = NEW.destination, type = NEW.type,
onpeak_init_rate = NEW.onpeak_init_rate, onpeak_init_interval = NEW.onpeak_init_interval,
onpeak_follow_rate = NEW.onpeak_follow_rate, onpeak_follow_interval = NEW.onpeak_follow_interval,
offpeak_init_rate = NEW.offpeak_init_rate, offpeak_init_interval = NEW.offpeak_init_interval,
offpeak_follow_rate = NEW.offpeak_follow_rate, offpeak_follow_interval = NEW.offpeak_follow_interval,
use_free_time = NEW.use_free_time
WHERE bf_id = OLD.id;
END;
|
DELIMITER ;
INSERT INTO billing.billing_fees_history
SELECT billing_fees.id, billing_fees.* FROM billing.billing_fees;

@ -0,0 +1,41 @@
-- this script does not change table data, as there is no reliable method
-- to determine the correct values for `billing_zone_id`
-- do not run systems between r4085 and r4091, but downgrade further
ALTER TABLE billing.billing_fees_history CHANGE COLUMN `billing_zones_history_id` `billing_zone_id` int(11) UNSIGNED NULL;
DROP TRIGGER billing.bill_fees_crepl_trig;
DROP TRIGGER billing.bill_fees_urepl_trig;
DELIMITER |
CREATE TRIGGER billing.bill_fees_crepl_trig AFTER INSERT ON billing_fees
FOR EACH ROW BEGIN
INSERT INTO billing_fees_history
VALUES(NULL, NEW.id, NEW.billing_profile_id, NEW.billing_zone_id, NEW.destination,
NEW.type, NEW.onpeak_init_rate, NEW.onpeak_init_interval, NEW.onpeak_follow_rate,
NEW.onpeak_follow_interval, NEW.offpeak_init_rate, NEW.offpeak_init_interval,
NEW.offpeak_follow_rate, NEW.offpeak_follow_interval, NEW.use_free_time);
END;
|
CREATE TRIGGER billing.bill_fees_urepl_trig AFTER UPDATE ON billing_fees
FOR EACH ROW BEGIN
UPDATE billing_fees_history
SET bf_id = NEW.id, billing_profile_id = NEW.billing_profile_id,
billing_zone_id = NEW.billing_zone_id, destination = NEW.destination, type = NEW.type,
onpeak_init_rate = NEW.onpeak_init_rate, onpeak_init_interval = NEW.onpeak_init_interval,
onpeak_follow_rate = NEW.onpeak_follow_rate, onpeak_follow_interval = NEW.onpeak_follow_interval,
offpeak_init_rate = NEW.offpeak_init_rate, offpeak_init_interval = NEW.offpeak_init_interval,
offpeak_follow_rate = NEW.offpeak_follow_rate, offpeak_follow_interval = NEW.offpeak_follow_interval,
use_free_time = NEW.use_free_time
WHERE bf_id = OLD.id;
END;
|
DELIMITER ;

@ -0,0 +1,47 @@
-- this script does not change table data, as there is no reliable method
-- to determine the correct values for `billing_zones_history_id`
-- do not run systems between r4085 and r4091
ALTER TABLE billing.billing_fees_history CHANGE COLUMN `billing_zone_id` `billing_zones_history_id` int(11) UNSIGNED NULL;
DROP TRIGGER billing.bill_fees_crepl_trig;
DROP TRIGGER billing.bill_fees_urepl_trig;
DELIMITER |
CREATE TRIGGER billing.bill_fees_crepl_trig AFTER INSERT ON billing_fees
FOR EACH ROW BEGIN
DECLARE my_bzh_id int UNSIGNED;
SELECT id INTO my_bzh_id FROM billing_zones_history WHERE bz_id = NEW.billing_zone_id;
INSERT INTO billing_fees_history
VALUES(NULL, NEW.id, NEW.billing_profile_id, my_bzh_id, NEW.destination,
NEW.type, NEW.onpeak_init_rate, NEW.onpeak_init_interval, NEW.onpeak_follow_rate,
NEW.onpeak_follow_interval, NEW.offpeak_init_rate, NEW.offpeak_init_interval,
NEW.offpeak_follow_rate, NEW.offpeak_follow_interval, NEW.use_free_time);
END;
|
CREATE TRIGGER billing.bill_fees_urepl_trig AFTER UPDATE ON billing_fees
FOR EACH ROW BEGIN
DECLARE my_bzh_id int UNSIGNED;
SELECT id INTO my_bzh_id FROM billing_zones_history WHERE bz_id = NEW.billing_zone_id;
UPDATE billing_fees_history
SET bf_id = NEW.id, billing_profile_id = NEW.billing_profile_id,
billing_zones_history_id = my_bzh_id, destination = NEW.destination, type = NEW.type,
onpeak_init_rate = NEW.onpeak_init_rate, onpeak_init_interval = NEW.onpeak_init_interval,
onpeak_follow_rate = NEW.onpeak_follow_rate, onpeak_follow_interval = NEW.onpeak_follow_interval,
offpeak_init_rate = NEW.offpeak_init_rate, offpeak_init_interval = NEW.offpeak_init_interval,
offpeak_follow_rate = NEW.offpeak_follow_rate, offpeak_follow_interval = NEW.offpeak_follow_interval,
use_free_time = NEW.use_free_time
WHERE bf_id = OLD.id;
END;
|
DELIMITER ;

@ -0,0 +1,3 @@
ALTER TABLE accounting.cdr MODIFY COLUMN `carrier_cost` float default NULL;
ALTER TABLE accounting.cdr MODIFY COLUMN `reseller_cost` float default NULL;
ALTER TABLE accounting.cdr MODIFY COLUMN `customer_cost` float default NULL;

@ -0,0 +1,3 @@
ALTER TABLE accounting.cdr MODIFY COLUMN `carrier_cost` decimal(10,2) default NULL;
ALTER TABLE accounting.cdr MODIFY COLUMN `reseller_cost` decimal(10,2) default NULL;
ALTER TABLE accounting.cdr MODIFY COLUMN `customer_cost` decimal(10,2) default NULL;

@ -0,0 +1 @@
ALTER TABLE billing.billing_profiles MODIFY COLUMN `prepaid` bool NOT NULL DEFAULT TRUE;

@ -0,0 +1 @@
ALTER TABLE billing.billing_profiles MODIFY COLUMN `prepaid` bool NOT NULL DEFAULT FALSE;

@ -0,0 +1,2 @@
DELETE FROM provisioning.voip_preferences WHERE attribute = 'block_out_override_pin';
DELETE FROM provisioning.voip_preferences WHERE attribute = 'adm_block_out_override_pin';

@ -0,0 +1,8 @@
INSERT INTO provisioning.voip_preferences
(attribute, type, data_type, max_occur, description)
VALUES('block_out_override_pin', 0, 'string', 1,
'A PIN code which may be used in a VSC to disable the outgoing user block list and NCOS level for a call.');
INSERT INTO provisioning.voip_preferences
(attribute, type, data_type, max_occur, description)
VALUES('adm_block_out_override_pin', 0, 'string', 1,
'Same as "block_out_override_pin" but additionally disables the administrative block list and NCOS level.');

@ -0,0 +1,2 @@
ALTER TABLE billing.voip_numbers MODIFY COLUMN `ac` int(5) UNSIGNED NOT NULL;
ALTER TABLE billing.voip_number_blocks MODIFY COLUMN `ac` int(5) UNSIGNED NOT NULL;

@ -0,0 +1,2 @@
ALTER TABLE billing.voip_numbers MODIFY COLUMN `ac` varchar(7) NOT NULL;
ALTER TABLE billing.voip_number_blocks MODIFY COLUMN `ac` varchar(7) NOT NULL;

@ -0,0 +1,5 @@
DELETE FROM provisioning.voip_preferences WHERE peer_pref = 1;
ALTER TABLE provisioning.voip_preferences DROP COLUMN `usr_pref`;
ALTER TABLE provisioning.voip_preferences DROP COLUMN `dom_pref`;
ALTER TABLE provisioning.voip_preferences DROP COLUMN `peer_pref`;

@ -0,0 +1,11 @@
ALTER TABLE provisioning.voip_preferences ADD COLUMN `usr_pref` bool NOT NULL default FALSE AFTER `max_occur`;
ALTER TABLE provisioning.voip_preferences ADD COLUMN `dom_pref` bool NOT NULL default FALSE AFTER `usr_pref`;
ALTER TABLE provisioning.voip_preferences ADD COLUMN `peer_pref` bool NOT NULL default FALSE AFTER `dom_pref`;
UPDATE provisioning.voip_preferences SET usr_pref = 1 WHERE attribute NOT LIKE 'dp_dom_%';
UPDATE provisioning.voip_preferences SET dom_pref = 1 WHERE attribute LIKE 'dp_dom_%';
INSERT INTO provisioning.voip_preferences (attribute, type, peer_pref, data_type, max_occur, description)
VALUES('auth_user', 0, 1, 'string', 1, 'A username used for authentication against the peer host.');
INSERT INTO provisioning.voip_preferences (attribute, type, peer_pref, data_type, max_occur, description)
VALUES('auth_pass', 0, 1, 'string', 1, 'A password used for authentication against the peer host.');

@ -0,0 +1,161 @@
CREATE TABLE `kamailio`.`gw` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`lcr_id` smallint(5) unsigned NOT NULL,
`gw_name` varchar(128) NOT NULL,
`grp_id` int(10) unsigned NOT NULL,
`ip_addr` varchar(15) NOT NULL,
`hostname` varchar(64) DEFAULT NULL,
`port` smallint(5) unsigned DEFAULT NULL,
`uri_scheme` tinyint(3) unsigned DEFAULT NULL,
`transport` tinyint(3) unsigned DEFAULT NULL,
`strip` tinyint(3) unsigned DEFAULT NULL,
`tag` varchar(16) DEFAULT NULL,
`weight` int(10) unsigned DEFAULT NULL,
`flags` int(10) unsigned NOT NULL DEFAULT '0',
`defunct` int(10) unsigned DEFAULT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `lcr_id_grp_id_gw_name_idx` (`lcr_id`,`grp_id`,`gw_name`),
UNIQUE KEY `lcr_id_grp_id_ip_addr_idx` (`lcr_id`,`grp_id`,`ip_addr`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
CREATE TABLE `kamailio`.`lcr` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`lcr_id` smallint(5) unsigned NOT NULL,
`prefix` varchar(16) DEFAULT NULL,
`from_uri` varchar(64) DEFAULT NULL,
`grp_id` int(10) unsigned NOT NULL,
`priority` tinyint(3) unsigned NOT NULL,
PRIMARY KEY (`id`),
KEY `lcr_id_idx` (`lcr_id`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
USE provisioning;
DROP trigger voip_prul_crepl_trig;
DROP trigger voip_prul_urepl_trig;
DROP trigger voip_prul_drepl_trig;
DROP trigger voip_pgrp_urepl_trig;
DROP trigger voip_pgrp_drepl_trig;
DROP trigger voip_phost_crepl_trig;
DROP trigger voip_phost_urepl_trig;
DROP trigger voip_phost_drepl_trig;
DELIMITER |
CREATE TRIGGER voip_prul_crepl_trig AFTER INSERT ON voip_peer_rules
FOR EACH ROW BEGIN
DECLARE prio int(11) unsigned;
SELECT priority INTO prio FROM voip_peer_groups
WHERE id = NEW.group_id;
INSERT INTO kamailio.lcr (lcr_id, prefix, from_uri, grp_id, priority)
VALUES(1, NEW.callee_prefix, IF(LENGTH(NEW.caller_prefix), CONCAT('^', NEW.caller_prefix), ''), NEW.group_id, prio);
END;
|
CREATE TRIGGER voip_prul_urepl_trig AFTER UPDATE ON voip_peer_rules
FOR EACH ROW BEGIN
DECLARE prio int(11) unsigned;
SELECT priority INTO prio FROM voip_peer_groups
WHERE id = NEW.group_id;
UPDATE kamailio.lcr SET prefix = NEW.callee_prefix,
from_uri = IF(LENGTH(NEW.caller_prefix), CONCAT('^', NEW.caller_prefix), '')
WHERE grp_id = OLD.group_id
AND prefix = OLD.callee_prefix
AND from_uri = IF(LENGTH(OLD.caller_prefix), CONCAT('^', OLD.caller_prefix), '')
AND priority = prio;
END;
|
CREATE TRIGGER voip_pgrp_urepl_trig AFTER UPDATE ON voip_peer_groups
FOR EACH ROW BEGIN
UPDATE kamailio.lcr SET priority = NEW.priority
WHERE grp_id = NEW.id;
END;
|
CREATE TRIGGER voip_prul_drepl_trig AFTER DELETE ON voip_peer_rules
FOR EACH ROW BEGIN
DECLARE prio int(11) unsigned;
SELECT priority INTO prio FROM voip_peer_groups
WHERE id = OLD.group_id;
DELETE FROM kamailio.lcr
WHERE grp_id = OLD.group_id AND
prefix = OLD.callee_prefix AND
from_uri = IF(LENGTH(OLD.caller_prefix), CONCAT('^', OLD.caller_prefix), '') AND
priority = prio;
END;
|
CREATE TRIGGER voip_pgrp_drepl_trig AFTER DELETE ON voip_peer_groups
FOR EACH ROW BEGIN
DELETE FROM kamailio.lcr WHERE grp_id = OLD.id;
DELETE FROM kamailio.gw WHERE grp_id = OLD.id;
END;
|
CREATE TRIGGER voip_phost_crepl_trig AFTER INSERT ON voip_peer_hosts
FOR EACH ROW BEGIN
INSERT INTO kamailio.gw (lcr_id, gw_name, grp_id, ip_addr, port, weight,
uri_scheme, transport, strip, tag, flags, defunct) VALUES
(1, NEW.name, NEW.group_id, NEW.ip, NEW.port, NEW.weight,
1, 1, 0, NULL, NEW.id, NULL);
END;
|
CREATE TRIGGER voip_phost_urepl_trig AFTER UPDATE ON voip_peer_hosts
FOR EACH ROW BEGIN
UPDATE kamailio.gw SET gw_name = NEW.name,
ip_addr = NEW.ip, port = NEW.port, weight = NEW.weight, tag = NULL
WHERE grp_id = OLD.group_id AND gw_name = OLD.name AND
ip_addr = OLD.ip AND port = OLD.port AND weight = OLD.weight;
END;
|
CREATE TRIGGER voip_phost_drepl_trig AFTER DELETE ON voip_peer_hosts
FOR EACH ROW BEGIN
DELETE FROM kamailio.gw
WHERE grp_id = OLD.group_id AND gw_name = OLD.name AND
ip_addr = OLD.ip AND port = OLD.port AND weight = OLD.weight;
DELETE FROM kamailio.dialplan
WHERE dpid IN (OLD.dp_caller_in_id, OLD.dp_callee_in_id,
OLD.dp_caller_out_id, OLD.dp_callee_out_id);
END;
|
DELIMITER ;
USE kamailio;
INSERT INTO gw (lcr_id, gw_name, grp_id, ip_addr, port, weight,
uri_scheme, transport, strip, flags)
SELECT 1, name, group_id, ip, port, weight, 1, 1, 0, id
FROM provisioning.voip_peer_hosts;
INSERT INTO lcr (lcr_id, prefix, from_uri, grp_id, priority)
SELECT 1, callee_prefix, IF(LENGTH(caller_prefix), CONCAT('^', caller_prefix), ''), group_id, priority
FROM provisioning.voip_peer_rules vph
INNER JOIN provisioning.voip_peer_groups vpg ON vpg.id = vph.group_id;
DROP table lcr_rule_target;
DROP table lcr_rule;
DROP table lcr_gw;

@ -0,0 +1,201 @@
CREATE TABLE `kamailio`.`lcr_gw` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`lcr_id` smallint(5) unsigned NOT NULL,
`gw_name` varchar(128) NOT NULL,
`ip_addr` varchar(15) NOT NULL,
`hostname` varchar(64) DEFAULT NULL,
`port` smallint(5) unsigned DEFAULT NULL,
`params` varchar(64) DEFAULT NULL,
`uri_scheme` tinyint(3) unsigned DEFAULT NULL,
`transport` tinyint(3) unsigned DEFAULT NULL,
`strip` tinyint(3) unsigned DEFAULT NULL,
`tag` varchar(16) DEFAULT NULL,
`flags` int(10) unsigned NOT NULL DEFAULT '0',
`defunct` int(10) unsigned DEFAULT NULL,
`group_id` int(11) unsigned NOT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `lcr_id_gw_name_idx` (`lcr_id`,`gw_name`),
UNIQUE KEY `lcr_id_ip_addr_idx` (`lcr_id`,`ip_addr`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
CREATE TABLE `kamailio`.`lcr_rule` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`lcr_id` smallint(5) unsigned NOT NULL,
`prefix` varchar(16) DEFAULT NULL,
`from_uri` varchar(64) DEFAULT NULL,
`stopper` int(10) unsigned NOT NULL DEFAULT '0',
`enabled` int(10) unsigned NOT NULL DEFAULT '1',
`group_id` int(11) unsigned NOT NULL,
PRIMARY KEY (`id`),
KEY `lcr_id_idx` (`lcr_id`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
CREATE TABLE `kamailio`.`lcr_rule_target` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`lcr_id` smallint(5) unsigned NOT NULL,
`rule_id` int(10) unsigned NOT NULL,
`gw_id` int(10) unsigned NOT NULL,
`priority` tinyint(3) unsigned NOT NULL,
`weight` int(10) unsigned NOT NULL DEFAULT '1',
PRIMARY KEY (`id`),
UNIQUE KEY `rule_id_gw_id_idx` (`rule_id`,`gw_id`),
KEY `lcr_id_idx` (`lcr_id`),
KEY `gw_id_idx` (`gw_id`),
CONSTRAINT `l_r_t_ruleid_ref` FOREIGN KEY (`rule_id`)
REFERENCES `lcr_rule` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `l_r_t_gwid_ref` FOREIGN KEY (`gw_id`)
REFERENCES `lcr_gw` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
USE provisioning;
DROP trigger voip_prul_crepl_trig;
DROP trigger voip_prul_urepl_trig;
DROP trigger voip_prul_drepl_trig;
DROP trigger voip_pgrp_urepl_trig;
DROP trigger voip_pgrp_drepl_trig;
DROP trigger voip_phost_crepl_trig;
DROP trigger voip_phost_urepl_trig;
DROP trigger voip_phost_drepl_trig;
DELIMITER |
CREATE TRIGGER voip_prul_crepl_trig AFTER INSERT ON voip_peer_rules
FOR EACH ROW BEGIN
INSERT INTO kamailio.lcr_rule (lcr_id, prefix, from_uri, stopper, enabled, group_id)
VALUES(1, NEW.callee_prefix,
IF(LENGTH(NEW.caller_prefix), CONCAT('^', NEW.caller_prefix), ''),
0, 1, NEW.group_id);
INSERT INTO kamailio.lcr_rule_target (lcr_id, rule_id, gw_id, priority, weight)
SELECT gw.lcr_id, LAST_INSERT_ID(), gw.id, vpg.priority, vph.weight
FROM kamailio.lcr_gw gw
INNER JOIN provisioning.voip_peer_hosts vph ON vph.ip = gw.ip_addr
AND gw.lcr_id = 1
AND vph.group_id = gw.group_id
INNER JOIN provisioning.voip_peer_groups vpg ON vpg.id = vph.group_id
WHERE vph.group_id = NEW.group_id;
END;
|
CREATE TRIGGER voip_prul_urepl_trig AFTER UPDATE ON voip_peer_rules
FOR EACH ROW BEGIN
UPDATE kamailio.lcr_rule
SET prefix = NEW.callee_prefix,
from_uri = IF(LENGTH(NEW.caller_prefix), CONCAT('^', NEW.caller_prefix), '')
WHERE prefix = OLD.callee_prefix
AND from_uri = IF(LENGTH(OLD.caller_prefix), CONCAT('^', OLD.caller_prefix), '')
AND group_id = OLD.group_id;
END;
|
CREATE TRIGGER voip_prul_drepl_trig AFTER DELETE ON voip_peer_rules
FOR EACH ROW BEGIN
DELETE FROM kamailio.lcr_rule
WHERE prefix = OLD.callee_prefix
AND from_uri = IF(LENGTH(OLD.caller_prefix), CONCAT('^', OLD.caller_prefix), '')
AND group_id = OLD.group_id;
-- foreign key will delete from kamailio.lcr_rule_target
END;
|
CREATE TRIGGER voip_pgrp_urepl_trig AFTER UPDATE ON voip_peer_groups
FOR EACH ROW BEGIN
UPDATE kamailio.lcr_rule_target rt, kamailio.lcr_gw gw
SET rt.priority = NEW.priority
WHERE gw.id = rt.gw_id
AND gw.lcr_id = 1
AND gw.group_id = NEW.id;
END;
|
CREATE TRIGGER voip_pgrp_drepl_trig AFTER DELETE ON voip_peer_groups
FOR EACH ROW BEGIN
DELETE kamailio.rule, kamailio.gw FROM kamailio.lcr_rule rule, kamailio.lcr_gw gw
WHERE rule.group_id = OLD.id and gw.group_id = OLD.id;
END;
|
CREATE TRIGGER voip_phost_crepl_trig AFTER INSERT ON voip_peer_hosts
FOR EACH ROW BEGIN
INSERT INTO kamailio.lcr_gw (lcr_id, gw_name, ip_addr, port, uri_scheme, transport, strip, flags, group_id)
VALUES(1, NEW.name, NEW.ip, NEW.port, 1, 1, 0, NEW.id, NEW.group_id);
INSERT INTO kamailio.lcr_rule_target (lcr_id, rule_id, gw_id, priority, weight)
SELECT rule.lcr_id, rule.id, LAST_INSERT_ID(), vpg.priority, NEW.weight
FROM kamailio.lcr_rule rule
INNER JOIN provisioning.voip_peer_groups vpg ON vpg.id = rule.group_id
WHERE vpg.id = NEW.group_id;
END;
|
CREATE TRIGGER voip_phost_urepl_trig AFTER UPDATE ON voip_peer_hosts
FOR EACH ROW BEGIN
UPDATE kamailio.lcr_gw
SET gw_name = NEW.name, ip_addr = NEW.ip, port = NEW.port, flags = NEW.id
WHERE lcr_id = 1 AND ip_addr = OLD.ip;
UPDATE kamailio.lcr_rule_target rt, kamailio.lcr_gw gw
SET rt.weight = NEW.weight
WHERE gw.id = rt.gw_id
AND gw.lcr_id = 1
AND gw.group_id = NEW.group_id
AND gw.ip_addr = NEW.ip;
END;
|
CREATE TRIGGER voip_phost_drepl_trig AFTER DELETE ON voip_peer_hosts
FOR EACH ROW BEGIN
DELETE FROM kamailio.lcr_gw
WHERE lcr_id = 1
AND group_id = OLD.group_id
AND ip_addr = OLD.ip;
-- foreign key will delete from kamailio.lcr_rule_target
END;
|
DELIMITER ;
USE kamailio;
INSERT INTO lcr_rule (lcr_id, prefix, from_uri, stopper, enabled, group_id)
SELECT 1, callee_prefix,
IF(LENGTH(caller_prefix), CONCAT('^', caller_prefix), ''),
0, 1, group_id
FROM provisioning.voip_peer_rules;
INSERT INTO lcr_gw (lcr_id, gw_name, ip_addr, port, uri_scheme, transport, strip, flags, group_id)
SELECT 1, name, ip, port, 1, 1, 0, id, group_id
FROM provisioning.voip_peer_hosts;
INSERT INTO lcr_rule_target (lcr_id, rule_id, gw_id, priority, weight)
SELECT rule.lcr_id, rule.id, gw.id, vpg.priority, vph.weight
FROM kamailio.lcr_rule rule
INNER JOIN provisioning.voip_peer_groups vpg ON vpg.id = rule.group_id
INNER JOIN provisioning.voip_peer_hosts vph ON vpg.id = vph.group_id
INNER JOIN lcr_gw gw ON gw.ip_addr = vph.ip AND gw.lcr_id = 1;
DROP table lcr;
DROP table gw;

@ -0,0 +1,4 @@
INSERT INTO kamailio.version (table_name, table_version) VALUES ('gw',10);
INSERT INTO kamailio.version (table_name, table_version) VALUES ('lcr',3);
DELETE FROM kamailio.version WHERE table_name = 'lcr_gw' OR table_name = 'lcr_rule' OR table_name = 'lcr_rule_target';

@ -0,0 +1,6 @@
INSERT INTO kamailio.version (table_name, table_version) VALUES ('lcr_gw',1);
INSERT INTO kamailio.version (table_name, table_version) VALUES ('lcr_rule_target',1);
INSERT INTO kamailio.version (table_name, table_version) VALUES ('lcr_rule',1);
DELETE FROM kamailio.version WHERE table_name = 'gw' OR table_name = 'lcr';

@ -0,0 +1,3 @@
ALTER TABLE kamailio.address DROP COLUMN `tag`;
UPDATE kamailio.version SET table_version = 3 WHERE table_name = 'address';

@ -0,0 +1,3 @@
ALTER TABLE kamailio.address ADD COLUMN `tag` VARCHAR(64) default NULL;
UPDATE kamailio.version SET table_version = 4 WHERE table_name = 'address';

@ -0,0 +1,5 @@
DELETE FROM provisioning.xmlgroups WHERE name = 'proxy-ng';
DELETE FROM provisioning.xmlhosts WHERE description = 'Kamailio-SR';
DELETE FROM provisioning.xmlhostgroups WHERE group_id = 6 and host_id = 3;

@ -0,0 +1,5 @@
INSERT INTO provisioning.xmlgroups (id, name) VALUES(6, 'proxy-ng');
INSERT INTO provisioning.xmlhosts (id, ip, port, path, description) VALUES (3,'127.0.0.1','5062','/','Kamailio-SR');
INSERT INTO provisioning.xmlhostgroups (id, group_id, host_id) VALUES (3,6,3);

@ -0,0 +1 @@
alter table kamailio.dialplan change column repl_exp `repl_exp` varchar(32) NOT NULL;

@ -0,0 +1 @@
alter table kamailio.dialplan change column repl_exp `repl_exp` varchar(64) NOT NULL;

@ -0,0 +1,6 @@
DROP TRIGGER `provisioning`.`voip_peerpref_crepl_trig`;
DROP TRIGGER `provisioning`.`voip_peerpref_urepl_trig`;
DROP TRIGGER `provisioning`.`voip_peerpref_drepl_trig`;
DROP TABLE `provisioning`.`voip_peer_preferences`;
DROP TABLE `kamailio`.`peer_preferences`;

@ -0,0 +1,69 @@
CREATE TABLE `provisioning`.`voip_peer_preferences` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`peer_host_id` int(11) UNSIGNED NOT NULL REFERENCES `voip_peer_hosts` (`id`),
`attribute_id` int(11) UNSIGNED NOT NULL REFERENCES `voip_preferences` (`id`),
`value` varchar(255) NOT NULL,
`modify_timestamp` timestamp NOT NULL default CURRENT_TIMESTAMP on update CURRENT_TIMESTAMP,
PRIMARY KEY (`id`),
KEY `peerhostid_idx` (`peer_host_id`),
KEY `attributeid_idx` (`attribute_id`),
CONSTRAINT `v_p_p_peerhostid_ref` FOREIGN KEY (`peer_host_id`)
REFERENCES `voip_peer_hosts` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `v_p_p_attributeid_ref` FOREIGN KEY (`attribute_id`)
REFERENCES `voip_preferences` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `kamailio`.`peer_preferences` (
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
`uuid` varchar(36) NOT NULL,
`username` varchar(128) NOT NULL DEFAULT '0',
`domain` varchar(64) NOT NULL DEFAULT '',
`attribute` varchar(32) NOT NULL DEFAULT '',
`type` int(11) NOT NULL DEFAULT '0',
`value` varchar(128) NOT NULL DEFAULT '',
`last_modified` datetime NOT NULL DEFAULT '1900-01-01 00:00:01',
PRIMARY KEY (`id`),
KEY `ua_idx` (`uuid`,`attribute`)
) ENGINE=InnoDB DEFAULT CHARSET=latin1;
USE provisioning;
DELIMITER |
CREATE TRIGGER voip_peerpref_crepl_trig AFTER INSERT ON voip_peer_preferences
FOR EACH ROW BEGIN
INSERT INTO kamailio.peer_preferences
(id, uuid, attribute, type, value, last_modified)
SELECT NEW.id, NEW.peer_host_id, attribute, type, NEW.value, NOW()
FROM provisioning.voip_preferences
WHERE id = NEW.attribute_id;
END;
|
CREATE TRIGGER voip_peerpref_urepl_trig AFTER UPDATE ON voip_peer_preferences
FOR EACH ROW BEGIN
UPDATE kamailio.peer_preferences pp, provisioning.voip_preferences vp
SET pp.id = NEW.id, pp.uuid = NEW.peer_host_id, pp.type = vp.type,
pp.attribute = vp.attribute, pp.value = NEW.value, pp.last_modified = NOW()
WHERE pp.id = OLD.id
AND vp.id = NEW.attribute_id;
END;
|
CREATE TRIGGER voip_peerpref_drepl_trig BEFORE DELETE ON voip_peer_preferences
FOR EACH ROW BEGIN
DELETE FROM kamailio.peer_preferences
WHERE id = OLD.id;
END;
|
DELIMITER ;

@ -0,0 +1,7 @@
UPDATE provisioning.voip_preferences
SET attribute = 'auth_user', usr_pref = 0
WHERE attribute = 'peer_auth_user';
UPDATE provisioning.voip_preferences
SET attribute = 'auth_pass', usr_pref = 0
WHERE attribute = 'peer_auth_pass';

@ -0,0 +1,7 @@
UPDATE provisioning.voip_preferences
SET attribute = 'peer_auth_user', usr_pref = 1
WHERE attribute = 'auth_user';
UPDATE provisioning.voip_preferences
SET attribute = 'peer_auth_pass', usr_pref = 1
WHERE attribute = 'auth_pass';

@ -0,0 +1 @@
DELETE FROM provisioning.voip_preferences WHERE attribute='unauth_inbound_calls';

@ -0,0 +1 @@
INSERT INTO provisioning.voip_preferences (attribute, type, dom_pref, data_type, max_occur, description) VALUES('unauth_inbound_calls', 1, 1, 'boolean', 1, 'Allow unauthenticated inbound calls from FOREIGN domain to users within this domain. Use with care - it allows to flood your users with voice spam.');

@ -0,0 +1 @@
alter table provisioning.xmlhosts drop column sip_port;

@ -0,0 +1,2 @@
alter table provisioning.xmlhosts add column sip_port int(5) unsigned default NULL after path;
update provisioning.xmlhosts set sip_port = 5062 where id = 1;

@ -0,0 +1 @@
DELETE FROM provisioning.voip_preferences WHERE attribute = 'peer_auth_realm';

@ -0,0 +1,2 @@
INSERT INTO provisioning.voip_preferences (attribute, type, usr_pref, peer_pref, data_type, max_occur, description)
VALUES('peer_auth_realm', 0, 1, 1, 'string', 1, 'A realm used for authentication against the peer host.');

@ -0,0 +1,2 @@
ALTER TABLE kamailio.voicemail_spool CHANGE COLUMN origtime origtime INT(11) UNSIGNED DEFAULT '0';
ALTER TABLE kamailio.voicemail_spool CHANGE COLUMN duration duration INT(11) UNSIGNED DEFAULT '0';

@ -0,0 +1,2 @@
ALTER TABLE kamailio.voicemail_spool CHANGE COLUMN origtime origtime VARCHAR(16) DEFAULT '';
ALTER TABLE kamailio.voicemail_spool CHANGE COLUMN duration duration VARCHAR(16) DEFAULT '';

@ -0,0 +1 @@
DROP TABLE kamailio.sems_registrations;

@ -0,0 +1,10 @@
CREATE TABLE kamailio.sems_registrations (
`subscriber_id` int(11) NOT NULL,
`registration_status` tinyint(1) NOT NULL DEFAULT '0',
`last_registration` datetime DEFAULT NULL,
`expiry` datetime DEFAULT NULL,
`last_code` smallint(2) DEFAULT NULL,
`last_reason` varchar(256) DEFAULT NULL,
`contacts` varchar(512) DEFAULT NULL,
PRIMARY KEY (`subscriber_id`)
) ENGINE=InnoDB;

@ -0,0 +1 @@
DROP DATABASE carrier;

@ -0,0 +1,90 @@
USE mysql;
CREATE DATABASE carrier CHARACTER SET 'utf8';
USE carrier;
CREATE TABLE `customers` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`url` varchar(31) NOT NULL,
`shopuser` varchar(31) NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `shopuser_idx` (`shopuser`)
) ENGINE=InnoDB;
CREATE TABLE `orders` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`customer_id` int(11) UNSIGNED NOT NULL REFERENCES `customers` (`id`),
PRIMARY KEY (`id`),
KEY `customerid_idx` (`customer_id`),
CONSTRAINT `o_customerid_ref` FOREIGN KEY (`customer_id`)
REFERENCES `customers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `contracts` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`url` varchar(31) NOT NULL,
`customer_id` int(11) UNSIGNED NULL REFERENCES `customers` (`id`),
PRIMARY KEY (`id`),
KEY `customerid_idx` (`customer_id`),
CONSTRAINT `c_customerid_ref` FOREIGN KEY (`customer_id`)
REFERENCES `customers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `credits` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`contract_id` int(11) UNSIGNED NOT NULL REFERENCES `contracts` (`id`),
PRIMARY KEY (`id`),
KEY `contractid_idx` (`contract_id`),
CONSTRAINT `c_contractid_ref` FOREIGN KEY (`contract_id`)
REFERENCES `contracts` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `payments` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`order_id` int(11) UNSIGNED NULL REFERENCES `orders` (`id`),
`credit_id` int(11) UNSIGNED NULL REFERENCES `credits` (`id`),
PRIMARY KEY (`id`),
KEY `orderid_idx` (`order_id`),
CONSTRAINT `p_orderid_ref` FOREIGN KEY (`order_id`)
REFERENCES `orders` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE,
KEY `creditid_idx` (`credit_id`),
CONSTRAINT `p_creditid_ref` FOREIGN KEY (`credit_id`)
REFERENCES `credits` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `subscribers` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`username` varchar(127) NOT NULL,
`domain` varchar(127) NOT NULL,
`webusername` varchar(127) default NULL,
`contract_id` int(11) UNSIGNED NOT NULL REFERENCES `contracts` (`id`),
PRIMARY KEY (`id`),
UNIQUE KEY `usrdom_idx` (`username`, `domain`),
UNIQUE KEY `domwebuser_idx` (`domain`, `webusername`),
KEY `contractid_idx` (`contract_id`),
CONSTRAINT `s_contractid_ref` FOREIGN KEY (`contract_id`)
REFERENCES `contracts` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `numbers` (
`number` varchar(42) NOT NULL,
`subscriber_id` int(11) UNSIGNED NULL REFERENCES `subscribers` (`id`),
PRIMARY KEY `number_idx` (`number`),
KEY `subscriberid_idx` (`subscriber_id`),
CONSTRAINT `n_subscriberid_ref` FOREIGN KEY (`subscriber_id`)
REFERENCES `subscribers` (`id`)
ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `interceptions` (
`id` int(11) UNSIGNED NOT NULL auto_increment,
`url` varchar(31) NOT NULL,
PRIMARY KEY (`id`)
) ENGINE=InnoDB;

@ -0,0 +1 @@
ALTER TABLE `carrier`.`contracts` DROP COLUMN `sip_uri`;

@ -0,0 +1 @@
ALTER TABLE `carrier`.`contracts` ADD COLUMN `sip_uri` varchar(127) NOT NULL;

@ -0,0 +1,6 @@
ALTER TABLE kamailio.acc CHANGE COLUMN callid callid varchar(64) NOT NULL DEFAULT '';
ALTER TABLE kamailio.acc_trash CHANGE COLUMN callid callid varchar(64) NOT NULL DEFAULT '';
ALTER TABLE kamailio.acc_backup CHANGE COLUMN callid callid varchar(64) NOT NULL DEFAULT '';
ALTER TABLE accounting.acc CHANGE COLUMN callid callid varchar(64) NOT NULL DEFAULT '';
ALTER TABLE accounting.acc_trash CHANGE COLUMN callid callid varchar(64) NOT NULL DEFAULT '';
ALTER TABLE accounting.acc_backup CHANGE COLUMN callid callid varchar(64) NOT NULL DEFAULT '';

@ -0,0 +1,6 @@
ALTER TABLE kamailio.acc CHANGE COLUMN callid callid varchar(255) NOT NULL DEFAULT '';
ALTER TABLE kamailio.acc_trash CHANGE COLUMN callid callid varchar(255) NOT NULL DEFAULT '';
ALTER TABLE kamailio.acc_backup CHANGE COLUMN callid callid varchar(255) NOT NULL DEFAULT '';
ALTER TABLE accounting.acc CHANGE COLUMN callid callid varchar(255) NOT NULL DEFAULT '';
ALTER TABLE accounting.acc_trash CHANGE COLUMN callid callid varchar(255) NOT NULL DEFAULT '';
ALTER TABLE accounting.acc_backup CHANGE COLUMN callid callid varchar(255) NOT NULL DEFAULT '';

@ -0,0 +1 @@
DELETE FROM provisioning.voip_preferences WHERE attribute='ignore_userprovided_cli';

@ -0,0 +1 @@
INSERT INTO provisioning.voip_preferences (attribute, type, dom_pref, usr_pref, data_type, max_occur, description) VALUES('ignore_userprovided_cli', 1, 1, 1, 'boolean', 1, 'Discard any subscriber provided CLI information');

@ -0,0 +1,2 @@
DELETE FROM provisioning.voip_preferences WHERE attribute='always_use_rtpproxy';
DELETE FROM provisioning.voip_preferences WHERE attribute='never_use_rtpproxy';

@ -0,0 +1,2 @@
INSERT INTO provisioning.voip_preferences (attribute, type, dom_pref, usr_pref, peer_pref, data_type, max_occur, description) VALUES('always_use_rtpproxy', 1, 1, 1, 1, 'boolean', 1, 'Force rtp relay for this peer/domain/user.');
INSERT INTO provisioning.voip_preferences (attribute, type, dom_pref, usr_pref, peer_pref, data_type, max_occur, description) VALUES('never_use_rtpproxy', 1, 1, 1, 1, 'boolean', 1, 'Do not use rtp relay for this peer/domain/user. Rtp will be relayed if other participants have always_use_rtpproxy preference enabled.');

@ -0,0 +1,7 @@
use billing;
ALTER TABLE `customers` DROP COLUMN `external_id`;
ALTER TABLE `contracts` DROP COLUMN `external_id`;
ALTER TABLE `voip_subscribers` DROP COLUMN `external_id`;

@ -0,0 +1,10 @@
use billing;
ALTER TABLE `customers` ADD COLUMN `external_id` varchar(255) NULL default NULL AFTER `comm_contact_id`;
ALTER TABLE `customers` ADD KEY `externalid_idx` (`external_id`);
ALTER TABLE `contracts` ADD COLUMN `external_id` varchar(255) NULL default NULL AFTER `status`;
ALTER TABLE `contracts` ADD KEY `externalid_idx` (`external_id`);
ALTER TABLE `voip_subscribers` ADD COLUMN `external_id` varchar(255) NULL default NULL AFTER `primary_number_id`;
ALTER TABLE `voip_subscribers` ADD KEY `externalid_idx` (`external_id`);

@ -0,0 +1,8 @@
use provisioning;
UPDATE voip_preferences
SET description = 'A realm used for authentication against a peer host.'
WHERE attribute = 'peer_auth_realm';
DELETE FROM voip_preferences WHERE attribute = 'peer_auth_register';
DELETE FROM voip_preferences WHERE attribute = 'concurrent_max';
DELETE FROM voip_preferences WHERE attribute = 'concurrent_max_out';

@ -0,0 +1,11 @@
use provisioning;
UPDATE voip_preferences
SET description = 'A realm (hostname) used to identify and for authentication against a peer host.'
WHERE attribute = 'peer_auth_realm';
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, description)
VALUES('peer_auth_register', 1, 1, 1, 1, 'boolean', 1, 'Specifies whether registration at the peer host is desired.');
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, description)
VALUES('concurrent_max', 1, 1, 1, 1, 'int', 1, 'Maximum number of concurrent sessions (calls) for a subscriber or peer.');
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, description)
VALUES('concurrent_max_out', 1, 1, 1, 1, 'int', 1, 'Maximum number of concurrent outgoing sessions (calls) coming from a subscriber or going to a peer.');

@ -0,0 +1,3 @@
use provisioning;
DELETE FROM voip_preferences WHERE attribute = 'allowed_clis';

@ -0,0 +1,4 @@
use provisioning;
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, description)
VALUES('allowed_clis', 0, 1, 'string', 0, 'A list of shell patterns specifying which CLIs are allowed to be set by the subscriber. "*", "?" and "[x-y]" with "x" and "y" representing numbers from 0 to 9 may be used as wildcards as usual in shell patterns.');

@ -0,0 +1 @@
DELETE FROM provisioning.voip_preferences WHERE attribute='force_to_pstn';

@ -0,0 +1 @@
INSERT INTO provisioning.voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, description) VALUES('force_to_pstn', 1, 1, 1, 1, 'boolean', 1, 'Force calls from this user/domain/peer to be routed to PSTN even if the callee is local. Use with caution, as this setting may increase your costs! When enabling this option in a peer, make sure you trust it, as the NGCP will become an open relay for it!');

@ -0,0 +1,2 @@
DROP TABLE IF EXISTS kamailio.fax_journal;
REVOKE ALL PRIVILEGES ON provisioning.* FROM 'hylafax'@'localhost';

@ -0,0 +1,20 @@
CREATE TABLE kamailio.fax_journal (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`subscriber_id` int(10) unsigned NOT NULL DEFAULT '0',
`the_timestamp` int(11) unsigned NOT NULL DEFAULT '0',
`duration` int(11) unsigned NOT NULL DEFAULT '0',
`direction` enum('in','out') NOT NULL DEFAULT 'in',
`peer_number` varchar(255) NOT NULL DEFAULT '',
`peer_name` varchar(255) NOT NULL DEFAULT '',
`pages` int(10) unsigned NOT NULL DEFAULT '0',
`reason` varchar(255) NOT NULL,
`status` varchar(255) NOT NULL DEFAULT '',
`signal_rate` int(10) unsigned NOT NULL DEFAULT '0',
`quality` varchar(255) NOT NULL DEFAULT '',
`filename` varchar(255) NOT NULL DEFAULT '',
PRIMARY KEY (`id`),
KEY `selkey` (`subscriber_id`,`direction`)
) ENGINE=InnoDB;
GRANT SELECT ON kamailio.* TO 'hylafax'@'localhost' IDENTIFIED BY 'PW_HYLAFAX';
GRANT INSERT ON kamailio.fax_journal TO 'hylafax'@'localhost' IDENTIFIED BY 'PW_HYLAFAX';
GRANT SELECT ON provisioning.* TO 'hylafax'@'localhost' IDENTIFIED BY 'PW_HYLAFAX';

@ -0,0 +1,19 @@
ALTER TABLE kamailio.acc CHANGE COLUMN src_leg src_leg varchar(255) DEFAULT NULL;
ALTER TABLE kamailio.acc CHANGE COLUMN dst_leg dst_leg varchar(255) DEFAULT NULL;
ALTER TABLE accounting.acc CHANGE COLUMN src_leg src_leg varchar(255) DEFAULT NULL;
ALTER TABLE accounting.acc CHANGE COLUMN dst_leg dst_leg varchar(255) DEFAULT NULL;
ALTER TABLE accounting.acc_backup CHANGE COLUMN src_leg src_leg varchar(255) DEFAULT NULL;
ALTER TABLE accounting.acc_backup CHANGE COLUMN dst_leg dst_leg varchar(255) DEFAULT NULL;
ALTER TABLE accounting.acc_trash CHANGE COLUMN src_leg src_leg varchar(255) DEFAULT NULL;
ALTER TABLE accounting.acc_trash CHANGE COLUMN dst_leg dst_leg varchar(255) DEFAULT NULL;
ALTER TABLE accounting.cdr DROP COLUMN source_external_subscriber_id;
ALTER TABLE accounting.cdr DROP COLUMN source_external_contract_id;
ALTER TABLE accounting.cdr DROP COLUMN source_account_id;
ALTER TABLE accounting.cdr DROP COLUMN destination_external_subscriber_id;
ALTER TABLE accounting.cdr DROP COLUMN destination_external_contract_id;
ALTER TABLE accounting.cdr DROP COLUMN destination_account_id;
ALTER TABLE accounting.cdr DROP COLUMN peer_auth_user;
ALTER TABLE accounting.cdr DROP COLUMN peer_auth_realm;

@ -0,0 +1,19 @@
ALTER TABLE kamailio.acc CHANGE COLUMN src_leg src_leg varchar(2048) DEFAULT NULL;
ALTER TABLE kamailio.acc CHANGE COLUMN dst_leg dst_leg varchar(2048) DEFAULT NULL;
ALTER TABLE accounting.acc CHANGE COLUMN src_leg src_leg varchar(2048) DEFAULT NULL;
ALTER TABLE accounting.acc CHANGE COLUMN dst_leg dst_leg varchar(2048) DEFAULT NULL;
ALTER TABLE accounting.acc_backup CHANGE COLUMN src_leg src_leg varchar(2048) DEFAULT NULL;
ALTER TABLE accounting.acc_backup CHANGE COLUMN dst_leg dst_leg varchar(2048) DEFAULT NULL;
ALTER TABLE accounting.acc_trash CHANGE COLUMN src_leg src_leg varchar(2048) DEFAULT NULL;
ALTER TABLE accounting.acc_trash CHANGE COLUMN dst_leg dst_leg varchar(2048) DEFAULT NULL;
ALTER TABLE accounting.cdr ADD COLUMN source_external_subscriber_id varchar(255) DEFAULT NULL AFTER source_provider_id;
ALTER TABLE accounting.cdr ADD COLUMN source_external_contract_id varchar(255) DEFAULT NULL AFTER source_external_subscriber_id;
ALTER TABLE accounting.cdr ADD COLUMN source_account_id int(11) unsigned NOT NULL DEFAULT '0' AFTER source_external_contract_id;
ALTER TABLE accounting.cdr ADD COLUMN destination_external_subscriber_id varchar(255) DEFAULT NULL AFTER destination_provider_id;
ALTER TABLE accounting.cdr ADD COLUMN destination_external_contract_id varchar(255) DEFAULT NULL AFTER destination_external_subscriber_id;
ALTER TABLE accounting.cdr ADD COLUMN destination_account_id int(11) unsigned NOT NULL DEFAULT '0' AFTER destination_external_contract_id;
ALTER TABLE accounting.cdr ADD COLUMN peer_auth_user varchar(255) DEFAULT NULL AFTER destination_domain_in;
ALTER TABLE accounting.cdr ADD COLUMN peer_auth_realm varchar(255) DEFAULT NULL AFTER peer_auth_user;

@ -0,0 +1,55 @@
DROP TRIGGER provisioning.voip_prul_crepl_trig;
DROP TRIGGER provisioning.voip_prul_urepl_trig;
DROP TRIGGER provisioning.voip_prul_drepl_trig;
DELIMITER |
CREATE TRIGGER provisioning.voip_prul_crepl_trig AFTER INSERT ON voip_peer_rules
FOR EACH ROW BEGIN
INSERT INTO kamailio.lcr_rule (lcr_id, prefix, from_uri, stopper, enabled, group_id)
VALUES(1, NEW.callee_prefix,
IF(LENGTH(NEW.caller_prefix), CONCAT('^', NEW.caller_prefix), ''),
0, 1, NEW.group_id);
INSERT INTO kamailio.lcr_rule_target (lcr_id, rule_id, gw_id, priority, weight)
SELECT gw.lcr_id, LAST_INSERT_ID(), gw.id, vpg.priority, vph.weight
FROM kamailio.lcr_gw gw
INNER JOIN provisioning.voip_peer_hosts vph ON vph.ip = gw.ip_addr
AND gw.lcr_id = 1
AND vph.group_id = gw.group_id
INNER JOIN provisioning.voip_peer_groups vpg ON vpg.id = vph.group_id
WHERE vph.group_id = NEW.group_id;
END;
|
CREATE TRIGGER provisioning.voip_prul_urepl_trig AFTER UPDATE ON voip_peer_rules
FOR EACH ROW BEGIN
UPDATE kamailio.lcr_rule
SET prefix = NEW.callee_prefix,
from_uri = IF(LENGTH(NEW.caller_prefix), CONCAT('^', NEW.caller_prefix), '')
WHERE prefix = OLD.callee_prefix
AND from_uri = IF(LENGTH(OLD.caller_prefix), CONCAT('^', OLD.caller_prefix), '')
AND group_id = OLD.group_id;
END;
|
CREATE TRIGGER provisioning.voip_prul_drepl_trig AFTER DELETE ON voip_peer_rules
FOR EACH ROW BEGIN
DELETE FROM kamailio.lcr_rule
WHERE prefix = OLD.callee_prefix
AND from_uri = IF(LENGTH(OLD.caller_prefix), CONCAT('^', OLD.caller_prefix), '')
AND group_id = OLD.group_id;
-- foreign key will delete from kamailio.lcr_rule_target
END;
|
DELIMITER ;

@ -0,0 +1,54 @@
DROP TRIGGER provisioning.voip_prul_crepl_trig;
DROP TRIGGER provisioning.voip_prul_urepl_trig;
DROP TRIGGER provisioning.voip_prul_drepl_trig;
DELIMITER |
CREATE TRIGGER provisioning.voip_prul_crepl_trig AFTER INSERT ON voip_peer_rules
FOR EACH ROW BEGIN
INSERT INTO kamailio.lcr_rule (lcr_id, prefix, from_uri, stopper, enabled, group_id)
VALUES(1, NEW.callee_prefix, NEW.caller_prefix,
0, 1, NEW.group_id);
INSERT INTO kamailio.lcr_rule_target (lcr_id, rule_id, gw_id, priority, weight)
SELECT gw.lcr_id, LAST_INSERT_ID(), gw.id, vpg.priority, vph.weight
FROM kamailio.lcr_gw gw
INNER JOIN provisioning.voip_peer_hosts vph ON vph.ip = gw.ip_addr
AND gw.lcr_id = 1
AND vph.group_id = gw.group_id
INNER JOIN provisioning.voip_peer_groups vpg ON vpg.id = vph.group_id
WHERE vph.group_id = NEW.group_id;
END;
|
CREATE TRIGGER provisioning.voip_prul_urepl_trig AFTER UPDATE ON voip_peer_rules
FOR EACH ROW BEGIN
UPDATE kamailio.lcr_rule
SET prefix = NEW.callee_prefix, from_uri = NEW.caller_prefix
WHERE prefix = OLD.callee_prefix
AND from_uri = OLD.caller_prefix
AND group_id = OLD.group_id;
END;
|
CREATE TRIGGER provisioning.voip_prul_drepl_trig AFTER DELETE ON voip_peer_rules
FOR EACH ROW BEGIN
DELETE FROM kamailio.lcr_rule
WHERE prefix = OLD.callee_prefix
AND from_uri = OLD.caller_prefix
AND group_id = OLD.group_id;
-- foreign key will delete from kamailio.lcr_rule_target
END;
|
DELIMITER ;
UPDATE kamailio.lcr_rule SET from_uri = REPLACE(from_uri, '^', '');

@ -0,0 +1,4 @@
use provisioning;
ALTER TABLE voip_subscribers MODIFY COLUMN `password` varchar(31) default NULL;
ALTER TABLE voip_subscribers MODIFY COLUMN `webpassword` varchar(31) default NULL;

@ -0,0 +1,4 @@
use provisioning;
ALTER TABLE voip_subscribers MODIFY COLUMN `password` varchar(40) default NULL;
ALTER TABLE voip_subscribers MODIFY COLUMN `webpassword` varchar(40) default NULL;

@ -0,0 +1,5 @@
use provisioning;
DELETE FROM voip_preferences WHERE attribute = 'account_id';
DELETE FROM voip_preferences WHERE attribute = 'ext_contract_id';
DELETE FROM voip_preferences WHERE attribute = 'ext_subscriber_id';

@ -0,0 +1,5 @@
use provisioning;
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, internal) VALUES('account_id', 1, 1, 'int', 1, 1);
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, internal) VALUES('ext_contract_id', 0, 1, 'string', 1, 1);
INSERT INTO voip_preferences (attribute, type, usr_pref, data_type, max_occur, internal) VALUES('ext_subscriber_id', 0, 1, 'string', 1, 1);

@ -0,0 +1 @@
DELETE FROM provisioning.voip_preferences WHERE attribute='find_subscriber_by_auth_user';

@ -0,0 +1 @@
INSERT INTO provisioning.voip_preferences (attribute, type, dom_pref, usr_pref, peer_pref, data_type, max_occur, description) VALUES('find_subscriber_by_auth_user', 1, 0, 0, 1, 'boolean', 1, 'For incoming calls from this peer, find the destination subscriber also using its auth_username used for outbound registration.');

@ -0,0 +1,5 @@
use carrier;
ALTER TABLE `customers` DROP COLUMN `external_id`;
ALTER TABLE `contracts` DROP COLUMN `external_id`;
ALTER TABLE `subscribers` DROP COLUMN `external_id`;

@ -0,0 +1,10 @@
use carrier;
ALTER TABLE `customers` ADD COLUMN `external_id` varchar(255) NULL default NULL AFTER `id`;
ALTER TABLE `customers` ADD UNIQUE KEY `externalid_idx` (`external_id`);
ALTER TABLE `contracts` ADD COLUMN `external_id` varchar(255) NULL default NULL AFTER `id`;
ALTER TABLE `contracts` ADD UNIQUE KEY `externalid_idx` (`external_id`);
ALTER TABLE `subscribers` ADD COLUMN `external_id` varchar(255) NULL default NULL AFTER `id`;
ALTER TABLE `subscribers` ADD UNIQUE KEY `externalid_idx` (`external_id`);

@ -0,0 +1 @@
ALTER TABLE kamailio.subscriber MODIFY COLUMN `password` varchar(25) NOT NULL default '';

@ -0,0 +1 @@
ALTER TABLE kamailio.subscriber MODIFY COLUMN `password` varchar(40) NOT NULL default '';

@ -0,0 +1,253 @@
-- NOTE! This does not migrate data from new to old tables, but will delete everything from kamailio.dialplan!
use provisioning;
CREATE TABLE `voip_domain_rewrites` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`domain_id` int(11) unsigned NOT NULL,
`match_pattern` varchar(64) NOT NULL DEFAULT '',
`replace_pattern` varchar(64) NOT NULL,
`description` varchar(127) NOT NULL DEFAULT '',
`direction` enum('in','out') NOT NULL,
`field` enum('caller','callee') NOT NULL,
`priority` int(11) unsigned NOT NULL DEFAULT 50,
PRIMARY KEY (`id`),
KEY `domainidx` (`domain_id`),
CONSTRAINT `v_drw_domainid_ref` FOREIGN KEY (`domain_id`) REFERENCES `voip_domains` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
CREATE TABLE `voip_peer_rewrites` (
`id` int(11) unsigned NOT NULL auto_increment,
`peer_id` int(11) unsigned NOT NULL,
`match_pattern` varchar(64) NOT NULL default '',
`replace_pattern` varchar(64) NOT NULL,
`description` varchar(127) NOT NULL default '',
`direction` enum('in','out') NOT NULL default 'in',
`field` enum('caller','callee') NOT NULL default 'caller',
`priority` int(11) unsigned NOT NULL DEFAULT 50,
PRIMARY KEY (`id`),
KEY `peeridx` (`peer_id`),
KEY `dirfieldidx` (`direction`,`field`),
CONSTRAINT `v_prw_peerid_ref` FOREIGN KEY (`peer_id`) REFERENCES `voip_peer_hosts` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
DROP TRIGGER voip_rwrules_crepl_trig;
DROP TRIGGER voip_rwrules_urepl_trig;
DROP TRIGGER voip_rwrules_drepl_trig;
DROP TRIGGER voip_rwrulesets_drepl_trig;
DELIMITER |
CREATE TRIGGER voip_domrw_crepl_trig AFTER INSERT ON voip_domain_rewrites
FOR EACH ROW BEGIN
DECLARE caller_in_id int(11) unsigned;
DECLARE callee_in_id int(11) unsigned;
DECLARE caller_out_id int(11) unsigned;
DECLARE callee_out_id int(11) unsigned;
DECLARE dp_id int(11) unsigned default 0;
SELECT vdp.value INTO caller_in_id FROM voip_dom_preferences vdp, voip_preferences vp,
voip_domains vd WHERE vd.id = NEW.domain_id AND vp.attribute = 'dp_dom_caller_in'
AND vdp.attribute_id = vp.id AND vd.id = vdp.domain_id;
SELECT vdp.value INTO callee_in_id FROM voip_dom_preferences vdp, voip_preferences vp,
voip_domains vd WHERE vd.id = NEW.domain_id AND vp.attribute = 'dp_dom_callee_in'
AND vdp.attribute_id = vp.id AND vd.id = vdp.domain_id;
SELECT vdp.value INTO caller_out_id FROM voip_dom_preferences vdp, voip_preferences vp,
voip_domains vd WHERE vd.id = NEW.domain_id AND vp.attribute = 'dp_dom_caller_out'
AND vdp.attribute_id = vp.id AND vd.id = vdp.domain_id;
SELECT vdp.value INTO callee_out_id FROM voip_dom_preferences vdp, voip_preferences vp,
voip_domains vd WHERE vd.id = NEW.domain_id AND vp.attribute = 'dp_dom_callee_out'
AND vdp.attribute_id = vp.id AND vd.id = vdp.domain_id;
IF NEW.direction = 'in' AND NEW.field = 'caller' THEN
SET dp_id = caller_in_id;
ELSEIF NEW.direction = 'in' AND NEW.field = 'callee' THEN
SET dp_id = callee_in_id;
ELSEIF NEW.direction = 'out' AND NEW.field = 'caller' THEN
SET dp_id = caller_out_id;
ELSEIF NEW.direction = 'out' AND NEW.field = 'callee' THEN
SET dp_id = callee_out_id;
END IF;
INSERT INTO kamailio.dialplan (dpid, pr, match_op, match_exp,
match_len, subst_exp, repl_exp, attrs)
VALUES(dp_id, NEW.priority, 1, NEW.match_pattern, 0, NEW.match_pattern, NEW.replace_pattern, '');
END;
|
CREATE TRIGGER voip_domrw_urepl_trig AFTER UPDATE ON voip_domain_rewrites
FOR EACH ROW BEGIN
DECLARE caller_in_id int(11) unsigned;
DECLARE callee_in_id int(11) unsigned;
DECLARE caller_out_id int(11) unsigned;
DECLARE callee_out_id int(11) unsigned;
DECLARE dp_id int(11) unsigned default 0;
SELECT vdp.value INTO caller_in_id FROM voip_dom_preferences vdp, voip_preferences vp,
voip_domains vd WHERE vd.id = NEW.domain_id AND vp.attribute = 'dp_dom_caller_in'
AND vdp.attribute_id = vp.id AND vd.id = vdp.domain_id;
SELECT vdp.value INTO callee_in_id FROM voip_dom_preferences vdp, voip_preferences vp,
voip_domains vd WHERE vd.id = NEW.domain_id AND vp.attribute = 'dp_dom_callee_in'
AND vdp.attribute_id = vp.id AND vd.id = vdp.domain_id;
SELECT vdp.value INTO caller_out_id FROM voip_dom_preferences vdp, voip_preferences vp,
voip_domains vd WHERE vd.id = NEW.domain_id AND vp.attribute = 'dp_dom_caller_out'
AND vdp.attribute_id = vp.id AND vd.id = vdp.domain_id;
SELECT vdp.value INTO callee_out_id FROM voip_dom_preferences vdp, voip_preferences vp,
voip_domains vd WHERE vd.id = NEW.domain_id AND vp.attribute = 'dp_dom_callee_out'
AND vdp.attribute_id = vp.id AND vd.id = vdp.domain_id;
IF NEW.direction = 'in' AND NEW.field = 'caller' THEN
SET dp_id = caller_in_id;
ELSEIF NEW.direction = 'in' AND NEW.field = 'callee' THEN
SET dp_id = callee_in_id;
ELSEIF NEW.direction = 'out' AND NEW.field = 'caller' THEN
SET dp_id = caller_out_id;
ELSEIF NEW.direction = 'out' AND NEW.field = 'callee' THEN
SET dp_id = callee_out_id;
END IF;
UPDATE kamailio.dialplan SET match_exp = NEW.match_pattern,
subst_exp = NEW.match_pattern, repl_exp = NEW.replace_pattern, pr = NEW.priority
WHERE dpid = dp_id AND match_exp = OLD.match_pattern AND pr = OLD.priority
AND subst_exp = OLD.match_pattern AND repl_exp = OLD.replace_pattern;
END;
|
CREATE TRIGGER voip_domrw_drepl_trig AFTER DELETE ON voip_domain_rewrites
FOR EACH ROW BEGIN
DECLARE caller_in_id int(11) unsigned;
DECLARE callee_in_id int(11) unsigned;
DECLARE caller_out_id int(11) unsigned;
DECLARE callee_out_id int(11) unsigned;
DECLARE dp_id int(11) unsigned default 0;
SELECT vdp.value INTO caller_in_id FROM voip_dom_preferences vdp, voip_preferences vp,
voip_domains vd WHERE vd.id = OLD.domain_id AND vp.attribute = 'dp_dom_caller_in'
AND vdp.attribute_id = vp.id AND vd.id = vdp.domain_id;
SELECT vdp.value INTO callee_in_id FROM voip_dom_preferences vdp, voip_preferences vp,
voip_domains vd WHERE vd.id = OLD.domain_id AND vp.attribute = 'dp_dom_callee_in'
AND vdp.attribute_id = vp.id AND vd.id = vdp.domain_id;
SELECT vdp.value INTO caller_out_id FROM voip_dom_preferences vdp, voip_preferences vp,
voip_domains vd WHERE vd.id = OLD.domain_id AND vp.attribute = 'dp_dom_caller_out'
AND vdp.attribute_id = vp.id AND vd.id = vdp.domain_id;
SELECT vdp.value INTO callee_out_id FROM voip_dom_preferences vdp, voip_preferences vp,
voip_domains vd WHERE vd.id = OLD.domain_id AND vp.attribute = 'dp_dom_callee_out'
AND vdp.attribute_id = vp.id AND vd.id = vdp.domain_id;
IF OLD.direction = 'in' AND OLD.field = 'caller' THEN
SET dp_id = caller_in_id;
ELSEIF OLD.direction = 'in' AND OLD.field = 'callee' THEN
SET dp_id = callee_in_id;
ELSEIF OLD.direction = 'out' AND OLD.field = 'caller' THEN
SET dp_id = caller_out_id;
ELSEIF OLD.direction = 'out' AND OLD.field = 'callee' THEN
SET dp_id = callee_out_id;
END IF;
DELETE FROM kamailio.dialplan
WHERE dpid = dp_id AND match_exp = OLD.match_pattern
AND subst_exp = OLD.match_pattern AND repl_exp = OLD.replace_pattern;
END;
|
CREATE TRIGGER voip_peerrw_crepl_trig AFTER INSERT ON voip_peer_rewrites
FOR EACH ROW BEGIN
DECLARE caller_in_id int(11) unsigned;
DECLARE callee_in_id int(11) unsigned;
DECLARE caller_out_id int(11) unsigned;
DECLARE callee_out_id int(11) unsigned;
DECLARE dp_id int(11) unsigned default 0;
SELECT dp_caller_in_id, dp_callee_in_id, dp_caller_out_id, dp_callee_out_id
INTO caller_in_id, callee_in_id, caller_out_id, callee_out_id
FROM voip_peer_hosts WHERE id = NEW.peer_id;
IF NEW.direction = 'in' AND NEW.field = 'caller' THEN
SET dp_id = caller_in_id;
ELSEIF NEW.direction = 'in' AND NEW.field = 'callee' THEN
SET dp_id = callee_in_id;
ELSEIF NEW.direction = 'out' AND NEW.field = 'caller' THEN
SET dp_id = caller_out_id;
ELSEIF NEW.direction = 'out' AND NEW.field = 'callee' THEN
SET dp_id = callee_out_id;
END IF;
INSERT INTO kamailio.dialplan (dpid, pr, match_op, match_exp,
match_len, subst_exp, repl_exp, attrs)
VALUES(dp_id, NEW.priority, 1, NEW.match_pattern, 0, NEW.match_pattern, NEW.replace_pattern, '');
END;
|
CREATE TRIGGER voip_peerrw_urepl_trig AFTER UPDATE ON voip_peer_rewrites
FOR EACH ROW BEGIN
DECLARE caller_in_id int(11) unsigned;
DECLARE callee_in_id int(11) unsigned;
DECLARE caller_out_id int(11) unsigned;
DECLARE callee_out_id int(11) unsigned;
DECLARE dp_id int(11) unsigned default 0;
SELECT dp_caller_in_id, dp_callee_in_id, dp_caller_out_id, dp_callee_out_id
INTO caller_in_id, callee_in_id, caller_out_id, callee_out_id
FROM voip_peer_hosts WHERE id = NEW.peer_id;
IF NEW.direction = 'in' AND NEW.field = 'caller' THEN
SET dp_id = caller_in_id;
ELSEIF NEW.direction = 'in' AND NEW.field = 'callee' THEN
SET dp_id = callee_in_id;
ELSEIF NEW.direction = 'out' AND NEW.field = 'caller' THEN
SET dp_id = caller_out_id;
ELSEIF NEW.direction = 'out' AND NEW.field = 'callee' THEN
SET dp_id = callee_out_id;
END IF;
UPDATE kamailio.dialplan SET match_exp = NEW.match_pattern,
subst_exp = NEW.match_pattern, repl_exp = NEW.replace_pattern,
pr = NEW.priority
WHERE dpid = dp_id AND match_exp = OLD.match_pattern AND pr = OLD.priority
AND subst_exp = OLD.match_pattern AND repl_exp = OLD.replace_pattern;
END;
|
CREATE TRIGGER voip_peerrw_drepl_trig AFTER DELETE ON voip_peer_rewrites
FOR EACH ROW BEGIN
DECLARE caller_in_id int(11) unsigned;
DECLARE callee_in_id int(11) unsigned;
DECLARE caller_out_id int(11) unsigned;
DECLARE callee_out_id int(11) unsigned;
DECLARE dp_id int(11) unsigned default 0;
SELECT dp_caller_in_id, dp_callee_in_id, dp_caller_out_id, dp_callee_out_id
INTO caller_in_id, callee_in_id, caller_out_id, callee_out_id
FROM voip_peer_hosts WHERE id = OLD.peer_id;
IF OLD.direction = 'in' AND OLD.field = 'caller' THEN
SET dp_id = caller_in_id;
ELSEIF OLD.direction = 'in' AND OLD.field = 'callee' THEN
SET dp_id = callee_in_id;
ELSEIF OLD.direction = 'out' AND OLD.field = 'caller' THEN
SET dp_id = caller_out_id;
ELSEIF OLD.direction = 'out' AND OLD.field = 'callee' THEN
SET dp_id = callee_out_id;
END IF;
DELETE FROM kamailio.dialplan
WHERE dpid = dp_id AND match_exp = OLD.match_pattern
AND subst_exp = OLD.match_pattern AND repl_exp = OLD.replace_pattern;
END;
|
DELIMITER ;
DELETE FROM voip_preferences WHERE attribute = 'rewrite_rule_set';
DROP TABLE `voip_rewrite_rules`;
DROP TABLE `voip_rewrite_rule_sets`;

@ -0,0 +1,123 @@
-- NOTE -- This will delete everything from kamailio.dialplan!
-- NOTE -- A backup is made to migration tables, run 5824.up immediately to restore it!
use provisioning;
CREATE TABLE `voip_rewrite_rule_sets` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`name` varchar(32) NOT NULL,
`description` varchar(255) DEFAULT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `name_idx` (`name`)
) ENGINE=InnoDB;
CREATE TABLE `voip_rewrite_rules` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`set_id` int(11) unsigned NOT NULL,
`match_pattern` varchar(64) NOT NULL DEFAULT '',
`replace_pattern` varchar(64) NOT NULL,
`description` varchar(127) NOT NULL DEFAULT '',
`direction` enum('in','out') NOT NULL DEFAULT 'in',
`field` enum('caller','callee') NOT NULL DEFAULT 'caller',
`priority` int(11) unsigned NOT NULL DEFAULT '50',
PRIMARY KEY (`id`),
KEY `setidx` (`set_id`),
KEY `dirfieldidx` (`direction`,`field`),
CONSTRAINT `v_rwr_setid_ref` FOREIGN KEY (`set_id`) REFERENCES `voip_rewrite_rule_sets` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB;
DROP TRIGGER voip_domrw_crepl_trig;
DROP TRIGGER voip_domrw_urepl_trig;
DROP TRIGGER voip_domrw_drepl_trig;
DROP TRIGGER voip_peerrw_crepl_trig;
DROP TRIGGER voip_peerrw_urepl_trig;
DROP TRIGGER voip_peerrw_drepl_trig;
DELETE FROM kamailio.dialplan;
DELIMITER |
CREATE TRIGGER voip_rwrules_crepl_trig AFTER INSERT ON voip_rewrite_rules
FOR EACH ROW BEGIN
INSERT INTO kamailio.dialplan (dpid,pr,match_op,match_exp,match_len,subst_exp,repl_exp,attrs)
VALUES(NEW.set_id,NEW.priority,1,NEW.match_pattern,0,NEW.match_pattern,NEW.replace_pattern,'');
END;
|
CREATE TRIGGER voip_rwrules_urepl_trig AFTER UPDATE ON voip_rewrite_rules
FOR EACH ROW BEGIN
UPDATE kamailio.dialplan
SET pr = NEW.priority,
match_exp = NEW.match_pattern,
subst_exp = NEW.match_pattern,
repl_exp = NEW.replace_pattern
WHERE dpid = OLD.set_id
AND pr = OLD.priority
AND match_exp = OLD.match_pattern
AND subst_exp = OLD.match_pattern
AND repl_exp = OLD.replace_pattern;
END;
|
CREATE TRIGGER voip_rwrules_drepl_trig BEFORE DELETE ON voip_rewrite_rules
FOR EACH ROW BEGIN
DELETE FROM kamailio.dialplan
WHERE dpid = OLD.set_id
AND pr = OLD.priority
AND match_exp = OLD.match_pattern
AND subst_exp = OLD.match_pattern
AND repl_exp = OLD.replace_pattern;
END;
|
CREATE TRIGGER voip_rwrulesets_drepl_trig BEFORE DELETE ON voip_rewrite_rule_sets
FOR EACH ROW BEGIN
-- work around MySQL bug. the cascaded delete should trigger our
-- voip_dom_preferences delete action, but doesn't
DELETE FROM kamailio.dialplan WHERE dpid = OLD.id;
END;
|
DELIMITER ;
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, description)
VALUES('rewrite_rule_set', 1, 1, 1, 1, 'int', 1, 'Specifies the list of caller and callee rewrite rules which should be applied for incoming and outgoing calls.');
-- create rw rules backup for upgrade
CREATE TABLE `voip_domain_rewrites_rwsmig` SELECT * FROM `voip_domain_rewrites`;
CREATE TABLE `voip_domain_rwsmig` SELECT b.domain_id,
b.value AS dp_caller_in_id,
d.value AS dp_callee_in_id,
f.value AS dp_caller_out_id,
h.value AS dp_callee_out_id
FROM `voip_preferences` a INNER JOIN `voip_dom_preferences` b
ON a.attribute = 'dp_dom_caller_in'
AND a.id = b.attribute_id
INNER JOIN `voip_preferences` c
ON c.attribute = 'dp_dom_callee_in'
INNER JOIN `voip_dom_preferences` d
ON c.id = d.attribute_id
AND b.domain_id = d.domain_id
INNER JOIN `voip_preferences` e
ON e.attribute = 'dp_dom_caller_out'
INNER JOIN `voip_dom_preferences` f
ON e.id = f.attribute_id
AND d.domain_id = f.domain_id
INNER JOIN `voip_preferences` g
ON g.attribute = 'dp_dom_callee_out'
INNER JOIN `voip_dom_preferences` h
ON g.id = h.attribute_id
AND f.domain_id = h.domain_id;
CREATE TABLE `voip_peer_rewrites_rwsmig` SELECT * FROM `voip_peer_rewrites`;
CREATE TABLE `voip_peer_hosts_rwsmig` SELECT * FROM `voip_peer_hosts`;
DROP TABLE `voip_domain_rewrites`;
DROP TABLE `voip_peer_rewrites`;

@ -0,0 +1,83 @@
-- NOTE! This does not update but will delete all rewrite data!
use provisioning;
DELETE FROM voip_rewrite_rules;
DELETE FROM voip_rewrite_rule_sets;
DELETE FROM voip_preferences WHERE attribute = 'rewrite_caller_in_dpid';
DELETE FROM voip_preferences WHERE attribute = 'rewrite_callee_in_dpid';
DELETE FROM voip_preferences WHERE attribute = 'rewrite_caller_out_dpid';
DELETE FROM voip_preferences WHERE attribute = 'rewrite_callee_out_dpid';
UPDATE voip_preferences SET internal = 0 WHERE attribute = 'rewrite_rule_set';
DELIMITER |
DROP TRIGGER voip_rwrulesets_crepl_trig|
DROP TRIGGER voip_rwrulesets_urepl_trig|
DROP TRIGGER voip_rwrulesets_drepl_trig|
CREATE TRIGGER voip_rwrulesets_drepl_trig BEFORE DELETE ON voip_rewrite_rule_sets
FOR EACH ROW BEGIN
-- work around MySQL bug. the cascaded delete should trigger our
-- voip_dom_preferences delete action, but doesn't
DELETE FROM kamailio.dialplan WHERE dpid = OLD.id;
END;
|
DROP TRIGGER voip_rwrules_crepl_trig|
CREATE TRIGGER voip_rwrules_crepl_trig AFTER INSERT ON voip_rewrite_rules
FOR EACH ROW BEGIN
INSERT INTO kamailio.dialplan (dpid,pr,match_op,match_exp,match_len,subst_exp,repl_exp,attrs)
VALUES(NEW.set_id,NEW.priority,1,NEW.match_pattern,0,NEW.match_pattern,NEW.replace_pattern,'');
END;
|
DROP TRIGGER voip_rwrules_urepl_trig|
CREATE TRIGGER voip_rwrules_urepl_trig AFTER UPDATE ON voip_rewrite_rules
FOR EACH ROW BEGIN
UPDATE kamailio.dialplan
SET pr = NEW.priority,
match_exp = NEW.match_pattern,
subst_exp = NEW.match_pattern,
repl_exp = NEW.replace_pattern
WHERE dpid = OLD.set_id
AND pr = OLD.priority
AND match_exp = OLD.match_pattern
AND subst_exp = OLD.match_pattern
AND repl_exp = OLD.replace_pattern;
END;
|
DROP TRIGGER voip_rwrules_drepl_trig|
CREATE TRIGGER voip_rwrules_drepl_trig BEFORE DELETE ON voip_rewrite_rules
FOR EACH ROW BEGIN
DELETE FROM kamailio.dialplan
WHERE dpid = OLD.set_id
AND pr = OLD.priority
AND match_exp = OLD.match_pattern
AND subst_exp = OLD.match_pattern
AND repl_exp = OLD.replace_pattern;
END;
|
DELIMITER ;
DROP TABLE `voip_rwrs_sequence`;
ALTER TABLE voip_rewrite_rule_sets DROP COLUMN `caller_in_dpid`;
ALTER TABLE voip_rewrite_rule_sets DROP COLUMN `callee_in_dpid`;
ALTER TABLE voip_rewrite_rule_sets DROP COLUMN `caller_out_dpid`;
ALTER TABLE voip_rewrite_rule_sets DROP COLUMN `callee_out_dpid`;

@ -0,0 +1,208 @@
-- NOTE -- This restores data in kamailio.dialplan which has been deleted by 5800.up!
-- NOTE -- Run 5800.up first to create the data backup.
use provisioning;
DELETE FROM voip_rewrite_rules;
DELETE FROM voip_rewrite_rule_sets;
ALTER TABLE voip_rewrite_rule_sets ADD COLUMN `caller_in_dpid` int(11) unsigned DEFAULT NULL AFTER `description`;
ALTER TABLE voip_rewrite_rule_sets ADD COLUMN `callee_in_dpid` int(11) unsigned DEFAULT NULL AFTER `caller_in_dpid`;
ALTER TABLE voip_rewrite_rule_sets ADD COLUMN `caller_out_dpid` int(11) unsigned DEFAULT NULL AFTER `callee_in_dpid`;
ALTER TABLE voip_rewrite_rule_sets ADD COLUMN `callee_out_dpid` int(11) unsigned DEFAULT NULL AFTER `caller_out_dpid`;
CREATE TABLE `voip_rwrs_sequence` (
`id` int(11) unsigned NOT NULL AUTO_INCREMENT,
PRIMARY KEY (`id`)
) ENGINE=InnoDB;
DELIMITER |
DROP TRIGGER voip_rwrules_crepl_trig|
CREATE TRIGGER voip_rwrules_crepl_trig AFTER INSERT ON voip_rewrite_rules
FOR EACH ROW BEGIN
DECLARE new_set_id int(11) unsigned;
SELECT IF(NEW.direction = 'in', IF(NEW.field = 'caller', caller_in_dpid, callee_in_dpid), IF(NEW.field = 'caller', caller_out_dpid, callee_out_dpid))
INTO new_set_id FROM voip_rewrite_rule_sets WHERE id = NEW.set_id;
INSERT INTO kamailio.dialplan (dpid,pr,match_op,match_exp,match_len,subst_exp,repl_exp,attrs)
VALUES(new_set_id,NEW.priority,1,NEW.match_pattern,0,NEW.match_pattern,NEW.replace_pattern,'');
END;
|
DROP TRIGGER voip_rwrules_urepl_trig|
CREATE TRIGGER voip_rwrules_urepl_trig AFTER UPDATE ON voip_rewrite_rules
FOR EACH ROW BEGIN
DECLARE old_set_id int(11) unsigned;
DECLARE new_set_id int(11) unsigned;
SELECT IF(OLD.direction = 'in', IF(OLD.field = 'caller', caller_in_dpid, callee_in_dpid), IF(OLD.field = 'caller', caller_out_dpid, callee_out_dpid))
INTO old_set_id FROM voip_rewrite_rule_sets WHERE id = OLD.set_id;
SELECT IF(NEW.direction = 'in', IF(NEW.field = 'caller', caller_in_dpid, callee_in_dpid), IF(NEW.field = 'caller', caller_out_dpid, callee_out_dpid))
INTO new_set_id FROM voip_rewrite_rule_sets WHERE id = NEW.set_id;
UPDATE kamailio.dialplan
SET dpid = new_set_id,
pr = NEW.priority,
match_exp = NEW.match_pattern,
subst_exp = NEW.match_pattern,
repl_exp = NEW.replace_pattern
WHERE dpid = old_set_id
AND pr = OLD.priority
AND match_exp = OLD.match_pattern
AND subst_exp = OLD.match_pattern
AND repl_exp = OLD.replace_pattern;
END;
|
DROP TRIGGER voip_rwrules_drepl_trig|
CREATE TRIGGER voip_rwrules_drepl_trig BEFORE DELETE ON voip_rewrite_rules
FOR EACH ROW BEGIN
DECLARE old_set_id int(11) unsigned;
SELECT IF(OLD.direction = 'in', IF(OLD.field = 'caller', caller_in_dpid, callee_in_dpid), IF(OLD.field = 'caller', caller_out_dpid, callee_out_dpid))
INTO old_set_id FROM voip_rewrite_rule_sets WHERE id = OLD.set_id;
DELETE FROM kamailio.dialplan
WHERE dpid = old_set_id
AND pr = OLD.priority
AND match_exp = OLD.match_pattern
AND subst_exp = OLD.match_pattern
AND repl_exp = OLD.replace_pattern;
END;
|
DROP TRIGGER voip_rwrulesets_drepl_trig|
CREATE TRIGGER voip_rwrulesets_drepl_trig BEFORE DELETE ON voip_rewrite_rule_sets
FOR EACH ROW BEGIN
-- work around MySQL bug. the cascaded delete should trigger our
-- voip_dom_preferences delete action, but doesn't
DELETE FROM kamailio.dialplan WHERE dpid = OLD.caller_in_dpid;
DELETE FROM kamailio.dialplan WHERE dpid = OLD.callee_in_dpid;
DELETE FROM kamailio.dialplan WHERE dpid = OLD.caller_out_dpid;
DELETE FROM kamailio.dialplan WHERE dpid = OLD.callee_out_dpid;
END;
|
CREATE TRIGGER voip_rwrulesets_crepl_trig BEFORE INSERT ON voip_rewrite_rule_sets
FOR EACH ROW BEGIN
IF NEW.caller_in_dpid IS NULL THEN
INSERT INTO voip_rwrs_sequence VALUES();
SET NEW.caller_in_dpid = (SELECT LAST_INSERT_ID());
END IF;
IF NEW.callee_in_dpid IS NULL THEN
INSERT INTO voip_rwrs_sequence VALUES();
SET NEW.callee_in_dpid = (SELECT LAST_INSERT_ID());
END IF;
IF NEW.caller_out_dpid IS NULL THEN
INSERT INTO voip_rwrs_sequence VALUES();
SET NEW.caller_out_dpid = (SELECT LAST_INSERT_ID());
END IF;
IF NEW.callee_out_dpid IS NULL THEN
INSERT INTO voip_rwrs_sequence VALUES();
SET NEW.callee_out_dpid = (SELECT LAST_INSERT_ID());
END IF;
DELETE a FROM voip_rwrs_sequence a, voip_rwrs_sequence b WHERE a.id < b.id;
END;
|
CREATE TRIGGER voip_rwrulesets_urepl_trig AFTER UPDATE ON voip_rewrite_rule_sets
FOR EACH ROW BEGIN
UPDATE kamailio.dialplan SET dpid = NEW.caller_in_dpid WHERE dpid = OLD.caller_in_dpid;
UPDATE kamailio.dialplan SET dpid = NEW.callee_in_dpid WHERE dpid = OLD.callee_in_dpid;
UPDATE kamailio.dialplan SET dpid = NEW.caller_out_dpid WHERE dpid = OLD.caller_out_dpid;
UPDATE kamailio.dialplan SET dpid = NEW.callee_out_dpid WHERE dpid = OLD.callee_out_dpid;
END;
|
DELIMITER ;
DELETE FROM voip_preferences WHERE attribute = 'rewrite_rule_set';
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, internal, description)
VALUES('rewrite_rule_set', 1, 1, 1, 1, 'int', 1, -1, 'Specifies the list of caller and callee rewrite rules which should be applied for incoming and outgoing calls.');
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, internal)
VALUES('rewrite_caller_in_dpid', 1, 1, 1, 1, 'int', 1, 1);
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, internal)
VALUES('rewrite_callee_in_dpid', 1, 1, 1, 1, 'int', 1, 1);
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, internal)
VALUES('rewrite_caller_out_dpid', 1, 1, 1, 1, 'int', 1, 1);
INSERT INTO voip_preferences (attribute, type, usr_pref, dom_pref, peer_pref, data_type, max_occur, internal)
VALUES('rewrite_callee_out_dpid', 1, 1, 1, 1, 'int', 1, 1);
-- restore data from migration tables
INSERT INTO voip_rewrite_rule_sets (name,description,caller_in_dpid,callee_in_dpid,caller_out_dpid,callee_out_dpid)
SELECT CONCAT('peer___',ip), CONCAT('auto-generated ruleset for ',name),
dp_caller_in_id, dp_callee_in_id, dp_caller_out_id, dp_callee_out_id
FROM voip_peer_hosts_rwsmig;
INSERT INTO voip_rewrite_rules (set_id, match_pattern, replace_pattern, description, direction, field, priority)
SELECT a.id, b.match_pattern, b.replace_pattern, b.description, b.direction, b.field, b.priority
FROM voip_rewrite_rule_sets a, voip_peer_rewrites_rwsmig b, voip_peer_hosts_rwsmig c
WHERE a.name = CONCAT('peer___',c.ip)
AND b.peer_id = c.id;
INSERT INTO voip_peer_preferences (peer_host_id,attribute_id,value)
SELECT a.id, b.id, a.dp_caller_in_id
FROM voip_peer_hosts_rwsmig a, voip_preferences b
WHERE b.attribute = 'rewrite_caller_in_dpid';
INSERT INTO voip_peer_preferences (peer_host_id,attribute_id,value)
SELECT a.id, b.id, a.dp_callee_in_id
FROM voip_peer_hosts_rwsmig a, voip_preferences b
WHERE b.attribute = 'rewrite_callee_in_dpid';
INSERT INTO voip_peer_preferences (peer_host_id,attribute_id,value)
SELECT a.id, b.id, a.dp_caller_out_id
FROM voip_peer_hosts_rwsmig a, voip_preferences b
WHERE b.attribute = 'rewrite_caller_out_dpid';
INSERT INTO voip_peer_preferences (peer_host_id,attribute_id,value)
SELECT a.id, b.id, a.dp_callee_out_id
FROM voip_peer_hosts_rwsmig a, voip_preferences b
WHERE b.attribute = 'rewrite_callee_out_dpid';
INSERT INTO voip_rewrite_rule_sets (name,description,caller_in_dpid,callee_in_dpid,caller_out_dpid,callee_out_dpid)
SELECT CONCAT('dom___',b.domain), CONCAT('auto-generated ruleset for ',b.domain),
dp_caller_in_id, dp_callee_in_id, dp_caller_out_id, dp_callee_out_id
FROM voip_domain_rwsmig a, voip_domains b
WHERE a.domain_id = b.id;
INSERT INTO voip_rewrite_rules (set_id, match_pattern, replace_pattern, description, direction, field, priority)
SELECT a.id, b.match_pattern, b.replace_pattern, b.description, b.direction, b.field, b.priority
FROM voip_rewrite_rule_sets a, voip_domain_rewrites_rwsmig b, voip_domains c
WHERE a.name = CONCAT('dom___',c.domain)
AND b.domain_id = c.id;
INSERT INTO voip_dom_preferences (domain_id,attribute_id,value)
SELECT a.domain_id, b.id, a.dp_caller_in_id
FROM voip_domain_rwsmig a, voip_preferences b
WHERE b.attribute = 'rewrite_caller_in_dpid';
INSERT INTO voip_dom_preferences (domain_id,attribute_id,value)
SELECT a.domain_id, b.id, a.dp_callee_in_id
FROM voip_domain_rwsmig a, voip_preferences b
WHERE b.attribute = 'rewrite_callee_in_dpid';
INSERT INTO voip_dom_preferences (domain_id,attribute_id,value)
SELECT a.domain_id, b.id, a.dp_caller_out_id
FROM voip_domain_rwsmig a, voip_preferences b
WHERE b.attribute = 'rewrite_caller_out_dpid';
INSERT INTO voip_dom_preferences (domain_id,attribute_id,value)
SELECT a.domain_id, b.id, a.dp_callee_out_id
FROM voip_domain_rwsmig a, voip_preferences b
WHERE b.attribute = 'rewrite_callee_out_dpid';
DROP TABLE voip_peer_hosts_rwsmig;
DROP TABLE voip_peer_rewrites_rwsmig;
DROP TABLE voip_domain_rwsmig;
DROP TABLE voip_domain_rewrites_rwsmig;

@ -0,0 +1,39 @@
use provisioning;
DROP TRIGGER voip_dom_drepl_trig;
DELIMITER |
CREATE TRIGGER voip_dom_drepl_trig BEFORE DELETE ON voip_domains
FOR EACH ROW BEGIN
DECLARE caller_in_id int(11) unsigned;
DECLARE callee_in_id int(11) unsigned;
DECLARE caller_out_id int(11) unsigned;
DECLARE callee_out_id int(11) unsigned;
SELECT vdp.value INTO caller_in_id FROM voip_dom_preferences vdp, voip_preferences vp
WHERE vp.attribute = 'dp_dom_caller_in' AND vdp.attribute_id = vp.id AND vdp.domain_id = OLD.id;
SELECT vdp.value INTO callee_in_id FROM voip_dom_preferences vdp, voip_preferences vp
WHERE vp.attribute = 'dp_dom_callee_in' AND vdp.attribute_id = vp.id AND vdp.domain_id = OLD.id;
SELECT vdp.value INTO caller_out_id FROM voip_dom_preferences vdp, voip_preferences vp
WHERE vp.attribute = 'dp_dom_caller_out' AND vdp.attribute_id = vp.id AND vdp.domain_id = OLD.id;
SELECT vdp.value INTO callee_out_id FROM voip_dom_preferences vdp, voip_preferences vp
WHERE vp.attribute = 'dp_dom_callee_out' AND vdp.attribute_id = vp.id AND vdp.domain_id = OLD.id;
DELETE FROM kamailio.domain WHERE domain = OLD.domain;
DELETE FROM kamailio.dialplan WHERE dpid IN
(caller_in_id, callee_in_id, caller_out_id, callee_out_id);
-- work around MySQL bug. the cascaded delete should trigger our
-- voip_dom_preferences delete action, but doesn't
DELETE FROM kamailio.dom_preferences WHERE domain = OLD.domain;
-- this will trigger the delete action for each subscriber
DELETE FROM provisioning.voip_subscribers WHERE domain_id = OLD.id;
END;
|
DELIMITER ;

Some files were not shown because too many files have changed in this diff Show More

Loading…
Cancel
Save