# Phase 4 Migration: Application Versions **Date:** 2025-11-25 **Status:** Ready for deployment ## Overview This migration adds application version tracking to ShopDB: 1. **`appversions` table** - Stores version strings for each application 2. **`installedapps.appversionid`** - Links installed apps to specific versions 3. **`notifications.appid`** - Optional link from notifications to applications ## Schema Changes ### New Table: appversions ```sql CREATE TABLE appversions ( appversionid INT PRIMARY KEY AUTO_INCREMENT, appid TINYINT(4) NOT NULL, -- FK to applications version VARCHAR(50) NOT NULL, -- Version string (e.g., "2.1.0.45") releasedate DATE NULL, -- Optional release date notes VARCHAR(255) NULL, -- Optional notes isactive BIT(1) DEFAULT 1, dateadded DATETIME DEFAULT NOW(), UNIQUE KEY (appid, version) -- One entry per app+version combo ); ``` ### Modified Table: installedapps ```sql -- Added column: appversionid INT NULL -- FK to appversions (NULL for legacy records) ``` ### Modified Table: notifications ```sql -- Added column: appid TINYINT(4) NULL -- FK to applications (optional app association) ``` ## Files | File | Purpose | |------|---------| | `01_create_appversions_table.sql` | Creates the appversions table | | `02_add_appversionid_to_installedapps.sql` | Adds version FK to installedapps | | `03_add_appid_to_notifications.sql` | Adds app FK to notifications | | `VERIFY_PHASE4_MIGRATION.sql` | Verifies all changes | | `RUN_ALL_PHASE4_SCRIPTS.sql` | Runs all scripts in order | | `ROLLBACK_01_appversions_table.sql` | Drops appversions table | | `ROLLBACK_02_installedapps_appversionid.sql` | Removes installedapps column | | `ROLLBACK_03_notifications_appid.sql` | Removes notifications column | ## Deployment Instructions ### Prerequisites 1. Create database backup: ```bash mysqldump -u root -p shopdb > shopdb_backup_$(date +%Y%m%d_%H%M%S).sql ``` 2. Verify current schema: ```bash mysql -u root -p shopdb -e "DESCRIBE installedapps; DESCRIBE notifications;" ``` ### Run Migration **Option A: Run all scripts at once** ```bash cd /path/to/sql/migration_phase4 mysql -u root -p shopdb < RUN_ALL_PHASE4_SCRIPTS.sql ``` **Option B: Run scripts individually** ```bash mysql -u root -p shopdb < 01_create_appversions_table.sql mysql -u root -p shopdb < 02_add_appversionid_to_installedapps.sql mysql -u root -p shopdb < 03_add_appid_to_notifications.sql mysql -u root -p shopdb < VERIFY_PHASE4_MIGRATION.sql ``` ### Verify Success ```bash mysql -u root -p shopdb < VERIFY_PHASE4_MIGRATION.sql ``` All checks should show ` PASS`. ## Rollback Instructions If you need to rollback, run scripts in reverse order: ```bash mysql -u root -p shopdb < ROLLBACK_03_notifications_appid.sql mysql -u root -p shopdb < ROLLBACK_02_installedapps_appversionid.sql mysql -u root -p shopdb < ROLLBACK_01_appversions_table.sql ``` **Warning:** Rolling back `ROLLBACK_01` will delete all version data. ## Post-Migration: Code Changes Required ### 1. api.asp - Update GetOrCreateApplication() The function needs to: - Look up or create the application in `applications` - Look up or create the version in `appversions` - Return `appversionid` to store in `installedapps` ### 2. api.asp - Update UpdateInstalledApps() Change INSERT to include `appversionid`: ```sql INSERT INTO installedapps (machineid, appid, appversionid, isactive) VALUES (?, ?, ?, ?) ``` ### 3. Notification forms (addnotification.asp, editnotification.asp) Add optional application dropdown to link notifications to apps. ### 4. Display pages - `displayinstalledapps.asp` - Show version column - `displaynotifications.asp` - Show linked app name ## Example Queries ### Get installed apps with versions ```sql SELECT m.hostname, a.appname, av.version, ia.isactive FROM installedapps ia JOIN machines m ON ia.machineid = m.machineid JOIN applications a ON ia.appid = a.appid LEFT JOIN appversions av ON ia.appversionid = av.appversionid WHERE m.pctypeid IS NOT NULL ORDER BY m.hostname, a.appname; ``` ### Get notifications with linked apps ```sql SELECT n.notification, n.starttime, n.endtime, a.appname AS related_app FROM notifications n LEFT JOIN applications a ON n.appid = a.appid WHERE n.isactive = 1 ORDER BY n.starttime DESC; ``` ### Find all versions of a specific app ```sql SELECT a.appname, av.version, av.releasedate, COUNT(ia.machineid) AS install_count FROM applications a JOIN appversions av ON a.appid = av.appid LEFT JOIN installedapps ia ON av.appversionid = ia.appversionid WHERE a.appname LIKE '%PC-DMIS%' GROUP BY a.appid, av.appversionid ORDER BY av.version DESC; ```