USE billing; CREATE TABLE reseller_phonebook ( id INT(11) UNSIGNED NOT NULL AUTO_INCREMENT, reseller_id INT(11) UNSIGNED NOT NULL, name VARCHAR(255) NOT NULL, number VARCHAR(255) NOT NULL, PRIMARY KEY (id), UNIQUE KEY rel_u_idx (reseller_id, number), KEY name_idx(name), KEY number_idx(number), CONSTRAINT pb_reseller_id_ref FOREIGN KEY (reseller_id) REFERENCES resellers (id) ON DELETE CASCADE ON UPDATE CASCADE ); CREATE TABLE contract_phonebook ( id INT(11) UNSIGNED NOT NULL AUTO_INCREMENT, contract_id INT(11) UNSIGNED NOT NULL, name VARCHAR(255) NOT NULL, number VARCHAR(255) NOT NULL, PRIMARY KEY (id), UNIQUE KEY rel_u_idx (contract_id, number), KEY name_idx(name), KEY number_idx(number), CONSTRAINT pb_contract_id_ref FOREIGN KEY (contract_id) REFERENCES contracts (id) ON DELETE CASCADE ON UPDATE CASCADE ); CREATE TABLE subscriber_phonebook ( id INT(11) UNSIGNED NOT NULL AUTO_INCREMENT, subscriber_id INT(11) UNSIGNED NOT NULL, name VARCHAR(255) NOT NULL, number VARCHAR(255) NOT NULL, shared TINYINT(1) NOT NULL DEFAULT '0', PRIMARY KEY (id), UNIQUE KEY rel_u_idx (subscriber_id, number), KEY name_idx(name), KEY number_idx(number), CONSTRAINT pb_subscriber_id_ref FOREIGN KEY (subscriber_id) REFERENCES voip_subscribers (id) ON DELETE CASCADE ON UPDATE CASCADE ); DELIMITER // CREATE TRIGGER phonebook_on_reseller_update AFTER UPDATE ON resellers FOR EACH ROW BEGIN IF new.status = 'terminated' THEN DELETE FROM reseller_phonebook WHERE reseller_id = old.id; END IF; END; // DELIMITER ; DELIMITER // CREATE TRIGGER phonebook_on_contract_update AFTER UPDATE ON contracts FOR EACH ROW BEGIN IF new.status = 'terminated' THEN DELETE FROM contract_phonebook WHERE contract_id = old.id; END IF; END; // DELIMITER ; DELIMITER // CREATE TRIGGER phonebook_on_subscriber_update AFTER UPDATE ON voip_subscribers FOR EACH ROW BEGIN IF new.status = 'terminated' THEN DELETE FROM subscriber_phonebook WHERE subscriber_id = old.id; END IF; END; // DELIMITER ;