- Strip emojis from 47 markdown files across docs/, sql/, and root - Add docs/DOCS_CONSOLIDATION_PLAN.md with plan to reduce 45 docs to 8 - Establish no-emoji rule for documentation going forward 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
18 KiB
Views Migration Analysis - Phase 2 Schema
Date: 2025-11-20 Critical Finding: 24 out of 27 views require updates for Phase 2 schema Impact: HIGH - Views will break after PC migration if not updated
Executive Summary
Your production database has 27 views that provide critical reporting and data aggregation. After analyzing these views:
- 24 views MUST be updated - They reference deprecated tables (pc, pc_network_interfaces, etc.)
- 3 views OK - Already compatible with Phase 2 schema
- CRITICAL: These views must be updated BEFORE or DURING migration, or pages using them will break
Views Status Breakdown
Views Compatible with Phase 2 (3 views)
These views don't reference deprecated tables and will continue working after migration:
- vw_machinetype_comparison - Compares machine types between machines and models
- vw_unmapped_machines - Finds machines without map coordinates
- vw_network_devices - Already updated to query machines table (from our Nov 13 work!)
Views Requiring Updates (24 views)
All of these reference tables that will be deprecated after Phase 2 migration:
Category 1: PC-Focused Views (12 views)
Views that query the pc and pctype tables directly:
-
vw_active_pcs - Active PCs updated in last 30 days
- References:
pc,pctype - Used by: displaypcs.asp (probably)
- Fix: Query
machines WHERE pctypeid IS NOT NULL
- References:
-
vw_engineer_pcs - Engineer workstations
- References:
pc,pctype - Fix: Query
machines WHERE pctypeid IN (SELECT pctypeid FROM pctype WHERE typename='Engineer')
- References:
-
vw_shopfloor_pcs - Shop floor PCs
- References:
pc,pctype - Fix: Query
machines WHERE pctypeid IS NOT NULLand filter by type
- References:
-
vw_standard_pcs - Standard workstations
- References:
pc,pctype - Fix: Query
machines WHERE pctypeid IN (SELECT pctypeid FROM pctype WHERE typename='Standard')
- References:
-
vw_pc_summary - PC inventory summary
- References:
pc,pctype - Fix: Query
machines WHERE pctypeid IS NOT NULL
- References:
-
vw_pcs_by_hardware - PC counts by hardware configuration
- References:
pc,pctype - Fix: Query
machines WHERE pctypeid IS NOT NULLgroup by vendor/model
- References:
-
vw_vendor_summary - PC counts by manufacturer
- References:
pc,pctype - Fix: Query
machines WHERE pctypeid IS NOT NULLgroup by vendor
- References:
-
vw_recent_updates - Recently updated PCs
- References:
pc,pctype - Fix: Query
machines WHERE pctypeid IS NOT NULL ORDER BY lastupdated
- References:
-
vw_pc_resolved_machines - PCs mapped to machines
- References:
pc - Fix: Query
machines WHERE pctypeid IS NOT NULL
- References:
-
vw_machine_type_stats - Machine type statistics
- References:
pc - Fix: Include PCs from machines table
- References:
-
vw_shopfloor_applications_summary - Application deployment summary
- References:
pc - Fix: Join to
machines WHERE pctypeid IS NOT NULL
- References:
-
vw_ge_machines - Machines with assigned PCs
- References:
pc,pctype - Fix: Query
machines WHERE pctypeid IS NOT NULLand join to machines (equipment)
- References:
Category 2: Network Interface Views (2 views)
Views that query pc_network_interfaces:
-
vw_pc_network_summary - PC network configuration summary
- References:
pc,pc_network_interfaces,pctype - Fix: Query
machinesandcommunicationstables - Example Change:
-- OLD: FROM pc p JOIN pc_network_interfaces pni ON p.pcid = pni.pcid -- NEW: FROM machines m JOIN communications c ON m.machineid = c.machineid WHERE m.pctypeid IS NOT NULL
- References:
-
vw_pctype_config - PC type configuration summary
- References:
pctype, references pc_network_interfaces in subquery - Fix: Query machines grouped by pctypeid, join to communications
- References:
Category 3: DNC Configuration Views (2 views)
Views that query pc_dnc_config:
-
vw_dnc_config - DNC configuration for all PCs
- References:
pc,pc_dnc_config - Fix: This data may need to be migrated to a new table or embedded in machine relationships
- Status: NEEDS DESIGN DECISION - Where does DNC config go in Phase 2?
- References:
-
vw_shopfloor_comm_config - Shop floor communication configuration
- References:
pc,pc_comm_config,pctype - Fix: Query
communicationstable with comstypeid for different comm types
- References:
Category 4: Dualpath Views (3 views)
Views that query pc_dualpath_assignments:
-
vw_dualpath_management - Dualpath configuration management
- References:
pc,pctype,pc_dnc_config,pc_dualpath_assignments - Fix: Query
machinerelationships WHERE relationshiptypeid = 2(Dualpath) - Example Change:
-- OLD: FROM pc p JOIN pc_dualpath_assignments dpa ON p.pcid = dpa.pcid -- NEW: FROM machines m JOIN machinerelationships mr ON m.machineid = mr.machineid JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid WHERE m.pctypeid IS NOT NULL AND rt.relationshiptype = 'Dualpath'
- References:
-
vw_machine_assignments - Machine to PC assignments
- References:
pc,pc_dualpath_assignments - Fix: Query
machinerelationshipsfor both primary and dualpath assignments
- References:
-
vw_multi_pc_machines - Machines with multiple PC assignments
- References:
pc - Fix: Query
machinesandmachinerelationshipswhere multiple PCs control same equipment
- References:
Category 5: Machine Assignment Views (1 view)
- vw_machine_assignment_status - Machine assignment status
- References:
pc,pctype,pc_dnc_config - Fix: Complex view needing updates to join machines table with pctypeid filter
- References:
Category 6: Warranty Views (2 views)
Views that track PC warranties:
-
vw_warranties_expiring - Warranties expiring soon
- References:
pc,pctype - Fix: Query
machinesandwarrantiestables where pctypeid IS NOT NULL
- References:
-
vw_warranty_status - Overall warranty status
- References:
pc,pctype(based on pattern) - Fix: Query
machinesandwarrantiestables
- References:
Category 7: Infrastructure Views (2 views)
Views that query network device tables:
-
vw_idf_inventory - IDF inventory with camera counts
- References:
idfs,cameras - Fix: Query
machines WHERE machinetypeid IN (17, 18)for IDFs and Cameras - Note: IDFs = machinetypeid 17, Cameras = machinetypeid 18
- References:
-
vw_infrastructure_summary - Infrastructure device counts
- References:
switches,accesspoints,servers,cameras,idfs - Fix: Query
machines WHERE machinetypeid IN (16,17,18,19,20) - Example Change:
-- OLD: SELECT 'Switches' AS device_type, COUNT(*) FROM switches UNION ALL SELECT 'Access Points', COUNT(*) FROM accesspoints -- NEW: SELECT mt.machinetype AS device_type, COUNT(*) AS total_count FROM machines m JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid WHERE mt.machinetypeid IN (16,17,18,19,20) GROUP BY mt.machinetype
- References:
Migration Strategy for Views
Option 1: Drop and Recreate All Views (RECOMMENDED)
Approach:
- Extract all current view definitions from production
- Update each view definition for Phase 2 schema
- During migration:
- DROP all 24 views that need updates
- CREATE updated views with Phase 2 schema
- Keep 3 compatible views as-is
Pros:
- Clean migration
- All views updated at once
- Easy to test before migration
Cons:
- Brief moment where views don't exist (during migration window)
- Requires updating all 24 views
Option 2: Create Views During Migration
Approach:
- Keep old tables as legacy (pc, pc_network_interfaces, etc.)
- Keep old views working during transition
- Create NEW views with "_v2" suffix for Phase 2 schema
- Update ASP pages to use new views
- After 30 days, drop old tables and old views
Pros:
- Zero downtime for views
- Gradual transition
- Can compare old vs new view results
Cons:
- Duplicate views (_v2 versions)
- Old tables must be kept (taking up space)
- More complex migration
Option 3: Hybrid Views (Query Both Old and New)
Approach: Create views that UNION data from both old and new tables during transition period.
Example:
CREATE VIEW vw_active_pcs AS
-- Get PCs from machines table (new Phase 2)
SELECT
m.machineid AS pcid,
m.hostname,
m.serialnumber,
...
FROM machines m
WHERE m.pctypeid IS NOT NULL
AND m.lastupdated > DATE_SUB(NOW(), INTERVAL 30 DAY)
UNION ALL
-- Get PCs from legacy pc table (if any remain)
SELECT
p.pcid,
p.hostname,
p.serialnumber,
...
FROM pc p
WHERE p.lastupdated > DATE_SUB(NOW(), INTERVAL 30 DAY)
AND NOT EXISTS (
SELECT 1 FROM machines m
WHERE m.hostname = p.hostname AND m.pctypeid IS NOT NULL
);
Pros:
- Works during transition
- No duplicate view names
- Handles mixed data scenarios
Cons:
- More complex queries
- Slower performance (UNION)
- Must remove legacy portions after migration complete
Recommended Approach
Use Option 1: Drop and Recreate
Reasoning:
- You're doing a full Phase 2 migration - commit to it fully
- Migration window is already scheduled for table changes
- Cleaner long-term solution
- Easier to test and validate
- All pages will use consistent schema
Migration Steps:
- Before migration: Test all updated views on dev database
- During migration:
- After data migration completes
- DROP all 24 old views
- CREATE all 24 updated views
- After migration: Test all pages that use views
Views Migration Checklist
Pre-Migration (Dev Testing)
- Extract all 27 view definitions from production
- Update 24 view definitions for Phase 2 schema
- Test updated views on dev database
- Identify which ASP pages use which views
- Test all pages that use views
During Migration
- Backup all view definitions (already in backup file)
- After PC data migration completes
- DROP 24 views requiring updates
- CREATE 24 updated views
- Run verification queries
- Test critical pages
Post-Migration
- Monitor view performance
- Check all pages using views
- Update documentation
- Remove old table references from any remaining code
Impact on ASP Pages
Views are typically used in these types of pages:
- Display/List Pages - displaypcs.asp, displaymachines.asp
- Dashboard Pages - default.asp, reports.asp
- Search Pages - search.asp
- API Endpoints - api_*.asp pages
Action Required:
- Identify all ASP pages that query views
- Test each page after view migration
- Update any pages that break
DNC Configuration Migration (Special Case)
Problem: Views reference pc_dnc_config and pc_comm_config tables
Question: Where does this data go in Phase 2?
Options:
- Create new tables:
machine_dnc_config(similar structure) - Use communications table: Store DNC settings in
settingsJSON field - Use compliance table: If DNC is compliance-related
- Keep legacy tables: Don't migrate DNC config yet (Phase 3?)
Recommendation: Keep pc_dnc_config and pc_comm_config tables for now (Phase 3 migration). Update views to join machines table instead of pc table.
Sample View Conversions
Example 1: vw_active_pcs
OLD (Production):
CREATE VIEW vw_active_pcs AS
SELECT
p.pcid,
p.hostname,
p.serialnumber,
COALESCE(v.vendor, 'Unknown') AS manufacturer,
m.modelnumber AS model,
p.loggedinuser,
p.machinenumber,
COALESCE(os.operatingsystem, 'Unknown') AS operatingsystem,
COALESCE(pt.typename, 'Unknown') AS pctype,
p.lastupdated
FROM pc p
LEFT JOIN models m ON p.modelnumberid = m.modelnumberid
LEFT JOIN vendors v ON m.vendorid = v.vendorid
LEFT JOIN pctype pt ON p.pctypeid = pt.pctypeid
LEFT JOIN operatingsystems os ON p.osid = os.osid
WHERE p.lastupdated > DATE_SUB(NOW(), INTERVAL 30 DAY);
NEW (Phase 2):
CREATE VIEW vw_active_pcs AS
SELECT
m.machineid AS pcid,
m.hostname,
m.serialnumber,
COALESCE(v.vendor, 'Unknown') AS manufacturer,
mo.modelnumber AS model,
m.loggedinuser,
m.machinenumber,
COALESCE(os.operatingsystem, 'Unknown') AS operatingsystem,
COALESCE(pt.typename, 'Unknown') AS pctype,
m.lastupdated
FROM machines m
LEFT JOIN models mo ON m.modelnumberid = mo.modelnumberid
LEFT JOIN vendors v ON mo.vendorid = v.vendorid
LEFT JOIN pctype pt ON m.pctypeid = pt.pctypeid
LEFT JOIN operatingsystems os ON m.osid = os.osid
WHERE m.pctypeid IS NOT NULL -- Only PCs
AND m.lastupdated > DATE_SUB(NOW(), INTERVAL 30 DAY);
Changes:
FROM pc p→FROM machines m- Added
WHERE m.pctypeid IS NOT NULLto filter PCs only m.modelnumberidalias changed tomoto avoid conflict
Example 2: vw_dualpath_management
OLD (Production):
CREATE VIEW vw_dualpath_management AS
SELECT
p.hostname AS pc_hostname,
p.pcid,
pt.typename AS pc_type,
p.machinenumber AS primary_machine,
dc.dualpath_enabled,
dpa.secondary_machine
FROM pc p
JOIN pctype pt ON p.pctypeid = pt.pctypeid
LEFT JOIN pc_dnc_config dc ON p.pcid = dc.pcid
LEFT JOIN pc_dualpath_assignments dpa ON p.pcid = dpa.pcid
WHERE p.isactive = 1;
NEW (Phase 2):
CREATE VIEW vw_dualpath_management AS
SELECT
m.hostname AS pc_hostname,
m.machineid AS pcid,
pt.typename AS pc_type,
m.machinenumber AS primary_machine,
dc.dualpath_enabled,
m2.machinenumber AS secondary_machine
FROM machines m
JOIN pctype pt ON m.pctypeid = pt.pctypeid
LEFT JOIN pc_dnc_config dc ON m.machineid = dc.pcid -- Note: keep legacy table for now
LEFT JOIN machinerelationships mr ON m.machineid = mr.machineid
AND mr.relationshiptypeid = 2 -- Dualpath relationship
LEFT JOIN machines m2 ON mr.related_machineid = m2.machineid
WHERE m.pctypeid IS NOT NULL
AND m.isactive = 1;
Changes:
FROM pc p→FROM machines m WHERE pctypeid IS NOT NULLpc_dualpath_assignments→machinerelationshipswith relationshiptype filter- Join to second machine using machinerelationships
Example 3: vw_infrastructure_summary
OLD (Production):
CREATE VIEW vw_infrastructure_summary AS
SELECT 'Switches' AS device_type, COUNT(*) AS total_count FROM switches
UNION ALL
SELECT 'Access Points', COUNT(*) FROM accesspoints
UNION ALL
SELECT 'Servers', COUNT(*) FROM servers
UNION ALL
SELECT 'Cameras', COUNT(*) FROM cameras
UNION ALL
SELECT 'IDFs', COUNT(*) FROM idfs;
NEW (Phase 2):
CREATE VIEW vw_infrastructure_summary AS
-- Network devices from machines table (Phase 2)
SELECT
mt.machinetype AS device_type,
COUNT(*) AS total_count,
SUM(CASE WHEN m.isactive = 1 THEN 1 ELSE 0 END) AS active_count
FROM machines m
JOIN machinetypes mt ON m.machinetypeid = mt.machinetypeid
WHERE mt.machinetypeid IN (16, 17, 18, 19, 20) -- Network device types
GROUP BY mt.machinetype
UNION ALL
-- Legacy devices from separate tables (if any remain)
SELECT 'Switches' AS device_type, COUNT(*) AS total_count,
SUM(CASE WHEN isactive = 1 THEN 1 ELSE 0 END) AS active_count
FROM switches
UNION ALL
SELECT 'Access Points', COUNT(*), SUM(CASE WHEN isactive = 1 THEN 1 ELSE 0 END) FROM accesspoints
UNION ALL
SELECT 'Servers', COUNT(*), SUM(CASE WHEN isactive = 1 THEN 1 ELSE 0 END) FROM servers
UNION ALL
SELECT 'Cameras', COUNT(*), SUM(CASE WHEN isactive = 1 THEN 1 ELSE 0 END) FROM cameras
UNION ALL
SELECT 'IDFs', COUNT(*), SUM(CASE WHEN isactive = 1 THEN 1 ELSE 0 END) FROM idfs;
Changes:
- Query machines table where machinetypeid IN (16,17,18,19,20)
- Keep legacy table queries in UNION for transition period
- Group by machinetype from machinetypes table
Critical Decision Points
1. DNC Configuration Tables
Decision Needed: Migrate pc_dnc_config now or later?
- Option A: Keep for Phase 3, update views to join machines instead of pc
- Option B: Migrate now to new table structure
2. View Migration Timing
Decision Needed: When to update views?
- During migration: As part of Phase 2 deployment
- Before migration: Create _v2 versions for testing
- After migration: Update after verifying data migrated correctly
3. Legacy Network Device Tables
Decision Needed: Keep empty legacy tables?
- Keep: For backward compatibility (until Phase 3)
- Drop: Clean up unused tables now
Next Steps
- Review this analysis with team
- Make decisions on DNC config and migration timing
- Create updated view definitions for all 24 views
- Test views on dev database with Phase 2 schema
- Add view migration to production deployment plan
- Update PRODUCTION_MIGRATION_PLAN.md to include views
Files to Create
/sql/production_migration/views/01_drop_old_views.sql- DROP old views/sql/production_migration/views/02_create_pc_views.sql- Create updated PC views/sql/production_migration/views/03_create_network_views.sql- Create updated network views/sql/production_migration/views/04_create_relationship_views.sql- Create updated relationship views/sql/production_migration/views/05_create_infrastructure_views.sql- Create updated infrastructure views/sql/production_migration/views/06_verify_views.sql- Verify all views work
Status: Analysis Complete - Awaiting Decisions Priority: HIGH - Views must be updated for Phase 2 to work Risk: MEDIUM - Views can be recreated if issues occur Estimated Time: 4-6 hours to update all 24 views + testing