68 lines
2.8 KiB
SQL
68 lines
2.8 KiB
SQL
-- Fix for suppliers split and foreign keys
|
|
|
|
-- 1. Move remaining suppliers from customers to suppliers table if type column exists
|
|
SET @dbname = DATABASE();
|
|
SET @tablename = 'customers';
|
|
SET @columnname = 'type';
|
|
SET @preparedStatement = (SELECT IF(
|
|
(SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS
|
|
WHERE TABLE_SCHEMA = @dbname AND TABLE_NAME = @tablename AND COLUMN_NAME = @columnname) > 0,
|
|
'INSERT IGNORE INTO suppliers (id, name, email, phone, tax_id, balance, credit_limit, created_at, total_spent) SELECT id, name, email, phone, tax_id, balance, credit_limit, created_at, total_spent FROM customers WHERE type = "supplier"',
|
|
'SELECT 1'
|
|
));
|
|
PREPARE stmt FROM @preparedStatement;
|
|
EXECUTE stmt;
|
|
DEALLOCATE PREPARE stmt;
|
|
|
|
-- 2. Delete them from customers if type column exists
|
|
SET @preparedStatement = (SELECT IF(
|
|
(SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS
|
|
WHERE TABLE_SCHEMA = @dbname AND TABLE_NAME = @tablename AND COLUMN_NAME = @columnname) > 0,
|
|
'DELETE FROM customers WHERE type = "supplier"',
|
|
'SELECT 1'
|
|
));
|
|
PREPARE stmt FROM @preparedStatement;
|
|
EXECUTE stmt;
|
|
DEALLOCATE PREPARE stmt;
|
|
|
|
-- 3. Drop type column if it exists
|
|
SET @preparedStatement = (SELECT IF(
|
|
(SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS
|
|
WHERE TABLE_SCHEMA = @dbname AND TABLE_NAME = @tablename AND COLUMN_NAME = @columnname) > 0,
|
|
'ALTER TABLE customers DROP COLUMN type',
|
|
'SELECT 1'
|
|
));
|
|
PREPARE stmt FROM @preparedStatement;
|
|
EXECUTE stmt;
|
|
DEALLOCATE PREPARE stmt;
|
|
|
|
-- 4. Fix foreign keys for supplier_id in stock_items
|
|
SET @tablename = 'stock_items';
|
|
SET @constraintname = 'fk_stock_items_supplier';
|
|
SET @preparedStatement = (SELECT IF(
|
|
(SELECT COUNT(*) FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS
|
|
WHERE CONSTRAINT_SCHEMA = @dbname AND TABLE_NAME = @tablename AND CONSTRAINT_NAME = @constraintname AND CONSTRAINT_TYPE = 'FOREIGN KEY') > 0,
|
|
'ALTER TABLE stock_items DROP FOREIGN KEY fk_stock_items_supplier',
|
|
'SELECT 1'
|
|
));
|
|
PREPARE stmt FROM @preparedStatement;
|
|
EXECUTE stmt;
|
|
DEALLOCATE PREPARE stmt;
|
|
|
|
ALTER TABLE stock_items ADD CONSTRAINT fk_stock_items_supplier FOREIGN KEY (supplier_id) REFERENCES suppliers(id) ON DELETE SET NULL;
|
|
|
|
-- 5. Fix foreign keys for supplier_id in purchase_returns
|
|
SET @tablename = 'purchase_returns';
|
|
SET @constraintname = 'purchase_returns_ibfk_2';
|
|
SET @preparedStatement = (SELECT IF(
|
|
(SELECT COUNT(*) FROM INFORMATION_SCHEMA.TABLE_CONSTRAINTS
|
|
WHERE CONSTRAINT_SCHEMA = @dbname AND TABLE_NAME = @tablename AND CONSTRAINT_NAME = @constraintname AND CONSTRAINT_TYPE = 'FOREIGN KEY') > 0,
|
|
'ALTER TABLE purchase_returns DROP FOREIGN KEY purchase_returns_ibfk_2',
|
|
'SELECT 1'
|
|
));
|
|
PREPARE stmt FROM @preparedStatement;
|
|
EXECUTE stmt;
|
|
DEALLOCATE PREPARE stmt;
|
|
|
|
ALTER TABLE purchase_returns ADD CONSTRAINT purchase_returns_ibfk_2 FOREIGN KEY (supplier_id) REFERENCES suppliers(id) ON DELETE SET NULL;
|