38471-vm/db/migrations/20260220_split_invoices_purchases.sql
2026-02-20 09:15:43 +00:00

70 lines
2.9 KiB
SQL

-- 1. Create purchases table
CREATE TABLE IF NOT EXISTS purchases (
id int(11) NOT NULL AUTO_INCREMENT,
supplier_id int(11) DEFAULT NULL,
invoice_date date NOT NULL,
payment_type varchar(100) DEFAULT NULL,
total_amount decimal(15,3) DEFAULT NULL,
vat_amount decimal(15,3) DEFAULT NULL,
total_with_vat decimal(15,3) DEFAULT NULL,
terms_conditions text DEFAULT NULL,
paid_amount decimal(15,3) DEFAULT NULL,
status enum('paid','unpaid','partially_paid') DEFAULT NULL,
register_session_id int(11) DEFAULT NULL,
due_date date DEFAULT NULL,
created_at timestamp NULL DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY (id)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
-- 2. Create purchase_items table
CREATE TABLE IF NOT EXISTS purchase_items (
id int(11) NOT NULL AUTO_INCREMENT,
purchase_id int(11) NOT NULL,
item_id int(11) NOT NULL,
quantity decimal(15,2) NOT NULL,
unit_price decimal(15,3) DEFAULT NULL,
vat_amount decimal(15,3) DEFAULT NULL,
total_price decimal(15,3) DEFAULT NULL,
PRIMARY KEY (id)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
-- 3. Create purchase_payments table
CREATE TABLE IF NOT EXISTS purchase_payments (
id int(11) NOT NULL AUTO_INCREMENT,
purchase_id int(11) NOT NULL,
payment_date date NOT NULL,
amount decimal(15,3) DEFAULT NULL,
payment_method varchar(50) DEFAULT NULL,
notes text DEFAULT NULL,
created_at timestamp NULL DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY (id)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
-- 4. Migrate purchase data
INSERT INTO purchases (id, supplier_id, invoice_date, payment_type, total_amount, vat_amount, total_with_vat, terms_conditions, paid_amount, status, register_session_id, due_date, created_at)
SELECT id, customer_id, invoice_date, payment_type, total_amount, vat_amount, total_with_vat, terms_conditions, paid_amount, status, register_session_id, due_date, created_at
FROM invoices
WHERE type = 'purchase';
-- 5. Migrate purchase items data
INSERT INTO purchase_items (id, purchase_id, item_id, quantity, unit_price, vat_amount, total_price)
SELECT ii.id, ii.invoice_id, ii.item_id, ii.quantity, ii.unit_price, ii.vat_amount, ii.total_price
FROM invoice_items ii
JOIN invoices i ON ii.invoice_id = i.id
WHERE i.type = 'purchase';
-- 6. Migrate purchase payments data
INSERT INTO purchase_payments (id, purchase_id, payment_date, amount, payment_method, notes, created_at)
SELECT p.id, p.invoice_id, p.payment_date, p.amount, p.payment_method, p.notes, p.created_at
FROM payments p
JOIN invoices i ON p.invoice_id = i.id
WHERE i.type = 'purchase';
-- 7. Clean up original tables
DELETE FROM invoice_items WHERE invoice_id IN (SELECT id FROM invoices WHERE type = 'purchase');
DELETE FROM payments WHERE invoice_id IN (SELECT id FROM invoices WHERE type = 'purchase');
DELETE FROM invoices WHERE type = 'purchase';
-- 8. Remove type column from invoices
ALTER TABLE invoices DROP COLUMN type;