# scanfg_orders Table - Box Tracking Implementation **Last Updated:** January 28, 2026 **Status:** ✅ Active and Deployed --- ## 📋 Table Overview The `scanfg_orders` table has been enhanced to support **scanned goods box tracking** functionality. It records all finished goods (FG) quality scans with integration to the box/location warehouse system. ### Current Status - **Total Records:** 0 - **Table Size:** Configured and ready - **New Box Tracking Columns:** ✅ Added and functional --- ## 📊 Complete Column Structure | # | Column Name | Data Type | Null | Key | Default | Purpose | |----|------------|-----------|------|-----|---------|---------| | 1 | **Id** | INT(11) | NO | PRI | auto_increment | Primary key - unique scan record ID | | 2 | **operator_code** | VARCHAR(50) | YES | MUL | NULL | Quality operator ID/code | | 3 | **CP_full_code** | VARCHAR(50) | YES | MUL | NULL | Complete CP (production order) code | | 4 | **OC1_code** | VARCHAR(50) | YES | - | NULL | Order code 1 (optional component) | | 5 | **OC2_code** | VARCHAR(50) | YES | - | NULL | Order code 2 (optional component) | | 6 | **quality_code** | VARCHAR(10) | YES | - | NULL | Defect/Quality classification code | | 7 | **date** | DATE | YES | MUL | NULL | Scan date | | 8 | **time** | TIME | YES | - | NULL | Scan time | | 9 | **approved_quantity** | INT(11) | YES | - | 0 | Count of approved units | | 10 | **rejected_quantity** | INT(11) | YES | - | 0 | Count of rejected units | | 11 | **box_id** | BIGINT(20) | YES | MUL | NULL | 🆕 FK to boxes_crates table | | 12 | **location_id** | BIGINT(20) | YES | MUL | NULL | 🆕 FK to warehouse_locations table | | 13 | **created_at** | TIMESTAMP | YES | - | CURRENT_TIMESTAMP | Record creation timestamp | --- ## 🆕 NEW BOX TRACKING COLUMNS ### Column 1: box_id ```sql box_id BIGINT(20) NULL, FOREIGN KEY (box_id) REFERENCES boxes_crates(id) ON DELETE SET NULL, INDEX idx_box_id (box_id) ``` **Purpose:** Links each scanned order to a specific box in the warehouse system **Relationship:** - Many scanfg_orders → One boxes_crates record - Enables tracking which box contains which CP codes - Allows retrieval of all scans for a specific box **Usage Example:** ```sql -- Find all scans in a specific box SELECT * FROM scanfg_orders WHERE box_id = 5 ORDER BY created_at DESC; -- Join with box details SELECT s.*, b.box_number, b.status FROM scanfg_orders s JOIN boxes_crates b ON s.box_id = b.id WHERE b.box_number = '00000001'; ``` --- ### Column 2: location_id ```sql location_id BIGINT(20) NULL, FOREIGN KEY (location_id) REFERENCES warehouse_locations(id) ON DELETE SET NULL, INDEX idx_location_id (location_id) ``` **Purpose:** Tracks the warehouse location where the scanned goods are stored **Relationship:** - Many scanfg_orders → One warehouse_locations record - Enables location-based inventory queries - Supports warehouse zone tracking (FG_INCOMING, TRUCK_LOADING, etc.) **Usage Example:** ```sql -- Find all scans in FG_INCOMING location SELECT s.*, l.location_code FROM scanfg_orders s JOIN warehouse_locations l ON s.location_id = l.id WHERE l.location_code = 'FG_INCOMING'; -- Count approvals by location SELECT l.location_code, COUNT(*) as total_scans FROM scanfg_orders s JOIN warehouse_locations l ON s.location_id = l.id GROUP BY l.location_code; ``` --- ## 🔗 Foreign Key Relationships ### scanfg_orders → boxes_crates ``` scanfg_orders.box_id → boxes_crates.id ``` - **Cardinality:** Many-to-One - **Delete Action:** SET NULL (orphaned scans remain) - **Purpose:** Track which box contains the scanned CP codes ### scanfg_orders → warehouse_locations ``` scanfg_orders.location_id → warehouse_locations.id ``` - **Cardinality:** Many-to-One - **Delete Action:** SET NULL (location deleted, scans preserved) - **Purpose:** Track warehouse location of the scanned goods --- ## 📑 Related Tables ### boxes_crates (Contains CP codes) ```sql CREATE TABLE boxes_crates ( id BIGINT PK, box_number VARCHAR(20) UNIQUE, status ENUM('open','closed'), location_id BIGINT FK, created_at TIMESTAMP, created_by INT FK ) ``` ### box_contents (Maps CP codes to boxes) ```sql CREATE TABLE box_contents ( id BIGINT PK, box_id BIGINT FK → boxes_crates.id, cp_code VARCHAR(50), quantity INT, added_at TIMESTAMP ) ``` ### warehouse_locations (Storage zones) ```sql CREATE TABLE warehouse_locations ( id BIGINT PK, location_code VARCHAR(12) UNIQUE, size INT, description VARCHAR(250), created_at TIMESTAMP ) ``` ### cp_location_history (Audit trail) ```sql CREATE TABLE cp_location_history ( id BIGINT PK, cp_code VARCHAR(50), box_id BIGINT FK, from_location_id BIGINT FK, to_location_id BIGINT FK, moved_by INT FK, moved_at TIMESTAMP ) ``` --- ## 🔍 Sample Query Patterns ### Get All Scans with Box and Location Info ```sql SELECT s.Id as scan_id, s.operator_code, s.CP_full_code, b.box_number, b.status, l.location_code, s.quality_code, s.approved_quantity, s.rejected_quantity, s.date, s.time FROM scanfg_orders s LEFT JOIN boxes_crates b ON s.box_id = b.id LEFT JOIN warehouse_locations l ON s.location_id = l.id ORDER BY s.created_at DESC; ``` ### Track Box Contents via Scans ```sql SELECT b.box_number, COUNT(DISTINCT s.CP_full_code) as unique_cp_codes, SUM(s.approved_quantity) as total_approved, SUM(s.rejected_quantity) as total_rejected, l.location_code FROM scanfg_orders s JOIN boxes_crates b ON s.box_id = b.id JOIN warehouse_locations l ON s.location_id = l.id GROUP BY b.id, l.location_code ORDER BY b.box_number; ``` ### Find Scans Without Box Assignment ```sql SELECT * FROM scanfg_orders WHERE box_id IS NULL ORDER BY created_at DESC LIMIT 10; ``` ### Historical Location Tracking for a Scan ```sql SELECT s.*, h.from_location_id, h.to_location_id, lf.location_code as from_location, lt.location_code as to_location, h.moved_at FROM scanfg_orders s LEFT JOIN cp_location_history h ON s.CP_full_code = h.cp_code LEFT JOIN warehouse_locations lf ON h.from_location_id = lf.id LEFT JOIN warehouse_locations lt ON h.to_location_id = lt.id WHERE s.Id = ? ORDER BY h.moved_at DESC; ``` --- ## 💾 Data Statistics | Metric | Value | |--------|-------| | Total Records | 0 | | Records with box_id | 0 | | Records with location_id | 0 | | Indexed Columns | Id, operator_code, CP_full_code, date, box_id, location_id | | Storage Engine | InnoDB | | Charset | utf8mb4 | --- ## 🔐 Indexes | Index Name | Columns | Type | Purpose | |-----------|---------|------|---------| | PRIMARY | Id | Unique | Record identification | | idx_operator | operator_code | Regular | Find scans by operator | | idx_cp_code | CP_full_code | Regular | Find scans by CP code | | idx_date | date | Regular | Find scans by date range | | idx_box_id | box_id | Regular | Find scans in specific box | | idx_location_id | location_id | Regular | Find scans by location | --- ## 📝 Table Creation SQL ```sql CREATE TABLE IF NOT EXISTS scanfg_orders ( id INT AUTO_INCREMENT PRIMARY KEY, operator_code VARCHAR(50), CP_full_code VARCHAR(50), OC1_code VARCHAR(50), OC2_code VARCHAR(50), quality_code VARCHAR(10), date DATE, time TIME, approved_quantity INT DEFAULT 0, rejected_quantity INT DEFAULT 0, box_id BIGINT, -- NEW: Links to boxes_crates location_id BIGINT, -- NEW: Links to warehouse_locations created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, -- Foreign Keys FOREIGN KEY (box_id) REFERENCES boxes_crates(id) ON DELETE SET NULL, FOREIGN KEY (location_id) REFERENCES warehouse_locations(id) ON DELETE SET NULL, -- Indexes INDEX idx_operator (operator_code), INDEX idx_cp_code (CP_full_code), INDEX idx_date (date), INDEX idx_box_id (box_id), INDEX idx_location_id (location_id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; ``` --- ## 🎯 Features Enabled by Box Tracking Columns ### 1. **Box-Based Inventory Tracking** - Know exactly which scanned CP codes are in which box - Track box status (open/closed) with scan completion - Generate box contents reports ### 2. **Location-Based Inventory** - Locate all scans in a specific warehouse zone - Generate location usage reports - Track goods movement through warehouse ### 3. **Scan-to-Box Assignment** - Operator can assign scan to a box during FG scan entry - Supports quick box label printing workflow - Enables just-in-time box creation ### 4. **Quality Report by Location** - Analyze approval/rejection rates by warehouse location - Generate performance metrics by zone - Identify quality patterns by location ### 5. **Audit Trail Integration** - cp_location_history tracks box movements - Combined with scanfg_orders, full traceability available - Supports root cause analysis for quality issues --- ## ✅ Implementation Checklist - [x] box_id column added to scanfg_orders - [x] location_id column added to scanfg_orders - [x] Foreign key constraints established - [x] Indexes created for query performance - [x] Table structure verified in database - [x] Documentation created - [ ] Backend routes updated to populate box_id on scan - [ ] Backend routes updated to populate location_id on scan - [ ] Frontend form updated to select box during scan entry - [ ] Test scans with box assignment - [ ] Verify box_contents table reflects scanned items --- ## 🚀 Next Steps 1. **Update FG Scan Route** - Modify `/fg_scan` route to capture and store box_id 2. **Update Frontend Form** - Add box selection dropdown to scan entry form 3. **Create Box Assignment Logic** - Auto-link scans to selected box 4. **Test Box Tracking** - Verify data flow end-to-end 5. **Create Reports** - Build box inventory and location reports --- ## 📚 Related Documentation - [BOXES_IMPLEMENTATION_DETAILS.md](BOXES_IMPLEMENTATION_DETAILS.md) - Box feature implementation - [QUICK_BOX_CHECKPOINT_IMPLEMENTATION_COMPLETE.md](QUICK_BOX_CHECKPOINT_IMPLEMENTATION_COMPLETE.md) - Box checkpoint workflow - [DATABASE_SCHEMA_ANALYSIS.md](DATABASE_SCHEMA_ANALYSIS.md) - Full schema analysis --- ## 🔧 Maintenance Notes ### Backup Considerations - Include scanfg_orders in daily backups - Maintain referential integrity with boxes_crates - Archive old scans periodically ### Performance Tuning - For 100,000+ records, consider partitioning by date - Monitor index usage on date, box_id, location_id - Vacuum/optimize table after large delete operations ### Data Consistency - Ensure box_id is valid before insert (FK constraint enforces this) - Handle orphaned scans gracefully (FK SET NULL allows this) - Regular integrity checks: `CHECK TABLE scanfg_orders;`