From ab1dabecfbdbd14525b8883493c4f39ff18a1736 Mon Sep 17 00:00:00 2001 From: Christian Veigl Date: Fri, 17 Aug 2012 07:48:43 +0000 Subject: [PATCH] make provisioning.voip_subscribers.webusername unique (see mantis:1913) also suffix already existing duplicates with CONCAT("-", voip_subscriber.id). --- db_scripts/diff/10331.down | 11 +++++++++++ db_scripts/diff/10331.up | 23 +++++++++++++++++++++++ 2 files changed, 34 insertions(+) create mode 100644 db_scripts/diff/10331.down create mode 100644 db_scripts/diff/10331.up diff --git a/db_scripts/diff/10331.down b/db_scripts/diff/10331.down new file mode 100644 index 00000000..1203ae3e --- /dev/null +++ b/db_scripts/diff/10331.down @@ -0,0 +1,11 @@ +USE provisioning; + +DELETE FROM language_strings WHERE code='Client.Voip.ExistingWebUser'; + +-- delete unique constraint +ALTER TABLE voip_subscribers DROP INDEX webuser_dom_idx; + +-- remove suffix set when adding above unique constraint +UPDATE voip_subscribers +SET webusername=REPLACE(webusername, CONCAT('-', id), '') +WHERE webusername LIKE CONCAT('%', '-', id) diff --git a/db_scripts/diff/10331.up b/db_scripts/diff/10331.up new file mode 100644 index 00000000..df3a88f5 --- /dev/null +++ b/db_scripts/diff/10331.up @@ -0,0 +1,23 @@ +USE provisioning; + +INSERT INTO language_strings (code, language, string) VALUES ('Client.Voip.ExistingWebUser', 'en', 'This webuser is already in use.'); +INSERT INTO language_strings (code, language, string) VALUES ('Client.Voip.ExistingWebUser', 'de', 'Dieser Webuser ist nicht mehr verfügbar.'); +INSERT INTO language_strings (code, language, string) VALUES ('Client.Voip.ExistingWebUser', 'es', 'This webuser is already in use.'); +INSERT INTO language_strings (code, language, string) VALUES ('Client.Voip.ExistingWebUser', 'fr', 'This webuser is already in use.'); + +-- need to check if there are duplicates in voip_subscribers.webusername and +-- suffix them with with "-"voip_subscribers.id before createing unique constraint (see below) +CREATE OR REPLACE VIEW webusername_dupes_view +AS select webusername, count(*) c from voip_subscribers group by webusername having c > 1; + +UPDATE voip_subscribers +SET voip_subscribers.webusername = CONCAT(voip_subscribers.webusername, '-', voip_subscribers.id) +WHERE +voip_subscribers.webusername IN ( + SELECT webusername FROM webusername_dupes_view +); + +DROP VIEW webusername_dupes_view; + +-- its safe now to make voip_subscribers.webusername unique +ALTER TABLE voip_subscribers ADD CONSTRAINT UNIQUE KEY `webuser_dom_idx` (`webusername`,`domain_id`);