-- ===================================================== -- SCRIPT 04: Create Warranty Infrastructure -- ===================================================== -- Date: 2025-11-06 -- Purpose: Create warranties table for tracking machine warranties -- Status: REVERSIBLE (see ROLLBACK_04) -- Estimated Time: 1-2 minutes -- ===================================================== USE shopdb; SET SQL_SAFE_UPDATES = 0; -- ===================================================== -- STEP 1: Create warranties table -- ===================================================== CREATE TABLE IF NOT EXISTS warranties ( warrantyid INT(11) PRIMARY KEY AUTO_INCREMENT, machineid INT(11) NOT NULL, warrantyname VARCHAR(100), -- Dell Basic, HP Premium, etc. enddate DATE, servicelevel VARCHAR(100), -- Next Business Day, 4-hour, etc. lastcheckeddate DATETIME, -- Last time warranty was verified -- Audit fields lastupdated DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, dateadded DATETIME DEFAULT CURRENT_TIMESTAMP, -- Indexes KEY idx_machineid (machineid), KEY idx_enddate (enddate), KEY idx_lastcheckeddate (lastcheckeddate), -- Foreign Key CONSTRAINT fk_warranties_machineid FOREIGN KEY (machineid) REFERENCES machines(machineid) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='Warranty tracking for machines (PCs, equipment, etc.)'; -- ===================================================== -- STEP 2: Create warranty status view -- ===================================================== CREATE OR REPLACE VIEW vw_warranty_status AS SELECT m.machineid, m.machinenumber, m.hostname, m.serialnumber, w.warrantyid, w.warrantyname, w.enddate AS warrantyenddate, w.servicelevel AS warrantyservicelevel, w.lastcheckeddate AS warrantylastchecked, CASE WHEN w.enddate IS NULL THEN 'Unknown' WHEN w.enddate < CURDATE() THEN 'Expired' WHEN w.enddate < DATE_ADD(CURDATE(), INTERVAL 90 DAY) THEN 'Expiring Soon' ELSE 'Active' END AS warrantystatus, CASE WHEN w.enddate IS NULL THEN NULL ELSE DATEDIFF(w.enddate, CURDATE()) END AS warrantydaysremaining FROM machines m LEFT JOIN warranties w ON m.machineid = w.machineid WHERE m.isactive = 1; -- ===================================================== -- STEP 3: Create expiring warranties view -- ===================================================== CREATE OR REPLACE VIEW vw_warranties_expiring AS SELECT machineid, machinenumber, hostname, serialnumber, warrantyname, warrantyenddate, warrantyservicelevel, warrantystatus, warrantydaysremaining FROM vw_warranty_status WHERE warrantyenddate IS NOT NULL AND warrantyenddate >= CURDATE() AND warrantyenddate <= DATE_ADD(CURDATE(), INTERVAL 90 DAY) ORDER BY warrantyenddate; -- ===================================================== -- VERIFICATION -- ===================================================== SELECT '✓ warranties table created' AS status; DESCRIBE warranties; SELECT '✓ Warranty views created' AS status; SHOW TABLES LIKE 'vw_warrant%'; SELECT '✓ Script 04 completed successfully' AS status; SET SQL_SAFE_UPDATES = 1; -- ===================================================== -- NOTES -- ===================================================== -- Next: Run script 05_create_compliance_infrastructure.sql -- Rollback: Run ROLLBACK_04_warranty_infrastructure.sql -- -- Migration Notes: -- - PC warranty data will be migrated from pc table: -- - warrantyenddate → warranties.enddate -- - warrantyservicelevel → warranties.servicelevel -- - warrantylastchecked → warranties.lastcheckeddate -- - warrantystatus (computed field, not stored) -- - warrantydaysremaining (computed field, not stored) -- =====================================================