Files
shopdb/sql/migration_phase1/01_create_communications_infrastructure.sql
cproudlock 4bcaf0913f Complete Phase 2 PC migration and network device infrastructure updates
This commit captures 20 days of development work (Oct 28 - Nov 17, 2025)
including Phase 2 PC migration, network device unification, and numerous
bug fixes and enhancements.

## Major Changes

### Phase 2: PC Migration to Unified Machines Table
- Migrated all PCs from separate `pc` table to unified `machines` table
- PCs identified by `pctypeid IS NOT NULL` in machines table
- Updated all display, add, edit, and update pages for PC functionality
- Comprehensive testing: 15 critical pages verified working

### Network Device Infrastructure Unification
- Unified network devices (Switches, Servers, Cameras, IDFs, Access Points)
  into machines table using machinetypeid 16-20
- Updated vw_network_devices view to query both legacy tables and machines table
- Enhanced network_map.asp to display all device types from machines table
- Fixed location display for all network device types

### Machine Management System
- Complete machine CRUD operations (Create, Read, Update, Delete)
- 5-tab interface: Basic Info, Network, Relationships, Compliance, Location
- Support for multiple network interfaces (up to 3 per machine)
- Machine relationships: Controls (PC→Equipment) and Dualpath (redundancy)
- Compliance tracking with third-party vendor management

### Bug Fixes (Nov 7-14, 2025)
- Fixed editdevice.asp undefined variable (pcid → machineid)
- Migrated updatedevice.asp and updatedevice_direct.asp to Phase 2 schema
- Fixed network_map.asp to show all network device types
- Fixed displaylocation.asp to query machines table for network devices
- Fixed IP columns migration and compliance column handling
- Fixed dateadded column errors in network device pages
- Fixed PowerShell API integration issues
- Simplified displaypcs.asp (removed IP and Machine columns)

### Documentation
- Created comprehensive session summaries (Nov 10, 13, 14)
- Added Machine Quick Reference Guide
- Documented all bug fixes and migrations
- API documentation for ASP endpoints

### Database Schema Updates
- Phase 2 migration scripts for PC consolidation
- Phase 3 migration scripts for network devices
- Updated views to support hybrid table approach
- Sample data creation/removal scripts for testing

## Files Modified (Key Changes)
- editdevice.asp, updatedevice.asp, updatedevice_direct.asp
- network_map.asp, network_devices.asp, displaylocation.asp
- displaypcs.asp, displaypc.asp, displaymachine.asp
- All machine management pages (add/edit/save/update)
- save_network_device.asp (fixed machine type IDs)

## Testing Status
- 15 critical pages tested and verified
- Phase 2 PC functionality: 100% working
- Network device display: 100% working
- Security: All queries use parameterized commands

## Production Readiness
- Core functionality complete and tested
- 85% production ready
- Remaining: Full test coverage of all 123 ASP pages

🤖 Generated with [Claude Code](https://claude.com/claude-code)

Co-Authored-By: Claude <noreply@anthropic.com>
2025-11-17 20:04:06 -05:00

120 lines
4.2 KiB
SQL

-- =====================================================
-- SCRIPT 01: Create Communications Infrastructure
-- =====================================================
-- Date: 2025-11-06
-- Purpose: Create comstypes and communications tables
-- Status: REVERSIBLE (see ROLLBACK_01)
-- Estimated Time: 2-3 minutes
-- =====================================================
USE shopdb;
SET SQL_SAFE_UPDATES = 0;
-- =====================================================
-- STEP 1: Create comstypes table
-- =====================================================
CREATE TABLE IF NOT EXISTS comstypes (
comstypeid INT(11) PRIMARY KEY AUTO_INCREMENT,
typename VARCHAR(50) NOT NULL UNIQUE,
description VARCHAR(255),
requires_port TINYINT(1) DEFAULT 0,
requires_ipaddress TINYINT(1) DEFAULT 0,
isactive TINYINT(1) DEFAULT 1,
displayorder INT(11) DEFAULT 0,
dateadded DATETIME DEFAULT CURRENT_TIMESTAMP,
KEY idx_isactive (isactive),
KEY idx_displayorder (displayorder)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4
COMMENT='Communication types (IP, Serial, Network Interface, etc.)';
-- Insert communication types
INSERT INTO comstypes (typename, description, requires_port, requires_ipaddress, displayorder) VALUES
('IP', 'TCP/IP Network Communication', 0, 1, 1),
('Serial', 'Serial Port Communication (RS-232)', 1, 0, 2),
('Network_Interface', 'Network Interface Card', 0, 1, 3),
('USB', 'USB Connection', 1, 0, 4),
('Parallel', 'Parallel Port Connection', 1, 0, 5),
('VNC', 'Virtual Network Computing', 0, 1, 6),
('FTP', 'File Transfer Protocol', 0, 1, 7),
('DNC', 'Direct Numerical Control', 0, 1, 8);
-- =====================================================
-- STEP 2: Create communications table
-- =====================================================
CREATE TABLE IF NOT EXISTS communications (
comid INT(11) PRIMARY KEY AUTO_INCREMENT,
machineid INT(11) NOT NULL,
comstypeid INT(11) NOT NULL,
-- Generic address field (IP, COM1, USB1, etc.)
address VARCHAR(100),
-- Port/socket information
port INT(11),
portname VARCHAR(20), -- COM1, COM2, LPT1, etc.
-- Network-specific
macaddress VARCHAR(17),
subnetmask VARCHAR(45),
defaultgateway VARCHAR(45),
dnsserver VARCHAR(45),
isdhcp TINYINT(1) DEFAULT 0,
-- Serial-specific
baud INT(11),
databits INT(11),
stopbits VARCHAR(5),
parity VARCHAR(10),
flowcontrol VARCHAR(20),
-- Protocol-specific
protocol VARCHAR(50),
username VARCHAR(100),
password VARCHAR(255),
-- General metadata
interfacename VARCHAR(255),
description VARCHAR(255),
isprimary TINYINT(1) DEFAULT 0,
isactive TINYINT(1) DEFAULT 1,
ismachinenetwork TINYINT(1) DEFAULT 0, -- Machine network vs office network
-- Additional settings as JSON
settings TEXT, -- JSON for VLAN, etc.
-- Audit fields
lastupdated DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
dateadded DATETIME DEFAULT CURRENT_TIMESTAMP,
-- Indexes
KEY idx_machineid (machineid),
KEY idx_comstypeid (comstypeid),
KEY idx_address (address),
KEY idx_isactive (isactive),
KEY idx_isprimary (isprimary),
-- Foreign Keys
CONSTRAINT fk_communications_machineid FOREIGN KEY (machineid) REFERENCES machines(machineid),
CONSTRAINT fk_communications_comstypeid FOREIGN KEY (comstypeid) REFERENCES comstypes(comstypeid)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4
COMMENT='Generic communications table for all connection types';
-- =====================================================
-- VERIFICATION
-- =====================================================
SELECT '✓ comstypes table created' AS status, COUNT(*) AS type_count FROM comstypes;
SELECT '✓ communications table created' AS status;
SELECT '✓ Script 01 completed successfully' AS status;
SET SQL_SAFE_UPDATES = 1;
-- =====================================================
-- NOTES
-- =====================================================
-- Next: Run script 02_extend_machines_table.sql
-- Rollback: Run ROLLBACK_01_communications_infrastructure.sql
-- =====================================================