Centralize credentials and make migration idempotent

- Move all DB credentials to config.asp with DSN/ODBC toggle
- Add Zabbix API URL and token to centralized config
- Update sql.asp, api.asp, apiusb.asp, zabbix.asp to use config
- Add GetConnectionString() and GetEmployeeConnectionString() functions
- Make migration SQL idempotent (safe to run multiple times)
- Add duplicate index cleanup (appname_2) to migration
- Document employee DB access limitation in CLAUDE.md

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

Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
This commit is contained in:
cproudlock
2025-12-12 08:11:28 -05:00
parent e0d89f9957
commit 131aaaddbf
9 changed files with 150 additions and 77 deletions

View File

@@ -5,10 +5,13 @@
-- ============================================================================
--
-- CHANGES:
-- 1. Add primary key to installedapps table
-- 2. Migrate machines using PC-specific machinetypes to generic PC (33) + pctypeid
-- 3. Update models to use generic PC machinetype
-- 4. Remove unused PC machinetypes (34-43, 45-46), keep USB Device (44)
-- 1. Drop duplicate appname_2 index on applications table
-- 2. Add primary key to installedapps table (if not exists)
-- 3. Migrate machines using PC-specific machinetypes to generic PC (33) + pctypeid
-- 4. Update models to use generic PC machinetype
-- 5. Remove unused PC machinetypes (34-43, 45-46), keep USB Device (44)
--
-- NOTE: This migration is IDEMPOTENT - safe to run multiple times
--
-- RUN ON: Production database
-- BACKUP FIRST: mysqldump -u root -p shopdb > shopdb_backup_$(date +%Y%m%d).sql
@@ -18,16 +21,42 @@
START TRANSACTION;
-- ============================================================================
-- 1. ADD PRIMARY KEY TO INSTALLEDAPPS TABLE
-- 1. DROP DUPLICATE INDEX ON APPLICATIONS
-- ============================================================================
ALTER TABLE installedapps
ADD COLUMN installedappid INT AUTO_INCREMENT PRIMARY KEY FIRST;
-- Check if appname_2 index exists before dropping
SET @index_exists = (SELECT COUNT(*) FROM information_schema.STATISTICS
WHERE table_schema = DATABASE()
AND table_name = 'applications'
AND index_name = 'appname_2');
SELECT 'Added PK to installedapps' AS status;
SET @sql = IF(@index_exists > 0, 'DROP INDEX appname_2 ON applications', 'SELECT "Index appname_2 does not exist" AS status');
PREPARE stmt FROM @sql;
EXECUTE stmt;
DEALLOCATE PREPARE stmt;
SELECT IF(@index_exists > 0, 'Dropped duplicate appname_2 index', 'Index appname_2 already removed') AS status;
-- ============================================================================
-- 2. MIGRATE MACHINES FROM PC-SPECIFIC TYPES TO GENERIC PC (33) + PCTYPEID
-- 2. ADD PRIMARY KEY TO INSTALLEDAPPS TABLE (if not exists)
-- ============================================================================
SET @col_exists = (SELECT COUNT(*) FROM information_schema.COLUMNS
WHERE table_schema = DATABASE()
AND table_name = 'installedapps'
AND column_name = 'installedappid');
SET @sql = IF(@col_exists = 0,
'ALTER TABLE installedapps ADD COLUMN installedappid INT AUTO_INCREMENT PRIMARY KEY FIRST',
'SELECT "Column installedappid already exists" AS status');
PREPARE stmt FROM @sql;
EXECUTE stmt;
DEALLOCATE PREPARE stmt;
SELECT IF(@col_exists = 0, 'Added PK to installedapps', 'PK installedappid already exists') AS status;
-- ============================================================================
-- 3. MIGRATE MACHINES FROM PC-SPECIFIC TYPES TO GENERIC PC (33) + PCTYPEID
-- ============================================================================
-- These UPDATEs are already idempotent (won't change rows that don't match)
-- PC - Standard (36) → machinetypeid=33, pctypeid=1 (Standard)
UPDATE machines
@@ -64,11 +93,11 @@ UPDATE machines
SET machinetypeid = 33, pctypeid = 4
WHERE machinetypeid BETWEEN 34 AND 46 AND pctypeid IS NULL;
SELECT CONCAT('Total machines now using machinetypeid 34-46: ',
SELECT CONCAT('Total machines still using machinetypeid 34-46: ',
(SELECT COUNT(*) FROM machines WHERE machinetypeid BETWEEN 34 AND 46)) AS status;
-- ============================================================================
-- 3. UPDATE MODELS TO USE GENERIC PC MACHINETYPE (33)
-- 4. UPDATE MODELS TO USE GENERIC PC MACHINETYPE (33)
-- ============================================================================
UPDATE models
SET machinetypeid = 33
@@ -77,9 +106,10 @@ WHERE machinetypeid BETWEEN 34 AND 46;
SELECT CONCAT('Updated ', ROW_COUNT(), ' models to generic PC type') AS status;
-- ============================================================================
-- 4. DELETE REDUNDANT MACHINETYPES
-- 5. DELETE REDUNDANT MACHINETYPES
-- ============================================================================
-- Keep 33 (PC) and 44 (USB Device), remove 34-43 and 45-46
-- These DELETEs are already idempotent (won't delete if rows don't exist)
DELETE FROM machinetypes WHERE machinetypeid BETWEEN 34 AND 43;
SELECT CONCAT('Deleted ', ROW_COUNT(), ' machinetypes (34-43)') AS status;
@@ -101,10 +131,13 @@ WHERE m.pctypeid IS NOT NULL
GROUP BY m.pctypeid
ORDER BY count DESC;
SELECT 'VERIFICATION - Applications indexes:' AS info;
SELECT index_name, column_name FROM information_schema.STATISTICS
WHERE table_schema = DATABASE() AND table_name = 'applications';
-- ============================================================================
-- COMMIT (uncomment when ready to apply)
-- COMMIT
-- ============================================================================
COMMIT;
-- ROLLBACK; -- Use this instead if something looks wrong
SELECT 'Migration completed successfully!' AS status;