-- ===================================================== -- 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 -- =====================================================