# ShopDB API (ASP) - PowerShell Data Collection Endpoint **File:** `api.asp` **Created:** 2025-11-13 **Purpose:** Receive PC asset data from PowerShell scripts and store in Phase 2 schema **Schema:** Phase 2 (machines, communications, machinerelationships) --- ## Overview This ASP API replaces the PHP api.php and provides the same functionality but runs on IIS with the ShopDB ASP application. It's designed to work with Phase 2 schema from day one. **Key Features:** - Uses Phase 2 schema (machines, communications) - Parameterized queries (SQL injection protection) - JSON request/response handling - Automatic vendor/model/pctype creation - PC-to-equipment relationship management - Network interface tracking - DNC configuration storage - Warranty data management - Application tracking --- ## Endpoints ### 1. `updateCompleteAsset` **Purpose:** Main endpoint for PowerShell data collection **Method:** POST **Parameters:** **Basic PC Info (Required):** - `hostname` - PC hostname - `serialNumber` - Serial number - `manufacturer` - Manufacturer (e.g., "Dell", "HP") - `model` - Model name - `pcType` - PC type ("Engineer", "Shopfloor", "Standard") **Basic PC Info (Optional):** - `loggedInUser` - Current logged in user - `machineNo` - Machine number (for shopfloor PCs) - `osVersion` - Operating system version **Warranty Info (Optional):** - `warrantyEndDate` - Warranty end date (YYYY-MM-DD) - `warrantyStatus` - Status ("Active", "Expired", etc.) - `warrantyServiceLevel` - Service level description - `warrantyDaysRemaining` - Days until warranty expires **Shopfloor Data (Optional):** - `networkInterfaces` - JSON array of network interfaces - `commConfigs` - JSON array of serial port configs - `dncConfig` - JSON object with DNC configuration **DNC/GE Registry Data (Optional):** - `dncDualPathEnabled` - Boolean (true/false) - `dncPath1Name` - Path 1 name - `dncPath2Name` - Path 2 name - `dncGeRegistry32Bit` - Boolean for 32-bit registry - `dncGeRegistry64Bit` - Boolean for 64-bit registry - `dncGeRegistryNotes` - Registry notes **Response:** ```json { "success": true, "message": "PC asset data updated successfully", "machineid": 123, "hostname": "PC-NAME", "operation": "complete", "data": { "networkInterfaces": 3, "commConfigs": 2, "dncConfig": true, "relationshipCreated": true } } ``` **Database Operations:** 1. Insert/update record in `machines` table with `pctypeid IS NOT NULL` 2. Clear old network interfaces from `communications` 3. Insert new network interfaces to `communications` with `comstypeid = 1` 4. Clear old serial port configs from `commconfig` 5. Insert new serial port configs to `commconfig` 6. Clear old DNC config from `dncconfig` 7. Insert new DNC config to `dncconfig` 8. Create PC-to-equipment relationship in `machinerelationships` if `machineNo` provided 9. Update warranty data in `warranties` table --- ### 2. `updatePrinterMapping` **Purpose:** Map a PC to its default printer **Method:** POST **Parameters:** - `hostname` - PC hostname - `printerFQDN` - Printer FQDN or IP address **Response:** ```json { "success": true, "message": "Printer mapping updated", "data": { "printerId": 45, "machinesUpdated": 1, "matchMethod": "ip" } } ``` **Database Operations:** 1. Find PC by hostname in `machines` table 2. Find printer by FQDN (tries name match, then IP match) 3. Update `machines.printerid` to link PC to printer --- ### 3. `updateInstalledApps` **Purpose:** Update installed applications for a PC **Method:** POST **Parameters:** - `hostname` - PC hostname - `installedApps` - JSON array of applications **installedApps Format:** ```json [ {"Name": "SolidWorks 2024", "Version": "32.1.0"}, {"Name": "AutoCAD", "Version": "2024.1"}, {"Name": "Microsoft Office", "Version": "16.0"} ] ``` **Response:** ```json { "success": true, "message": "Installed applications updated", "data": { "appsProcessed": 3 } } ``` **Database Operations:** 1. Find PC by hostname in `machines` table 2. Delete existing app mappings from `machineapplications` 3. Create applications in `applications` table if they don't exist 4. Insert new app mappings to `machineapplications` --- ### 4. `getDashboardData` **Purpose:** Health check / connection test **Method:** GET or POST **Parameters:** None **Response:** ```json { "success": true, "message": "ShopDB API is online", "version": "1.0", "schema": "Phase 2" } ``` --- ### 5. `getShopfloorPCs` **Purpose:** Returns list of all active shopfloor PCs for remote management **Method:** GET **Parameters:** None **Response:** ```json { "success": true, "count": 25, "pcs": [ { "machineid": 123, "hostname": "SHOPFLOOR-PC-01", "machinenumber": "2001", "serialnumber": "ABC123", "loggedinuser": "jsmith", "lastupdated": "2025-12-11 10:30:00", "ipaddress": "10.134.100.50", "pctype": "Shopfloor" } ] } ``` --- ### 6. `getRecordedIP` **Purpose:** Look up recorded primary IP (10.134.*) for a hostname **Method:** POST **Parameters:** - `hostname` - PC hostname **Response:** ```json { "success": true, "hostname": "SHOPFLOOR-PC-01", "ipaddress": "10.134.100.50" } ``` --- ### 7. `updateWinRMStatus` **Purpose:** Update WinRM enabled status for a PC **Method:** POST or GET **Parameters:** - `hostname` - PC hostname - `hasWinRM` - "1" or "0" (defaults to 1 if not specified) **Response:** ```json { "success": true, "message": "WinRM status updated", "hostname": "SHOPFLOOR-PC-01", "haswinrm": 1 } ``` --- ### 8. `updateMachinePositions` **Purpose:** Bulk update machine map positions (used by map editor) **Method:** POST **Parameters:** - `changes` - JSON array of position changes **changes Format:** ```json [ {"id": 123, "newLeft": 450, "newTop": 200}, {"id": 124, "newLeft": 500, "newTop": 250} ] ``` **Response:** ```json { "success": true, "message": "Updated 2 machine positions", "updated": 2, "errors": 0 } ``` --- ## JSON Formats ### Network Interfaces Format ```json [ { "IPAddress": "10.48.130.100", "MACAddress": "00:1A:2B:3C:4D:5E", "SubnetMask": "255.255.255.0", "DefaultGateway": "10.48.130.1", "InterfaceName": "Ethernet", "IsMachineNetwork": false }, { "IPAddress": "192.168.1.100", "MACAddress": "00:1A:2B:3C:4D:5F", "SubnetMask": "255.255.255.0", "DefaultGateway": "192.168.1.1", "InterfaceName": "Machine Network", "IsMachineNetwork": true } ] ``` **Stored in:** `communications` table - `comstypeid = 1` (Network Interface) - First interface with valid IP marked as `isprimary = 1` --- ### Communication Configs Format (Serial Ports) ```json [ { "PortName": "COM1", "BaudRate": 9600, "DataBits": 8, "Parity": "None", "StopBits": "One", "FlowControl": "None" }, { "PortName": "COM2", "BaudRate": 19200, "DataBits": 8, "Parity": "Even", "StopBits": "One", "FlowControl": "Hardware" } ] ``` **Stored in:** `commconfig` table --- ### DNC Config Format ```json { "Site": "West Jefferson", "CNC": "FANUC", "NCIF": "eFOCAS", "MachineNumber": "2001", "HostType": "Control", "FTPHostPrimary": "192.168.1.100", "FTPHostSecondary": "192.168.1.101", "FTPAccount": "dnc_user", "Debug": "Off", "Uploads": "C:\\DNC\\Uploads", "Scanner": "On", "DripFeed": "Off", "AdditionalSettings": "timeout=30" } ``` **Stored in:** `dncconfig` table **Additional DNC fields sent as separate parameters:** - `dncDualPathEnabled` - true/false - `dncPath1Name` - Path 1 name - `dncPath2Name` - Path 2 name - `dncGeRegistry32Bit` - true/false - `dncGeRegistry64Bit` - true/false - `dncGeRegistryNotes` - Text notes --- ## Database Schema ### Tables Used #### machines (Main PC Storage) ```sql CREATE TABLE machines ( machineid INT(11) PRIMARY KEY AUTO_INCREMENT, hostname VARCHAR(100), serialnumber VARCHAR(50), modelnumberid INT(11), pctypeid INT(11), -- NOT NULL = PC, NULL = Equipment machinetypeid INT(11), -- 28-32 for PC types loggedinuser VARCHAR(100), machinenumber VARCHAR(50), -- For shopfloor PCs osid INT(11), machinestatusid INT(11), machinenotes TEXT, printerid INT(11), -- Default printer isactive TINYINT(1), lastupdated DATETIME ); ``` #### communications (Network Interfaces) ```sql CREATE TABLE communications ( comid INT(11) PRIMARY KEY AUTO_INCREMENT, machineid INT(11), comstypeid INT(11), -- 1 = Network Interface address VARCHAR(45), -- IP address macaddress VARCHAR(17), subnetmask VARCHAR(45), defaultgateway VARCHAR(45), interfacename VARCHAR(50), isprimary TINYINT(1), isactive TINYINT(1) ); ``` #### commconfig (Serial Port Configs) ```sql CREATE TABLE commconfig ( configid INT(11) PRIMARY KEY AUTO_INCREMENT, machineid INT(11), configtype VARCHAR(50), portid VARCHAR(20), baud INT(11), databits INT(11), parity VARCHAR(10), stopbits VARCHAR(5), ipaddress VARCHAR(45), socketnumber INT(11), additionalsettings TEXT, lastupdated DATETIME ); ``` #### dncconfig (DNC Configuration) ```sql CREATE TABLE dncconfig ( dncid INT(11) PRIMARY KEY AUTO_INCREMENT, machineid INT(11), site VARCHAR(100), cnc VARCHAR(100), ncif VARCHAR(50), machinenumber VARCHAR(50), hosttype VARCHAR(50), ftphostprimary VARCHAR(100), ftphostsecondary VARCHAR(100), ftpaccount VARCHAR(100), debug VARCHAR(10), uploads VARCHAR(10), scanner VARCHAR(10), dripfeed VARCHAR(10), additionalsettings TEXT, dualpath_enabled TINYINT(1), path1_name VARCHAR(255), path2_name VARCHAR(255), ge_registry_32bit TINYINT(1), ge_registry_64bit TINYINT(1), ge_registry_notes TEXT, lastupdated DATETIME ); ``` #### machinerelationships (PC-to-Equipment Links) ```sql CREATE TABLE machinerelationships ( relationshipid INT(11) PRIMARY KEY AUTO_INCREMENT, machineid INT(11), -- Equipment ID related_machineid INT(11), -- PC ID relationshiptypeid INT(11), -- 3 = Controls isactive TINYINT(1) ); ``` #### warranties (Warranty Tracking) ```sql CREATE TABLE warranties ( warrantyid INT(11) PRIMARY KEY AUTO_INCREMENT, machineid INT(11), enddate DATE, servicelevel VARCHAR(100), status VARCHAR(50), daysremaining INT(11), lastcheckeddate DATETIME ); ``` #### machineapplications (Installed Applications) ```sql CREATE TABLE machineapplications ( machineappid INT(11) PRIMARY KEY AUTO_INCREMENT, machineid INT(11), applicationid INT(11) ); ``` --- ## Automatic Lookups The API automatically creates records in these tables if they don't exist: ### vendors - Created when new manufacturer is encountered - Lookup: `SELECT vendorid FROM vendors WHERE vendor = ?` - Create: `INSERT INTO vendors (vendor) VALUES (?)` ### models - Created when new model is encountered for a vendor - Lookup: `SELECT modelnumberid FROM models WHERE modelnumber = ? AND vendorid = ?` - Create: `INSERT INTO models (modelnumber, vendorid, notes, isactive) VALUES (?, ?, 'Auto-imported via PowerShell', 1)` ### pctype - Created when new PC type is encountered - Lookup: `SELECT pctypeid FROM pctype WHERE typename = ?` - Create: `INSERT INTO pctype (typename) VALUES (?)` ### operatingsystems - Created when new OS version is encountered - Lookup: `SELECT osid FROM operatingsystems WHERE osname = ?` - Create: `INSERT INTO operatingsystems (osname) VALUES (?)` ### applications - Created when new application is encountered - Lookup: `SELECT applicationid FROM applications WHERE applicationname = ?` - Create: `INSERT INTO applications (applicationname, version) VALUES (?, ?)` --- ## PC Type to Machine Type Mapping When creating PCs, `machinetypeid` is automatically determined from `pctypeid`: | PC Type Name | pctypeid | machinetypeid | Machine Type | |--------------|----------|---------------|--------------| | Engineer | varies | 30 | Workstation | | Shopfloor | varies | 28 | Desktop PC | | Standard | varies | 28 | Desktop PC | | Laptop | varies | 29 | Laptop | | Thin Client | varies | 31 | Thin Client | | Server | varies | 32 | Server | This mapping allows: - PCs to be filtered with `WHERE pctypeid IS NOT NULL` - PC-specific queries to join to `machinetypes` table - Unified reporting across PCs and equipment --- ## Error Responses All errors return HTTP 200 with JSON: ```json { "success": false, "error": "Error message here" } ``` **Common Errors:** - `"hostname and serialNumber are required"` - Missing required fields - `"PC not found: HOSTNAME"` - PC doesn't exist in database - `"Printer not found: FQDN"` - Printer not found by FQDN or IP - `"Failed to insert/update PC: SQL error"` - Database error - `"Invalid action: ACTION"` - Unknown action parameter --- ## Security Features ### SQL Injection Protection All queries use parameterized commands: ```asp Set cmd = Server.CreateObject("ADODB.Command") cmd.ActiveConnection = objConn cmd.CommandText = "SELECT machineid FROM machines WHERE hostname = ?" cmd.Parameters.Append cmd.CreateParameter("@hostname", 200, 1, 100, hostname) Set rsResult = cmd.Execute ``` ### Input Validation - Required field checks - Numeric validation for IDs - Boolean conversion for true/false values - String length limits enforced ### HTML/JSON Escaping - All JSON output properly escaped - Special characters handled: `\`, `"`, CR, LF, TAB --- ## Logging API logs to: `/logs/api.log` **Log Format:** `YYYY-MM-DD HH:MM:SS - Message` **Logged Events:** - New requests with hostname/serial/pctype - Vendor/Model/PCType ID lookups - Record creation (machineid) - Network interface insertion counts - Comm config insertion counts - DNC config insertion success - PC-Machine relationship creation - Errors with full error descriptions **Log Directory:** Must exist and be writable by IIS process --- ## PowerShell Integration ### Default URL Configuration PowerShell scripts should use: ```powershell $DashboardURL = "http://192.168.122.151:8080/api.asp" ``` ### Example PowerShell Call ```powershell $postData = @{ action = 'updateCompleteAsset' hostname = $env:COMPUTERNAME serialNumber = $serialNumber manufacturer = $manufacturer model = $model pcType = "Shopfloor" loggedInUser = $env:USERNAME machineNo = "2001" osVersion = $osVersion networkInterfaces = $networkInterfacesJSON commConfigs = $commConfigsJSON dncConfig = $dncConfigJSON dncDualPathEnabled = $true dncPath1Name = "Path1" dncPath2Name = "Path2" } $response = Invoke-RestMethod -Uri $DashboardURL -Method Post -Body $postData ``` --- ## Testing ### Test 1: Health Check ```bash curl "http://192.168.122.151:8080/api.asp?action=getDashboardData" ``` **Expected:** ```json {"success":true,"message":"ShopDB API is online","version":"1.0","schema":"Phase 2"} ``` ### Test 2: Create New PC ```powershell $postData = @{ action = 'updateCompleteAsset' hostname = 'TEST-PC-01' serialNumber = 'ABC123456' manufacturer = 'Dell' model = 'OptiPlex 7090' pcType = 'Standard' osVersion = 'Windows 11 Pro' } Invoke-RestMethod -Uri "http://192.168.122.151:8080/api.asp" -Method Post -Body $postData ``` **Verify in Database:** ```sql SELECT machineid, hostname, serialnumber, pctypeid, machinetypeid FROM machines WHERE hostname = 'TEST-PC-01' AND pctypeid IS NOT NULL; ``` ### Test 3: Update Existing PC with Network Interfaces ```powershell $networkInterfaces = @( @{ IPAddress = '10.48.130.100' MACAddress = '00:1A:2B:3C:4D:5E' SubnetMask = '255.255.255.0' DefaultGateway = '10.48.130.1' InterfaceName = 'Ethernet' } ) | ConvertTo-Json $postData = @{ action = 'updateCompleteAsset' hostname = 'TEST-PC-01' serialNumber = 'ABC123456' manufacturer = 'Dell' model = 'OptiPlex 7090' pcType = 'Standard' networkInterfaces = $networkInterfaces } Invoke-RestMethod -Uri "http://192.168.122.151:8080/api.asp" -Method Post -Body $postData ``` **Verify in Database:** ```sql SELECT c.comid, c.address, c.macaddress, c.isprimary FROM communications c JOIN machines m ON c.machineid = m.machineid WHERE m.hostname = 'TEST-PC-01' AND c.comstypeid = 1; ``` ### Test 4: Shopfloor PC with Machine Relationship ```powershell $postData = @{ action = 'updateCompleteAsset' hostname = 'SHOPFLOOR-PC' serialNumber = 'XYZ789' manufacturer = 'HP' model = 'EliteDesk 800' pcType = 'Shopfloor' machineNo = '2001' } Invoke-RestMethod -Uri "http://192.168.122.151:8080/api.asp" -Method Post -Body $postData ``` **Verify Relationship:** ```sql SELECT equipment.machinenumber AS equipment, pc.hostname AS controlling_pc FROM machinerelationships mr JOIN machines equipment ON mr.machineid = equipment.machineid JOIN machines pc ON mr.related_machineid = pc.machineid JOIN relationshiptypes rt ON mr.relationshiptypeid = rt.relationshiptypeid WHERE equipment.machinenumber = '2001' AND rt.relationshiptype = 'Controls'; ``` --- ## Deployment ### Step 1: Database Schema Update Run the migration script: ```bash mysql -h 192.168.122.1 -u root -p shopdb < sql/migration_phase2/08_update_schema_for_api.sql ``` This renames `pcid` → `machineid` in: - `commconfig` - `dncconfig` ### Step 2: Deploy api.asp Copy `api.asp` to ShopDB root directory: ```bash cp api.asp /home/camp/projects/windows/shopdb/ ``` ### Step 3: Create Logs Directory Ensure logs directory exists and is writable: ```bash mkdir -p /home/camp/projects/windows/shopdb/logs chmod 755 /home/camp/projects/windows/shopdb/logs ``` ### Step 4: Update PowerShell Scripts Change default dashboard URL in `Update-PC-CompleteAsset.ps1`: ```powershell # OLD: [string]$DashboardURL = "http://10.48.130.197/dashboard-v2/api.php" # NEW: [string]$DashboardURL = "http://192.168.122.151:8080/api.asp" ``` ### Step 5: Test Run PowerShell script on one test PC: ```powershell .\Update-PC-CompleteAsset.ps1 ``` Check logs: ```bash tail -f /home/camp/projects/windows/shopdb/logs/api.log ``` Verify in ShopDB: ``` http://192.168.122.151:8080/displaypcs.asp ``` --- ## Troubleshooting ### Issue: "Object required" error **Cause:** RegExp object not created properly **Fix:** Check that VBScript RegExp is enabled: ```asp Dim regex Set regex = New RegExp ``` ### Issue: "ADO error" when inserting **Cause:** Parameter type mismatch **Fix:** Verify parameter types match database column types: - VARCHAR: `200` (adVarChar) - INT: `3` (adInteger) - DATE: `135` (adDBDate) - TINYINT: `16` (adTinyInt) ### Issue: Network interfaces not appearing **Cause:** `comstypeid` not set correctly **Fix:** Ensure `comstypeid = 1` for network interfaces ### Issue: PC relationships not created **Cause:** Equipment with matching machine number doesn't exist **Fix:** Ensure equipment record exists with `pctypeid IS NULL` and matching `machinenumber` ### Issue: Logs not writing **Cause:** Logs directory doesn't exist or isn't writable **Fix:** ```bash mkdir -p /home/camp/projects/windows/shopdb/logs chmod 755 /home/camp/projects/windows/shopdb/logs ``` --- ## Performance Considerations ### Indexes Required Ensure these indexes exist for optimal performance: ```sql -- machines table ALTER TABLE machines ADD INDEX idx_hostname (hostname); ALTER TABLE machines ADD INDEX idx_pctypeid (pctypeid); ALTER TABLE machines ADD INDEX idx_machinenumber (machinenumber); -- communications table ALTER TABLE communications ADD INDEX idx_machineid (machineid); ALTER TABLE communications ADD INDEX idx_comstypeid (comstypeid); -- commconfig table ALTER TABLE commconfig ADD INDEX idx_machineid (machineid); -- dncconfig table ALTER TABLE dncconfig ADD INDEX idx_machineid (machineid); -- machinerelationships table ALTER TABLE machinerelationships ADD INDEX idx_machineid (machineid); ALTER TABLE machinerelationships ADD INDEX idx_related_machineid (related_machineid); ``` ### Query Optimization - Uses parameterized queries for all SELECT/INSERT/UPDATE operations - Deletes old records before inserting new (avoids duplicate detection overhead) - Single transaction per request (faster than individual commits) - Lookup caching could be added for frequently accessed vendor/model/pctype IDs --- ## Maintenance ### Log Rotation Recommend setting up log rotation for `/logs/api.log`: **Windows Task Scheduler:** ```powershell # Rotate logs weekly Get-Content "C:\inetpub\wwwroot\shopdb\logs\api.log" | Set-Content "C:\inetpub\wwwroot\shopdb\logs\api_$(Get-Date -Format 'yyyyMMdd').log" Clear-Content "C:\inetpub\wwwroot\shopdb\logs\api.log" ``` ### Monitoring Monitor these metrics: - Request count per hour - Error rate (failed requests / total requests) - Average response time - Database connection pool usage - Disk space for logs directory --- ## Future Enhancements ### Planned Features: 1. **Batch Processing**: Accept arrays of PCs in single request 2. **Delta Updates**: Only update changed fields (reduces write load) 3. **Webhook Callbacks**: Notify on successful PC creation 4. **API Key Authentication**: Secure API access 5. **Rate Limiting**: Prevent abuse 6. **Caching Layer**: Cache vendor/model/pctype lookups 7. **Async Processing**: Queue large updates for background processing ### Nice to Have: - GraphQL endpoint for flexible queries - WebSocket support for real-time updates - OpenAPI/Swagger documentation - Postman collection for testing - Health metrics endpoint (uptime, request count, error rate) --- **Version:** 1.1 **Last Updated:** 2025-12-11 **Maintained By:** ShopDB Development Team **Support:** Review `/logs/api.log` for troubleshooting