# Warranty Management System Design **Date Created**: 2025-11-06 **Status**: DESIGN PHASE **Related Document**: PC_MACHINES_CONSOLIDATION_PLAN.md --- ## Executive Summary Instead of storing warranty fields directly on the `machines` table, create a dedicated warranty management system that supports: - Multiple warranties per machine (e.g., hardware warranty + extended support) - Warranty history and renewals - Different warranty providers - Automatic expiration tracking - Better reporting capabilities --- ## Part 1: New Warranty Infrastructure ### 1.1 Simple Warranty Table **Design Decision**: Keep it simple - just track warranty name and expiration date. **Rationale**: - Most important info: when does warranty expire and what is it called - Avoid over-engineering - Easy to add more fields later if needed ### 1.2 New Table: warranties Minimal warranty tracking - one or more warranties per machine ```sql CREATE TABLE warranties ( warrantyid INT(11) PRIMARY KEY AUTO_INCREMENT, machineid INT(11) NOT NULL, -- Core warranty info warrantyname VARCHAR(100) NOT NULL, -- 'ProFlex Support', 'Next Business Day', 'Standard 3-Year', etc. enddate DATE NOT NULL, -- Optional metadata notes TEXT, isactive TINYINT(1) DEFAULT 1, dateadded DATETIME DEFAULT CURRENT_TIMESTAMP, lastupdated DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, -- Indexes KEY idx_machineid (machineid), KEY idx_enddate (enddate), KEY idx_isactive (isactive), -- Foreign Keys CONSTRAINT fk_warranties_machineid FOREIGN KEY (machineid) REFERENCES machines(machineid) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; ``` **Total Columns**: 8 (simple and clean!) **Example Data:** ```sql -- Dell PC with ProSupport INSERT INTO warranties (machineid, warrantyname, enddate) VALUES (123, 'Dell ProSupport Plus', '2026-03-15'); -- CNC Machine with extended warranty INSERT INTO warranties (machineid, warrantyname, enddate) VALUES (456, 'Okuma Extended Service Agreement', '2027-12-31'); -- Server with multiple warranties INSERT INTO warranties (machineid, warrantyname, enddate) VALUES (789, 'HP Standard Hardware Warranty', '2025-06-30'), (789, 'HP 24/7 Support Contract', '2027-06-30'); ``` --- ## Part 2: Updated Machines Table Design ### 2.1 No Warranty Fields on Machines Table **Design Decision**: Don't add any warranty fields to the machines table. **Rationale**: - Warranties are separate entities in their own table - Use JOINs or views when you need warranty info - Keeps machines table clean - Supports multiple warranties per machine --- ## Part 3: Useful Views for Warranty Management ### 3.1 View: vw_machine_warranties Show all machines with their warranties ```sql CREATE VIEW vw_machine_warranties AS SELECT m.machineid, m.machinenumber, m.hostname, m.serialnumber, mt.machinetype, mo.modelnumber, v.vendor, -- Warranty info w.warrantyid, w.warrantyname, w.enddate AS warranty_enddate, DATEDIFF(w.enddate, CURDATE()) AS days_remaining, -- Status calculation CASE WHEN w.enddate IS NULL THEN 'No Warranty' WHEN w.enddate < CURDATE() THEN 'Expired' WHEN DATEDIFF(w.enddate, CURDATE()) <= 30 THEN 'Expiring Soon' ELSE 'Active' END AS warranty_status, -- How many warranties total for this machine (SELECT COUNT(*) FROM warranties w2 WHERE w2.machineid = m.machineid AND w2.isactive = 1) AS total_warranties, w.notes AS warranty_notes FROM machines m LEFT JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid LEFT JOIN models mo ON m.modelnumberid = mo.modelnumberid LEFT JOIN vendors v ON mo.vendorid = v.vendorid LEFT JOIN warranties w ON m.machineid = w.machineid AND w.isactive = 1 WHERE m.isactive = 1 ORDER BY m.machinenumber, w.enddate DESC; ``` ### 3.2 View: vw_warranties_expiring Show warranties expiring in the next 90 days ```sql CREATE VIEW vw_warranties_expiring AS SELECT m.machineid, m.machinenumber, m.hostname, m.serialnumber, mt.machinetype, mo.modelnumber, v.vendor AS manufacturer, w.warrantyname, w.enddate AS warranty_enddate, DATEDIFF(w.enddate, CURDATE()) AS days_remaining, CASE WHEN DATEDIFF(w.enddate, CURDATE()) <= 7 THEN 'Critical' WHEN DATEDIFF(w.enddate, CURDATE()) <= 30 THEN 'Warning' WHEN DATEDIFF(w.enddate, CURDATE()) <= 90 THEN 'Notice' ELSE 'Active' END AS urgency, w.notes FROM warranties w INNER JOIN machines m ON w.machineid = m.machineid LEFT JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid LEFT JOIN models mo ON m.modelnumberid = mo.modelnumberid LEFT JOIN vendors v ON mo.vendorid = v.vendorid WHERE w.isactive = 1 AND w.enddate >= CURDATE() AND DATEDIFF(w.enddate, CURDATE()) <= 90 AND m.isactive = 1 ORDER BY days_remaining ASC; ``` ### 3.3 View: vw_warranty_summary Summary statistics for reporting ```sql CREATE VIEW vw_warranty_summary AS SELECT COUNT(*) AS total_warranties, SUM(CASE WHEN w.enddate >= CURDATE() THEN 1 ELSE 0 END) AS active_warranties, SUM(CASE WHEN w.enddate < CURDATE() THEN 1 ELSE 0 END) AS expired_warranties, SUM(CASE WHEN DATEDIFF(w.enddate, CURDATE()) <= 90 AND w.enddate >= CURDATE() THEN 1 ELSE 0 END) AS expiring_soon, MIN(w.enddate) AS earliest_expiration, MAX(w.enddate) AS latest_expiration FROM warranties w WHERE w.isactive = 1; ``` ### 3.4 View: vw_machines_without_warranty Find machines with no warranty coverage ```sql CREATE VIEW vw_machines_without_warranty AS SELECT m.machineid, m.machinenumber, m.hostname, m.serialnumber, mt.machinetype, mo.modelnumber, v.vendor AS manufacturer, m.dateadded, DATEDIFF(CURDATE(), m.dateadded) AS days_since_added FROM machines m LEFT JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid LEFT JOIN models mo ON m.modelnumberid = mo.modelnumberid LEFT JOIN vendors v ON mo.vendorid = v.vendorid LEFT JOIN warranties w ON m.machineid = w.machineid AND w.isactive = 1 AND w.status = 'Active' WHERE m.isactive = 1 AND w.warrantyid IS NULL ORDER BY m.dateadded DESC; ``` --- ## Part 4: Data Migration from PC Table ### 4.1 Migrate PC Warranty Data ```sql -- Step 1: Insert warranty records for all PCs with warranty data INSERT INTO warranties ( machineid, warrantytypeid, warrantyvendorid, startdate, enddate, servicelevel, servicetag, status, isprimary, lastcheckeddate, notes, isactive ) SELECT -- Map to new machine ID (assuming PCs have been migrated to machines) m.machineid, -- Default to 'Standard Hardware' warranty type (SELECT warrantytypeid FROM warrantytypes WHERE typename = 'Standard Hardware' LIMIT 1), -- Map vendor from models table (SELECT mo.vendorid FROM models mo WHERE mo.modelnumberid = p.modelnumberid LIMIT 1), -- Calculate start date (assume 3 years before end date, or use dateadded) COALESCE(DATE_SUB(p.warrantyenddate, INTERVAL 3 YEAR), p.dateadded), -- End date from PC table p.warrantyenddate, -- Service level p.warrantyservicelevel, -- Use serial number as service tag p.serialnumber, -- Status based on current date CASE WHEN p.warrantyenddate < CURDATE() THEN 'Expired' WHEN p.warrantystatus = 'Unknown' THEN 'Pending' ELSE 'Active' END, -- Set as primary warranty 1, -- Last checked date p.warrantylastchecked, -- Notes CONCAT('Migrated from PC table. Original status: ', COALESCE(p.warrantystatus, 'Unknown')), -- Active flag 1 FROM pc p INNER JOIN machines m ON p.hostname = m.hostname -- Link by hostname after PC migration WHERE p.warrantyenddate IS NOT NULL; ``` --- ## Part 5: SQL Migration Scripts ### 5.1 Script 04: Create Warranty Infrastructure File: `sql/04_create_warranty_infrastructure.sql` ```sql -- ===================================================== -- SCRIPT 04: Create Warranty Management Infrastructure -- ===================================================== -- Date: 2025-11-06 -- Purpose: Create warranty tables and views -- Status: REVERSIBLE (has rollback script) -- ===================================================== USE shopdb; SET SQL_SAFE_UPDATES = 0; -- Create warrantytypes table CREATE TABLE IF NOT EXISTS warrantytypes ( warrantytypeid INT(11) PRIMARY KEY AUTO_INCREMENT, typename VARCHAR(50) NOT NULL UNIQUE, description VARCHAR(255), isactive TINYINT(1) DEFAULT 1, displayorder INT(11) DEFAULT 0, KEY idx_isactive (isactive), KEY idx_displayorder (displayorder) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- Insert warranty types INSERT INTO warrantytypes (typename, description, displayorder) VALUES ('Standard Hardware', 'Manufacturer standard warranty', 1), ('Extended Hardware', 'Extended manufacturer warranty', 2), ('Premium Support', 'Premium/ProSupport service level', 3), ('Onsite Service', 'Next business day onsite service', 4), ('Accidental Damage', 'Accidental damage protection', 5), ('Software Support', 'Software/OS support coverage', 6), ('Preventive Maintenance', 'Scheduled preventive maintenance', 7), ('Parts Only', 'Parts replacement only, no labor', 8); -- Create warranties table CREATE TABLE IF NOT EXISTS warranties ( warrantyid INT(11) PRIMARY KEY AUTO_INCREMENT, machineid INT(11) NOT NULL, warrantytypeid INT(11) NOT NULL, vendorid INT(11), startdate DATE NOT NULL, enddate DATE NOT NULL, servicelevel VARCHAR(100), servicetag VARCHAR(100), ordernumber VARCHAR(100), coveragenotes TEXT, cost DECIMAL(10,2), status VARCHAR(50) DEFAULT 'Active', isprimary TINYINT(1) DEFAULT 0, autorenew TINYINT(1) DEFAULT 0, lastcheckeddate DATETIME, daysremaining INT(11) GENERATED ALWAYS AS (DATEDIFF(enddate, CURDATE())) VIRTUAL, notify_60days TINYINT(1) DEFAULT 1, notify_30days TINYINT(1) DEFAULT 1, notify_7days TINYINT(1) DEFAULT 1, notificationemail VARCHAR(255), notes TEXT, isactive TINYINT(1) DEFAULT 1, dateadded DATETIME DEFAULT CURRENT_TIMESTAMP, lastupdated DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, addedby VARCHAR(100), KEY idx_machineid (machineid), KEY idx_warrantytypeid (warrantytypeid), KEY idx_vendorid (vendorid), KEY idx_enddate (enddate), KEY idx_status (status), KEY idx_isprimary (isprimary), KEY idx_isactive (isactive), CONSTRAINT fk_warranties_machineid FOREIGN KEY (machineid) REFERENCES machines(machineid), CONSTRAINT fk_warranties_warrantytypeid FOREIGN KEY (warrantytypeid) REFERENCES warrantytypes(warrantytypeid), CONSTRAINT fk_warranties_vendorid FOREIGN KEY (vendorid) REFERENCES vendors(vendorid) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- Create warrantyhistory table CREATE TABLE IF NOT EXISTS warrantyhistory ( historyid INT(11) PRIMARY KEY AUTO_INCREMENT, warrantyid INT(11) NOT NULL, machineid INT(11) NOT NULL, action VARCHAR(50) NOT NULL, oldenddate DATE, newenddate DATE, oldstatus VARCHAR(50), newstatus VARCHAR(50), reason TEXT, cost DECIMAL(10,2), actiondate DATETIME DEFAULT CURRENT_TIMESTAMP, actionby VARCHAR(100), KEY idx_warrantyid (warrantyid), KEY idx_machineid (machineid), KEY idx_actiondate (actiondate), CONSTRAINT fk_warrantyhistory_warrantyid FOREIGN KEY (warrantyid) REFERENCES warranties(warrantyid), CONSTRAINT fk_warrantyhistory_machineid FOREIGN KEY (machineid) REFERENCES machines(machineid) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -- Verification SELECT 'Warranty infrastructure created' AS status; SELECT COUNT(*) AS warranty_type_count FROM warrantytypes; SET SQL_SAFE_UPDATES = 1; ``` ### 5.2 Rollback Script 04 File: `sql/ROLLBACK_04_warranty_infrastructure.sql` ```sql -- ===================================================== -- ROLLBACK 04: Remove Warranty Infrastructure -- ===================================================== USE shopdb; SET SQL_SAFE_UPDATES = 0; -- Drop tables in correct order (FK constraints) DROP TABLE IF EXISTS warrantyhistory; DROP TABLE IF EXISTS warranties; DROP TABLE IF EXISTS warrantytypes; SELECT 'Warranty infrastructure removed' AS status; SET SQL_SAFE_UPDATES = 1; ``` --- ## Part 6: Benefits of Warranty System ### 6.1 Advantages Over Field-Based Approach | Feature | Old (fields on machines) | New (warranty tables) | |---------|-------------------------|----------------------| | Multiple warranties | No | Yes | | Warranty history | No | Yes | | Renewal tracking | No | Yes | | Cost tracking | No | Yes | | Different vendors | No | Yes | | Auto-notifications | No | Yes | | Reporting | Limited | Comprehensive | | Audit trail | No | Yes | ### 6.2 Example Use Cases **Use Case 1: PC with multiple warranties** - Dell standard 3-year warranty (expires 2026-01-15) - Extended ProSupport warranty (expires 2027-01-15) - Accidental damage protection (expires 2026-01-15) **Use Case 2: CNC Machine** - Okuma manufacturer warranty (expired 2020-05-01) - Extended service contract (expires 2026-12-31) - Preventive maintenance agreement (expires 2025-06-30) **Use Case 3: Server** - HP standard warranty (expires 2025-03-15) - Primary - Extended 24/7 support (expires 2027-03-15) --- ## Part 7: Integration with PC Migration Update the machines table design from PC_MACHINES_CONSOLIDATION_PLAN.md: ### Remove These Fields: ```sql -- DO NOT ADD: -- warrantyenddate -- warrantystatus -- warrantydaysremaining -- warrantyservicelevel -- warrantylastchecked ``` ### Keep Machines Table Clean: The machines table should NOT have warranty fields. All warranty information will be in the `warranties` table and accessed via JOINs or views. --- ## Next Steps 1. Review warranty table design 2. Create warranty management views 3. Create data migration script for PC warranties 4. Update PC migration plan to use warranty tables 5. Create ASP pages for warranty management 6. Create warranty expiration notification system --- **Document Status**: DRAFT - Ready for Review **Dependencies**: Requires machines table from PC consolidation **Production Impact**: New tables, no breaking changes