-- Warehouse Module Roles & Worker-Manager Binding Migration -- This migration adds: -- 1. Two new warehouse roles (warehouse_manager, warehouse_worker) -- 2. Worker-manager binding table for hierarchical access control -- ============================================================ -- 1. Insert new warehouse roles -- ============================================================ -- Note: These roles should be inserted if they don't exist -- This is typically handled by the Python init script, but this -- SQL is provided for reference or manual database setup INSERT IGNORE INTO roles (name, description, level) VALUES ('warehouse_manager', 'Manager - Warehouse - Full warehouse module access', 75), ('warehouse_worker', 'Worker - Warehouse - Input-only warehouse access', 35); -- Verify insertion SELECT id, name, level FROM roles WHERE name LIKE 'warehouse_%' ORDER BY level DESC; -- ============================================================ -- 2. Create worker_manager_bindings table -- ============================================================ CREATE TABLE IF NOT EXISTS worker_manager_bindings ( id INT AUTO_INCREMENT PRIMARY KEY, manager_id INT NOT NULL, worker_id INT NOT NULL, warehouse_zone VARCHAR(100), is_active TINYINT(1) DEFAULT 1, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, UNIQUE KEY unique_binding (manager_id, worker_id), FOREIGN KEY (manager_id) REFERENCES users(id) ON DELETE CASCADE, FOREIGN KEY (worker_id) REFERENCES users(id) ON DELETE CASCADE, CHECK (manager_id != worker_id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ============================================================ -- 3. Example queries for worker-manager binding management -- ============================================================ -- Assign a worker to a manager -- INSERT INTO worker_manager_bindings (manager_id, worker_id, warehouse_zone) -- VALUES (5, 12, NULL); -- Manager ID 5 oversees Worker ID 12 -- Get all workers for a specific manager -- SELECT u.id, u.username, u.full_name, wmb.warehouse_zone -- FROM worker_manager_bindings wmb -- JOIN users u ON wmb.worker_id = u.id -- WHERE wmb.manager_id = 5 AND wmb.is_active = 1 -- ORDER BY u.full_name; -- Get manager for a specific worker -- SELECT m.id, m.username, m.full_name -- FROM worker_manager_bindings wmb -- JOIN users m ON wmb.manager_id = m.id -- WHERE wmb.worker_id = 12 AND wmb.is_active = 1; -- Deactivate a binding (soft delete) -- UPDATE worker_manager_bindings SET is_active = 0 WHERE id = 1; -- ============================================================ -- 4. Verification Queries -- ============================================================ -- Verify warehouse roles exist -- SELECT COUNT(*) as warehouse_role_count FROM roles WHERE name LIKE 'warehouse_%'; -- Verify worker_manager_bindings table exists -- SELECT TABLE_NAME FROM information_schema.TABLES -- WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'worker_manager_bindings'; -- List all role hierarchy (for reference) -- SELECT name, level, CASE -- WHEN level >= 90 THEN 'Admin' -- WHEN level >= 70 THEN 'Manager' -- WHEN level >= 35 THEN 'Worker' -- ELSE 'Unknown' -- END as category FROM roles ORDER BY level DESC;