Files
quality_recticel/py_app/app/daily_mirror_database_schema.sql
2025-10-26 19:30:12 +02:00

344 lines
12 KiB
SQL

-- Daily Mirror Database Schema
-- Quality Recticel Production Tracking System
-- Created: October 24, 2025
-- =============================================
-- ORDERS DATA TABLES
-- =============================================
-- Main Orders Table (from Vizual. Artic. Comenzi Deschise)
CREATE TABLE IF NOT EXISTS dm_orders (
id INT AUTO_INCREMENT PRIMARY KEY,
order_id VARCHAR(50) UNIQUE NOT NULL,
customer_code VARCHAR(50),
customer_name VARCHAR(255),
client_order VARCHAR(100),
article_code VARCHAR(50),
article_description TEXT,
quantity_requested INT,
delivery_date DATE,
order_status VARCHAR(50),
priority VARCHAR(20),
product_group VARCHAR(100),
order_date DATE,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
INDEX idx_order_id (order_id),
INDEX idx_customer (customer_code),
INDEX idx_article (article_code),
INDEX idx_delivery_date (delivery_date),
INDEX idx_order_date (order_date),
INDEX idx_status (order_status)
);
-- =============================================
-- PRODUCTION DATA TABLES
-- =============================================
-- Production Orders Table (from Comenzi Productie - Production orders Data sheet)
CREATE TABLE IF NOT EXISTS dm_production_orders (
id INT AUTO_INCREMENT PRIMARY KEY,
-- Primary Identifiers
production_order VARCHAR(50) UNIQUE NOT NULL,
open_for_order_line VARCHAR(100), -- Concatenated: "Opened for Order" + "-" + "Linia"
client_order_line VARCHAR(100), -- Concatenated: "Com. Achiz. Client" + "-" + "Nr. linie com. client"
-- Customer Information
customer_code VARCHAR(50),
customer_name VARCHAR(255),
-- Article Information
article_code VARCHAR(100),
article_description TEXT,
quantity_requested INT,
unit_of_measure VARCHAR(20),
-- Dates
delivery_date DATE, -- SO Duedate
opening_date DATE, -- Data Deschiderii
closing_date DATE, -- Data Inchiderii
data_planificare DATE, -- Data Planific.
-- Production Status
production_status VARCHAR(50), -- Status (Inchis, etc.)
-- Machine Information
machine_code VARCHAR(50), -- Masina cusut
machine_type VARCHAR(50), -- Tip masina
machine_number VARCHAR(20), -- Machine Number
-- Production Timeline
end_of_quilting DATE, -- End of Quilting
end_of_sewing DATE, -- End of Sewing
-- Quality Control Phase T1 (Prepared)
phase_t1_prepared VARCHAR(50), -- Faza pregatit(T1)
t1_operator_name VARCHAR(100), -- Nume complet T1
t1_registration_date DATETIME, -- Data inregistrare T1
-- Quality Control Phase T2 (Cut/Quilted)
phase_t2_cut VARCHAR(50), -- Faza taiat/matlasat(T2)
t2_operator_name VARCHAR(100), -- Nume complet T2
t2_registration_date DATETIME, -- Data inregistrare T2
-- Quality Control Phase T3 (Sewing)
phase_t3_sewing VARCHAR(50), -- Faza cusut(T3)
t3_operator_name VARCHAR(100), -- Nume complet T3
t3_registration_date DATETIME, -- Data inregistrare T3
-- Additional Information
design_number INT, -- Design number
classification VARCHAR(100), -- Clasificare
model_description VARCHAR(255), -- Descriere Model
model_lb2 VARCHAR(255), -- Model Lb2
needle_position DECIMAL(5,1), -- Needle Position
needle_row VARCHAR(50), -- Needle row
priority INT DEFAULT 0, -- Prioritate executie
-- Metadata
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
-- Indexes for Performance
INDEX idx_production_order (production_order),
INDEX idx_open_for_order_line (open_for_order_line),
INDEX idx_client_order_line (client_order_line),
INDEX idx_customer (customer_code),
INDEX idx_article (article_code),
INDEX idx_delivery_date (delivery_date),
INDEX idx_status (production_status),
INDEX idx_machine (machine_code),
INDEX idx_quilting_date (end_of_quilting),
INDEX idx_sewing_date (end_of_sewing),
INDEX idx_data_planificare (data_planificare)
);
-- =============================================
-- DELIVERY DATA TABLES
-- =============================================
-- Delivery/Shipment Table (from Articole livrate)
CREATE TABLE IF NOT EXISTS dm_deliveries (
id INT AUTO_INCREMENT PRIMARY KEY,
shipment_id VARCHAR(50) UNIQUE NOT NULL,
order_id VARCHAR(50),
production_order VARCHAR(50),
customer_code VARCHAR(50),
customer_name VARCHAR(255),
article_code VARCHAR(50),
article_description TEXT,
quantity_delivered INT,
quantity_returned INT DEFAULT 0,
-- Delivery Timeline
shipment_date DATE,
delivery_date DATE,
return_date DATE,
-- Delivery Status
delivery_status VARCHAR(50), -- 'shipped', 'delivered', 'returned', 'partial'
shipping_method VARCHAR(100),
tracking_number VARCHAR(100),
shipping_address TEXT,
delivery_notes TEXT,
-- Financial
unit_price DECIMAL(10,2),
total_value DECIMAL(12,2),
currency VARCHAR(3) DEFAULT 'RON',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
INDEX idx_shipment_id (shipment_id),
INDEX idx_order_id (order_id),
INDEX idx_production_order (production_order),
INDEX idx_customer (customer_code),
INDEX idx_article (article_code),
INDEX idx_shipment_date (shipment_date),
INDEX idx_delivery_date (delivery_date),
INDEX idx_status (delivery_status)
);
-- =============================================
-- DAILY MIRROR AGGREGATION TABLES
-- =============================================
-- Daily Summary Table (for fast reporting)
CREATE TABLE IF NOT EXISTS dm_daily_summary (
id INT AUTO_INCREMENT PRIMARY KEY,
report_date DATE UNIQUE NOT NULL,
-- Orders Metrics
orders_received INT DEFAULT 0,
orders_quantity INT DEFAULT 0,
orders_value DECIMAL(15,2) DEFAULT 0,
unique_customers INT DEFAULT 0,
-- Production Metrics
production_launched INT DEFAULT 0,
production_finished INT DEFAULT 0,
production_in_progress INT DEFAULT 0,
quilting_completed INT DEFAULT 0,
sewing_completed INT DEFAULT 0,
-- Delivery Metrics
orders_shipped INT DEFAULT 0,
orders_delivered INT DEFAULT 0,
orders_returned INT DEFAULT 0,
delivery_value DECIMAL(15,2) DEFAULT 0,
-- Efficiency Metrics
on_time_deliveries INT DEFAULT 0,
late_deliveries INT DEFAULT 0,
active_operators INT DEFAULT 0,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
INDEX idx_report_date (report_date)
);
-- =============================================
-- CONFIGURATION AND LOOKUP TABLES
-- =============================================
-- Customer Master
CREATE TABLE IF NOT EXISTS dm_customers (
id INT AUTO_INCREMENT PRIMARY KEY,
customer_code VARCHAR(50) UNIQUE NOT NULL,
customer_name VARCHAR(255) NOT NULL,
customer_group VARCHAR(100),
country VARCHAR(50),
currency VARCHAR(3) DEFAULT 'RON',
payment_terms VARCHAR(100),
credit_limit DECIMAL(15,2),
active BOOLEAN DEFAULT TRUE,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
INDEX idx_customer_code (customer_code),
INDEX idx_customer_name (customer_name),
INDEX idx_customer_group (customer_group)
);
-- Article Master
CREATE TABLE IF NOT EXISTS dm_articles (
id INT AUTO_INCREMENT PRIMARY KEY,
article_code VARCHAR(50) UNIQUE NOT NULL,
article_description TEXT NOT NULL,
product_group VARCHAR(100),
classification VARCHAR(100),
unit_of_measure VARCHAR(20),
standard_price DECIMAL(10,2),
standard_time DECIMAL(8,2),
active BOOLEAN DEFAULT TRUE,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
INDEX idx_article_code (article_code),
INDEX idx_product_group (product_group),
INDEX idx_classification (classification)
);
-- Machine Master
CREATE TABLE IF NOT EXISTS dm_machines (
id INT AUTO_INCREMENT PRIMARY KEY,
machine_code VARCHAR(50) UNIQUE NOT NULL,
machine_name VARCHAR(255),
machine_type VARCHAR(50),
machine_number VARCHAR(20),
department VARCHAR(100),
capacity_per_hour DECIMAL(8,2),
active BOOLEAN DEFAULT TRUE,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
INDEX idx_machine_code (machine_code),
INDEX idx_machine_type (machine_type),
INDEX idx_department (department)
);
-- =============================================
-- DATA IMPORT TRACKING
-- =============================================
-- Track file uploads and data imports
CREATE TABLE IF NOT EXISTS dm_import_log (
id INT AUTO_INCREMENT PRIMARY KEY,
file_name VARCHAR(255) NOT NULL,
file_type VARCHAR(50) NOT NULL, -- 'orders', 'production', 'delivery'
upload_date TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
uploaded_by VARCHAR(100),
records_processed INT DEFAULT 0,
records_successful INT DEFAULT 0,
records_failed INT DEFAULT 0,
status VARCHAR(50) DEFAULT 'processing', -- 'processing', 'completed', 'failed'
error_message TEXT,
processing_time DECIMAL(8,2), -- seconds
INDEX idx_upload_date (upload_date),
INDEX idx_file_type (file_type),
INDEX idx_status (status),
INDEX idx_uploaded_by (uploaded_by)
);
-- =============================================
-- VIEWS FOR DAILY MIRROR REPORTING
-- =============================================
-- View: Current Production Status
CREATE OR REPLACE VIEW v_daily_production_status AS
SELECT
DATE(p.data_planificare) as production_date,
COUNT(*) as total_orders,
SUM(p.quantity_requested) as total_quantity,
SUM(CASE WHEN p.production_status = 'Inchis' THEN 1 ELSE 0 END) as completed_orders,
SUM(CASE WHEN p.production_status != 'Inchis' THEN 1 ELSE 0 END) as pending_orders,
SUM(CASE WHEN p.end_of_quilting IS NOT NULL THEN 1 ELSE 0 END) as quilting_done,
SUM(CASE WHEN p.end_of_sewing IS NOT NULL THEN 1 ELSE 0 END) as sewing_done,
COUNT(DISTINCT p.customer_code) as unique_customers,
COUNT(DISTINCT p.machine_code) as machines_used
FROM dm_production_orders p
WHERE p.data_planificare >= CURDATE() - INTERVAL 30 DAY
GROUP BY DATE(p.data_planificare)
ORDER BY production_date DESC;
-- View: Quality Performance Summary
CREATE OR REPLACE VIEW v_daily_quality_summary AS
SELECT
DATE(p.t1_registration_date) as scan_date,
COUNT(*) as total_t1_scans,
SUM(CASE WHEN p.t1_status = 0 THEN 1 ELSE 0 END) as t1_approved,
ROUND(SUM(CASE WHEN p.t1_status = 0 THEN 1 ELSE 0 END) / COUNT(*) * 100, 2) as t1_approval_rate,
COUNT(CASE WHEN p.t2_registration_date IS NOT NULL THEN 1 END) as total_t2_scans,
SUM(CASE WHEN p.t2_status = 0 THEN 1 ELSE 0 END) as t2_approved,
ROUND(SUM(CASE WHEN p.t2_status = 0 THEN 1 ELSE 0 END) / COUNT(CASE WHEN p.t2_registration_date IS NOT NULL THEN 1 END) * 100, 2) as t2_approval_rate,
COUNT(DISTINCT p.t1_operator_name) as active_operators
FROM dm_production_orders p
WHERE p.t1_registration_date >= CURDATE() - INTERVAL 30 DAY
GROUP BY DATE(p.t1_registration_date)
ORDER BY scan_date DESC;
-- View: Delivery Performance
CREATE OR REPLACE VIEW v_daily_delivery_summary AS
SELECT
d.delivery_date,
COUNT(*) as total_deliveries,
SUM(d.quantity_delivered) as total_quantity_delivered,
SUM(d.total_value) as total_delivery_value,
SUM(CASE WHEN d.delivery_date <= o.delivery_date THEN 1 ELSE 0 END) as on_time_deliveries,
SUM(CASE WHEN d.delivery_date > o.delivery_date THEN 1 ELSE 0 END) as late_deliveries,
COUNT(DISTINCT d.customer_code) as unique_customers
FROM dm_deliveries d
LEFT JOIN dm_orders o ON d.order_id = o.order_id
WHERE d.delivery_date >= CURDATE() - INTERVAL 30 DAY
AND d.delivery_status = 'delivered'
GROUP BY d.delivery_date
ORDER BY d.delivery_date DESC;