Set up change tracking in core tables
This commit is contained in:
@@ -1,6 +1,44 @@
|
||||
-- Disable foreign key checks
|
||||
SET FOREIGN_KEY_CHECKS = 0;
|
||||
|
||||
-- Create metric status tracking table
|
||||
CREATE TABLE IF NOT EXISTS product_metric_status (
|
||||
pid BIGINT NOT NULL,
|
||||
last_calculated_at TIMESTAMP NULL,
|
||||
needs_recalculation BOOLEAN DEFAULT TRUE,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (pid),
|
||||
INDEX idx_needs_recalc (needs_recalculation),
|
||||
INDEX idx_last_calc (last_calculated_at),
|
||||
FOREIGN KEY (pid) REFERENCES products(pid) ON DELETE CASCADE
|
||||
) ENGINE=InnoDB;
|
||||
|
||||
-- Add triggers for metric recalculation
|
||||
DROP TRIGGER IF EXISTS orders_after_insert_update;
|
||||
CREATE TRIGGER orders_after_insert_update AFTER INSERT ON orders FOR EACH ROW
|
||||
INSERT INTO product_metric_status (pid, needs_recalculation)
|
||||
VALUES (NEW.pid, TRUE)
|
||||
ON DUPLICATE KEY UPDATE
|
||||
needs_recalculation = TRUE,
|
||||
updated_at = CURRENT_TIMESTAMP;
|
||||
|
||||
DROP TRIGGER IF EXISTS purchase_orders_after_insert_update;
|
||||
CREATE TRIGGER purchase_orders_after_insert_update AFTER INSERT ON purchase_orders FOR EACH ROW
|
||||
INSERT INTO product_metric_status (pid, needs_recalculation)
|
||||
VALUES (NEW.pid, TRUE)
|
||||
ON DUPLICATE KEY UPDATE
|
||||
needs_recalculation = TRUE,
|
||||
updated_at = CURRENT_TIMESTAMP;
|
||||
|
||||
DROP TRIGGER IF EXISTS products_after_insert_update;
|
||||
CREATE TRIGGER products_after_insert_update AFTER INSERT ON products FOR EACH ROW
|
||||
INSERT INTO product_metric_status (pid, needs_recalculation)
|
||||
VALUES (NEW.pid, TRUE)
|
||||
ON DUPLICATE KEY UPDATE
|
||||
needs_recalculation = TRUE,
|
||||
updated_at = CURRENT_TIMESTAMP;
|
||||
|
||||
-- Temporary tables for batch metrics processing
|
||||
CREATE TABLE IF NOT EXISTS temp_sales_metrics (
|
||||
pid BIGINT NOT NULL,
|
||||
@@ -410,21 +448,4 @@ LEFT JOIN
|
||||
category_metrics cm ON c.cat_id = cm.category_id;
|
||||
|
||||
-- Re-enable foreign key checks
|
||||
SET FOREIGN_KEY_CHECKS = 1;
|
||||
|
||||
-- Create table for sales seasonality factors
|
||||
CREATE TABLE IF NOT EXISTS sales_seasonality (
|
||||
month INT NOT NULL,
|
||||
seasonality_factor DECIMAL(5,3) DEFAULT 0,
|
||||
last_updated TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (month),
|
||||
CHECK (month BETWEEN 1 AND 12),
|
||||
CHECK (seasonality_factor BETWEEN -1.0 AND 1.0)
|
||||
);
|
||||
|
||||
-- Insert default seasonality factors (neutral)
|
||||
INSERT INTO sales_seasonality (month, seasonality_factor)
|
||||
VALUES
|
||||
(1, 0), (2, 0), (3, 0), (4, 0), (5, 0), (6, 0),
|
||||
(7, 0), (8, 0), (9, 0), (10, 0), (11, 0), (12, 0)
|
||||
ON DUPLICATE KEY UPDATE last_updated = CURRENT_TIMESTAMP;
|
||||
SET FOREIGN_KEY_CHECKS = 1;
|
||||
Reference in New Issue
Block a user