mirror of https://github.com/sipwise/db-schema.git
You can not select more than 25 topics
Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
637 lines
26 KiB
637 lines
26 KiB
-- 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,
|
|
`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,
|
|
`reseller_id` int(11) UNSIGNED NOT NULL,
|
|
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,
|
|
`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,
|
|
`handle` varchar(63) NOT NULL,
|
|
`name` varchar(31) NOT NULL,
|
|
`prepaid` bool NOT NULL DEFAULT TRUE,
|
|
`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,
|
|
`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,
|
|
`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_fees` (
|
|
`id` int(11) UNSIGNED NOT NULL auto_increment,
|
|
`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 `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_peaktime_weekdays` (
|
|
`id` int(11) UNSIGNED NOT NULL auto_increment,
|
|
`billing_profile_id` int(11) UNSIGNED NOT NULL,
|
|
`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,
|
|
`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,
|
|
`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,
|
|
`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,
|
|
`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,
|
|
`lnp_provider_id` int(11) UNSIGNED NOT NULL,
|
|
`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,
|
|
`shopuser` varchar(31) NULL,
|
|
`shoppass` varchar(31) NULL,
|
|
`business` bool NOT NULL DEFAULT FALSE,
|
|
`contact_id` int(11) UNSIGNED NULL,
|
|
`tech_contact_id` int(11) UNSIGNED NULL,
|
|
`comm_contact_id` int(11) UNSIGNED 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
|
|
) ENGINE=InnoDB;
|
|
|
|
CREATE TABLE `customer_registers` (
|
|
`id` int(11) UNSIGNED NOT NULL auto_increment,
|
|
`customer_id` int(11) UNSIGNED NOT NULL,
|
|
`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,
|
|
`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,
|
|
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,
|
|
`customer_id` int(11) UNSIGNED,
|
|
`delivery_contact_id` int(11) UNSIGNED,
|
|
`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,
|
|
`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,
|
|
`payment_id` int(11) UNSIGNED NOT NULL,
|
|
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,
|
|
`reseller_id` int(11) UNSIGNED NULL,
|
|
`contact_id` int(11) UNSIGNED NULL,
|
|
`order_id` int(11) UNSIGNED NULL,
|
|
`status` enum('pending','active','locked','terminated') NOT NULL DEFAULT 'active',
|
|
`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
|
|
) 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,
|
|
`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,
|
|
`uuid` char(36) NOT NULL,
|
|
`username` varchar(127) NOT NULL,
|
|
`domain_id` int(11) UNSIGNED NOT NULL,
|
|
`status` enum('active','locked','terminated') NOT NULL DEFAULT 'active',
|
|
`primary_number_id` int(11) unsigned 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`)
|
|
) 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` int(5) UNSIGNED NOT NULL,
|
|
`sn` varchar(31) NOT NULL,
|
|
`reseller_id` int(11) UNSIGNED NULL,
|
|
`subscriber_id` int(11) UNSIGNED NULL,
|
|
`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`),
|
|
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` int(5) UNSIGNED 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,
|
|
`reseller_id` int(11) UNSIGNED NOT NULL,
|
|
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 CASCADE 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,
|
|
`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,
|
|
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,
|
|
`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,
|
|
`payment_id` int(11) UNSIGNED NOT NULL,
|
|
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,
|
|
`contract_id` int(11) UNSIGNED NOT NULL,
|
|
`product_id` int(11) UNSIGNED,
|
|
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,
|
|
`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`
|
|
VALUES (1,NULL,'pstnpeering','PSTN_PEERING','PSTN Peering',1,NULL,NULL,NULL),
|
|
(2,NULL,'sippeering','SIP_PEERING','SIP Peering',1,NULL,NULL,NULL),
|
|
(3,NULL,'reseller','VOIP_RESELLER','VoIP Reseller',1,NULL,NULL,NULL);
|
|
-- the default reseller contract, will be the only one unless multitenancy is enabled
|
|
INSERT INTO `contracts` VALUES (1,NULL,NULL,NULL,NULL,'active','0','0','0',NULL);
|
|
INSERT INTO `resellers` VALUES (1,1,'default','active');
|
|
INSERT INTO `billing_mappings` VALUES (1,NULL,NULL,NULL,1,3);
|
|
-- first administrative account, change password after first login
|
|
INSERT INTO `admins` VALUES (1,1,'administrator',md5('administrator'),1,1,1,0,1,1,1);
|
|
-- default billing profile creation
|
|
INSERT INTO `billing_profiles` VALUES(1,1,'default','Default Billing Profile',1,0,0,0,'month',1,NULL,0,0);
|
|
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);
|