From bd3911b9ac101e997ac2177469f398033d9290e2 Mon Sep 17 00:00:00 2001 From: Rene Krenn Date: Mon, 6 Jun 2016 17:01:40 +0200 Subject: [PATCH] MT#20023 MT#20027 lnp numbers unique contraint and restrict delete cascade +replace old lnp_provider_id index by multi-column unique index (safe one index) +not replicated, as lnp_numbers table could get large Change-Id: I776358e42345f9a58bd3c755f7e40b12c1ac0a25 --- db_scripts/diff/15251_not_replicated.down | 11 +++++++++++ db_scripts/diff/15251_not_replicated.up | 15 +++++++++++++++ 2 files changed, 26 insertions(+) create mode 100644 db_scripts/diff/15251_not_replicated.down create mode 100644 db_scripts/diff/15251_not_replicated.up diff --git a/db_scripts/diff/15251_not_replicated.down b/db_scripts/diff/15251_not_replicated.down new file mode 100644 index 00000000..1f63a256 --- /dev/null +++ b/db_scripts/diff/15251_not_replicated.down @@ -0,0 +1,11 @@ +SET sql_log_bin=0; +USE billing; + +ALTER TABLE lnp_numbers DROP FOREIGN KEY l_n_lnpproid_ref; +DROP INDEX l_n_lnpproidnumber_idx ON lnp_numbers; +CREATE INDEX l_n_lnpproid_ref ON lnp_numbers (lnp_provider_id); +ALTER TABLE lnp_numbers ADD CONSTRAINT l_n_lnpproid_ref FOREIGN KEY (lnp_provider_id) REFERENCES lnp_providers (id) ON DELETE CASCADE ON UPDATE CASCADE; + +UPDATE lnp_numbers +SET number=SUBSTRING_INDEX(SUBSTRING_INDEX(number,'--',2),'--',-1) +WHERE number LIKE 'dupe--%--%'; diff --git a/db_scripts/diff/15251_not_replicated.up b/db_scripts/diff/15251_not_replicated.up new file mode 100644 index 00000000..24fb80f1 --- /dev/null +++ b/db_scripts/diff/15251_not_replicated.up @@ -0,0 +1,15 @@ +SET sql_log_bin=0; +USE billing; + +UPDATE + lnp_numbers a + CROSS JOIN lnp_numbers b +SET a.number = CONCAT('dupe--',a.number,'--',a.id) +WHERE + a.id < b.id + and (a.number = b.number and a.lnp_provider_id = b.lnp_provider_id); + +ALTER TABLE lnp_numbers DROP FOREIGN KEY l_n_lnpproid_ref; +DROP INDEX l_n_lnpproid_ref ON lnp_numbers; +CREATE UNIQUE INDEX l_n_lnpproidnumber_idx ON lnp_numbers (lnp_provider_id,number); +ALTER TABLE lnp_numbers ADD CONSTRAINT l_n_lnpproid_ref FOREIGN KEY (lnp_provider_id) REFERENCES lnp_providers (id) ON DELETE RESTRICT ON UPDATE CASCADE;