USE provisioning;

alter table `voip_preferences` add column `dynamic` tinyint(1) unsigned NOT NULL DEFAULT '0';
alter table `voip_preferences` add column `fielddev_pref` tinyint(1) unsigned NOT NULL DEFAULT '0' AFTER `devprof_pref`;
alter table `voip_preferences_enum` add column `fielddev_pref` tinyint(1) unsigned NOT NULL DEFAULT '0' AFTER `devprof_pref`;

update `voip_preferences` set fielddev_pref = 1 where devprof_pref = 1;
update `voip_preferences` set dynamic = 1 where attribute like '\_\_%';
update `voip_preferences` set fielddev_pref = 1 where dynamic = 1;

CREATE TABLE `voip_preference_relations` (
  `id` int(11) unsigned NOT NULL AUTO_INCREMENT,
  `voip_preference_id` int(11) unsigned NOT NULL,
  `autoprov_device_id` int(11) unsigned,
  `reseller_id` int(11) unsigned,
  PRIMARY KEY (`id`),
  -- not unique, because autoprov_device_id can be null
  KEY `voip_pref_rel_devices` (`voip_preference_id`,`autoprov_device_id`),
  KEY `voip_pref_rel_reselle` (`voip_preference_id`,`reseller_id`),
  KEY `vpid_ref` (`voip_preference_id`),
  CONSTRAINT `vpid_ref` FOREIGN KEY (`voip_preference_id`) REFERENCES `voip_preferences` (`id`) ON UPDATE CASCADE ON DELETE CASCADE,
  KEY `adid_ref` (`autoprov_device_id`),
  CONSTRAINT `adid_ref` FOREIGN KEY (`autoprov_device_id`) REFERENCES `autoprov_devices` (`id`) ON UPDATE CASCADE ON DELETE CASCADE,
  KEY `rid_ref` (`reseller_id`),
  CONSTRAINT `rid_ref` FOREIGN KEY (`reseller_id`) REFERENCES `billing`.`resellers` (`id`) ON UPDATE CASCADE ON DELETE CASCADE
);

CREATE TABLE `voip_fielddev_preferences` (
  `id` int(11) unsigned NOT NULL AUTO_INCREMENT,
  `device_id` int(11) unsigned NOT NULL,
  `attribute_id` int(11) unsigned NOT NULL,
  `value` varchar(128) NOT NULL,
  `modify_timestamp` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
  PRIMARY KEY (`id`),
  KEY `fielddevidattrid_idx` (`device_id`,`attribute_id`),
  KEY `fielddeviceid_idx` (`device_id`),
  KEY `attributeid_idx` (`attribute_id`),
  CONSTRAINT `v_fdev_p_attributeid_ref` FOREIGN KEY (`attribute_id`) REFERENCES `voip_preferences` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
  CONSTRAINT `v_fd_p_deviceid_ref` FOREIGN KEY (`device_id`) REFERENCES `autoprov_devices` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
);

DROP TRIGGER IF EXISTS provisioning.voip_pref_icheck_trig;
DELIMITER ;;
/*!50003 CREATE*/ /*!50017 DEFINER=`sipwise`@`localhost`*/ /*!50003 TRIGGER voip_pref_icheck_trig BEFORE INSERT ON voip_preferences
FOR EACH ROW BEGIN
    IF ( ((NEW.attribute like '\_\_%') and !NEW.dynamic)
        or ((NEW.attribute not like '\_\_%') and NEW.dynamic)
    ) THEN
        SIGNAL sqlstate '45001' set message_text = "voip_preferences attributes are allowed either '__' prefixed + dynamic=1 or without the '__' prefix and dynamic=0";
    END IF;
END */;;
DELIMITER ;

DROP TRIGGER IF EXISTS provisioning.voip_pref_ucheck_trig;
DELIMITER ;;
/*!50003 CREATE*/ /*!50017 DEFINER=`sipwise`@`localhost`*/ /*!50003 TRIGGER voip_pref_ucheck_trig BEFORE UPDATE ON voip_preferences
FOR EACH ROW BEGIN
    IF ( ((NEW.attribute like '\_\_%') and !NEW.dynamic)
        or ((NEW.attribute not like '\_\_%') and NEW.dynamic)
    ) THEN
        SIGNAL sqlstate '45001' set message_text = "voip_preferences attributes are allowed either '__' prefixed + dynamic=1 or without the '__' prefix and dynamic=0";
    END IF;
END */;;
DELIMITER ;