Files
assetmgt/assets/database/STEP 1.sql
“VeLiTi” 0648b69eff Add configuration for warranty, payment options, and bookkeeping integration
- Defined constants for warranty months, eligibility window, and service months.
- Enabled automatic invoice forwarding to bookkeeping software with email configuration.
- Integrated payment options for Mollie and PayPal, including API keys and webhook settings.
- Disabled pay on delivery option.
2026-02-03 08:55:52 +01:00

533 lines
24 KiB
SQL

-- ============================================================================
-- ACCURATE MIGRATION SCRIPT: Based on DBeaver Comparison
-- ============================================================================
-- Source: VELITI_Test (Dev)
-- Target: TSSProduct (Production)
-- Based on: DBeaver comparison with TSSProduct_test
-- Date: 2026-01-30
--
-- CRITICAL: BACKUP YOUR PRODUCTION DATABASE BEFORE RUNNING THIS SCRIPT!
-- ============================================================================
SET FOREIGN_KEY_CHECKS=0;
SET SQL_MODE='NO_AUTO_VALUE_ON_ZERO';
-- ============================================================================
-- SECTION 1: ALTER EXISTING TABLES
-- ============================================================================
-- ----------------------------------------------------------------------------
-- Table: contracts
-- Change: start_date from NULL to NOT NULL
-- ----------------------------------------------------------------------------
ALTER TABLE `contracts`
MODIFY COLUMN `start_date` date NOT NULL;
-- ----------------------------------------------------------------------------
-- Table: equipment
-- Changes: Add 2 new columns + indexes
-- ----------------------------------------------------------------------------
ALTER TABLE `equipment`
ADD COLUMN `order_send_date` date DEFAULT NULL COMMENT 'Date when order was sent' AFTER `warranty_date`,
ADD COLUMN `sw_version_license` varchar(36) DEFAULT NULL COMMENT 'Software license key reference' AFTER `sw_version_latest`,
ADD INDEX `idx_sw_version_license` (`sw_version_license`),
ADD INDEX `idx_sw_version` (`sw_version`);
-- ----------------------------------------------------------------------------
-- Table: partner
-- Changes: Add 8 new columns
-- ----------------------------------------------------------------------------
ALTER TABLE `partner`
ADD COLUMN `is_dealer` tinyint(1) NOT NULL DEFAULT 0 AFTER `status`,
ADD COLUMN `name` varchar(512) DEFAULT NULL AFTER `is_dealer`,
ADD COLUMN `address` varchar(255) DEFAULT NULL AFTER `name`,
ADD COLUMN `city` varchar(100) DEFAULT NULL AFTER `address`,
ADD COLUMN `postalcode` varchar(20) DEFAULT NULL AFTER `city`,
ADD COLUMN `country` varchar(255) DEFAULT NULL AFTER `postalcode`,
ADD COLUMN `email` varchar(255) DEFAULT NULL AFTER `country`,
ADD COLUMN `phone` varchar(50) DEFAULT NULL AFTER `email`;
-- ----------------------------------------------------------------------------
-- Table: products
-- Changes: Add 4 new columns + 2 indexes
-- ----------------------------------------------------------------------------
ALTER TABLE `products`
ADD COLUMN `quantity` int(11) DEFAULT NULL AFTER `price`,
ADD COLUMN `configurable` int(11) DEFAULT NULL AFTER `quantity`,
ADD COLUMN `url_slug` varchar(255) NOT NULL DEFAULT '' AFTER `configurable`,
ADD COLUMN `product_media` int(11) DEFAULT NULL AFTER `url_slug`,
ADD INDEX `idx_url_slug` (`url_slug`),
ADD INDEX `idx_configurable` (`configurable`);
-- ----------------------------------------------------------------------------
-- Table: products_versions
-- Changes: Add 1 column, remove 1 column
-- ----------------------------------------------------------------------------
ALTER TABLE `products_versions`
ADD COLUMN `config` text DEFAULT NULL AFTER `version`,
DROP COLUMN `software`;
-- ----------------------------------------------------------------------------
-- Table: transactions
-- Changes: Add 1 new column
-- ----------------------------------------------------------------------------
ALTER TABLE `transactions`
ADD COLUMN `vat_number` varchar(255) DEFAULT NULL AFTER `accounthierarchy`;
-- ============================================================================
-- SECTION 2: CREATE NEW TABLES (16 tables)
-- ============================================================================
-- ----------------------------------------------------------------------------
-- Table: access_elements
-- ----------------------------------------------------------------------------
CREATE TABLE `access_elements` (
`rowID` int(11) NOT NULL AUTO_INCREMENT,
`access_name` varchar(100) NOT NULL,
`access_path` varchar(255) NOT NULL,
`description` text DEFAULT NULL,
`is_active` tinyint(1) NOT NULL DEFAULT 1,
`created` timestamp NULL DEFAULT current_timestamp(),
`createdby` varchar(255) DEFAULT NULL,
`updated` timestamp NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
`updatedby` varchar(255) DEFAULT NULL,
`access_group` varchar(100) NOT NULL,
PRIMARY KEY (`rowID`),
UNIQUE KEY `unique_access_path` (`access_path`)
) ENGINE=InnoDB AUTO_INCREMENT=265 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
-- ----------------------------------------------------------------------------
-- Table: dealers
-- ----------------------------------------------------------------------------
CREATE TABLE `dealers` (
`rowID` int(11) NOT NULL AUTO_INCREMENT,
`status` int(11) NOT NULL,
`name` varchar(512) DEFAULT NULL,
`usp1` varchar(512) DEFAULT NULL,
`usp2` varchar(512) DEFAULT NULL,
`usp3` varchar(512) DEFAULT NULL,
`short_description` text NOT NULL,
`long_description` blob NOT NULL,
`address` varchar(512) NOT NULL,
`postalcode` varchar(256) NOT NULL,
`city` varchar(512) NOT NULL,
`state` varchar(256) NOT NULL,
`country` varchar(512) NOT NULL,
`opening_hours` varchar(256) NOT NULL,
`lat` decimal(10,8) NOT NULL,
`lng` decimal(11,8) NOT NULL,
`url` varchar(512) NOT NULL,
`rating_overall` varchar(256) NOT NULL,
`rating_website` varchar(256) NOT NULL,
`garden_center` int(11) NOT NULL,
`brand_type` int(11) NOT NULL,
`showroom_size` int(11) NOT NULL,
`locations` int(11) NOT NULL,
`focus_offering` int(11) NOT NULL,
`dealer_type` int(11) NOT NULL,
`dealer_slug` varchar(256) NOT NULL,
`dealer_media` int(11) DEFAULT NULL,
`created` timestamp NULL DEFAULT current_timestamp(),
`createdby` varchar(255) DEFAULT NULL,
`updated` timestamp NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
`updatedby` varchar(255) DEFAULT NULL,
`accounthierarchy` varchar(1024) DEFAULT NULL,
`email` varchar(512) DEFAULT NULL,
`phone` varchar(50) DEFAULT NULL,
PRIMARY KEY (`rowID`),
UNIQUE KEY `dealer_slug` (`dealer_slug`),
KEY `idx_status` (`status`),
KEY `idx_location` (`lat`,`lng`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;
-- ----------------------------------------------------------------------------
-- Table: dealers_media
-- ----------------------------------------------------------------------------
CREATE TABLE `dealers_media` (
`rowID` int(11) NOT NULL AUTO_INCREMENT,
`dealer_id` int(11) NOT NULL,
`media_id` int(11) NOT NULL,
`position` int(11) NOT NULL,
`created` timestamp NULL DEFAULT current_timestamp(),
`createdby` varchar(255) DEFAULT NULL,
`updated` timestamp NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
`updatedby` varchar(255) DEFAULT NULL,
PRIMARY KEY (`rowID`),
KEY `idx_dealer` (`dealer_id`),
KEY `idx_media` (`media_id`),
KEY `idx_position` (`position`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb3 COLLATE=utf8mb3_general_ci;
-- ----------------------------------------------------------------------------
-- Table: download_tokens
-- ----------------------------------------------------------------------------
CREATE TABLE `download_tokens` (
`rowID` int(11) NOT NULL AUTO_INCREMENT,
`token` varchar(64) NOT NULL,
`software_version_id` int(11) NOT NULL,
`user_id` varchar(255) DEFAULT NULL,
`equipment_id` int(11) DEFAULT NULL,
`expires_at` datetime NOT NULL,
`is_used` tinyint(1) DEFAULT 0,
`used_at` timestamp NULL DEFAULT NULL,
`ip_address` varchar(45) DEFAULT NULL,
`user_agent` text DEFAULT NULL,
`created` timestamp NULL DEFAULT current_timestamp(),
PRIMARY KEY (`rowID`),
UNIQUE KEY `token` (`token`),
KEY `idx_software_version` (`software_version_id`),
KEY `idx_expires` (`expires_at`),
KEY `idx_used` (`is_used`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
-- ----------------------------------------------------------------------------
-- Table: marketing_tags
-- ----------------------------------------------------------------------------
CREATE TABLE `marketing_tags` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`tag_name` varchar(100) NOT NULL,
`created` timestamp NOT NULL DEFAULT current_timestamp(),
PRIMARY KEY (`id`),
UNIQUE KEY `tag_name` (`tag_name`)
) ENGINE=InnoDB AUTO_INCREMENT=20 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- ----------------------------------------------------------------------------
-- Table: marketing_folders
-- ----------------------------------------------------------------------------
CREATE TABLE `marketing_folders` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`folder_name` varchar(255) NOT NULL,
`parent_id` int(11) DEFAULT NULL,
`description` text DEFAULT NULL,
`created` timestamp NOT NULL DEFAULT current_timestamp(),
`createdby` varchar(100) DEFAULT NULL,
`updated` timestamp NULL DEFAULT NULL ON UPDATE current_timestamp(),
`updatedby` varchar(100) DEFAULT NULL,
`accounthierarchy` text DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `parent_id` (`parent_id`),
KEY `accounthierarchy_idx` (`accounthierarchy`(100)),
CONSTRAINT `fk_marketing_folders_parent` FOREIGN KEY (`parent_id`) REFERENCES `marketing_folders` (`id`) ON DELETE CASCADE
) ENGINE=InnoDB AUTO_INCREMENT=20 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- ----------------------------------------------------------------------------
-- Table: marketing_files
-- ----------------------------------------------------------------------------
CREATE TABLE `marketing_files` (
`id` int(11) NOT NULL AUTO_INCREMENT,
`title` varchar(255) NOT NULL,
`original_filename` varchar(255) NOT NULL,
`file_path` varchar(500) NOT NULL,
`thumbnail_path` varchar(500) DEFAULT NULL,
`file_type` varchar(10) NOT NULL,
`file_size` bigint(20) NOT NULL DEFAULT 0,
`folder_id` int(11) DEFAULT NULL,
`tags` longtext CHARACTER SET utf8mb4 COLLATE utf8mb4_bin DEFAULT NULL CHECK (json_valid(`tags`)),
`created` timestamp NOT NULL DEFAULT current_timestamp(),
`createdby` varchar(100) DEFAULT NULL,
`updated` timestamp NULL DEFAULT NULL ON UPDATE current_timestamp(),
`updatedby` varchar(100) DEFAULT NULL,
`accounthierarchy` text DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `folder_id` (`folder_id`),
KEY `file_type` (`file_type`),
KEY `accounthierarchy_idx` (`accounthierarchy`(100)),
KEY `created_idx` (`created`),
CONSTRAINT `fk_marketing_files_folder` FOREIGN KEY (`folder_id`) REFERENCES `marketing_folders` (`id`) ON DELETE SET NULL
) ENGINE=InnoDB AUTO_INCREMENT=33 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- ----------------------------------------------------------------------------
-- Table: marketing_file_tags
-- ----------------------------------------------------------------------------
CREATE TABLE `marketing_file_tags` (
`file_id` int(11) NOT NULL,
`tag_id` int(11) NOT NULL,
PRIMARY KEY (`file_id`,`tag_id`),
KEY `file_id` (`file_id`),
KEY `tag_id` (`tag_id`),
CONSTRAINT `fk_marketing_file_tags_file` FOREIGN KEY (`file_id`) REFERENCES `marketing_files` (`id`) ON DELETE CASCADE,
CONSTRAINT `fk_marketing_file_tags_tag` FOREIGN KEY (`tag_id`) REFERENCES `marketing_tags` (`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- ----------------------------------------------------------------------------
-- Table: products_software_versions
-- ----------------------------------------------------------------------------
CREATE TABLE `products_software_versions` (
`rowID` int(11) NOT NULL AUTO_INCREMENT,
`name` varchar(255) NOT NULL,
`version` varchar(50) NOT NULL,
`description` text DEFAULT NULL,
`mandatory` int(11) DEFAULT NULL,
`latest` int(11) DEFAULT NULL,
`hw_version` varchar(255) DEFAULT NULL,
`file_path` varchar(500) DEFAULT NULL,
`status` int(11) NOT NULL DEFAULT 0,
`accounthierarchy` varchar(1024) DEFAULT NULL,
`created` timestamp NULL DEFAULT current_timestamp(),
`createdby` varchar(255) DEFAULT NULL,
`updated` timestamp NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
`updatedby` varchar(255) DEFAULT NULL,
PRIMARY KEY (`rowID`),
KEY `idx_accounthierarchy` (`accounthierarchy`(255))
) ENGINE=InnoDB AUTO_INCREMENT=10000010 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
-- ----------------------------------------------------------------------------
-- Table: products_software_assignment
-- ----------------------------------------------------------------------------
CREATE TABLE `products_software_assignment` (
`rowID` int(11) NOT NULL AUTO_INCREMENT,
`product_id` int(11) NOT NULL,
`software_version_id` int(11) NOT NULL,
`assignment_type` int(11) DEFAULT 1,
`is_default` tinyint(1) DEFAULT 0,
`status` int(11) DEFAULT 1,
`accounthierarchy` varchar(1024) DEFAULT NULL,
`created` timestamp NULL DEFAULT current_timestamp(),
`createdby` varchar(255) DEFAULT NULL,
`updated` timestamp NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
`updatedby` varchar(255) DEFAULT NULL,
PRIMARY KEY (`rowID`),
KEY `idx_product_software` (`product_id`,`software_version_id`),
KEY `idx_default` (`is_default`)
) ENGINE=InnoDB AUTO_INCREMENT=35 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
-- ----------------------------------------------------------------------------
-- Table: products_software_licenses
-- ----------------------------------------------------------------------------
CREATE TABLE `products_software_licenses` (
`rowID` int(11) NOT NULL AUTO_INCREMENT,
`version_id` int(11) NOT NULL,
`license_type` int(11) NOT NULL DEFAULT 0,
`license_key` varchar(36) NOT NULL,
`status` int(11) NOT NULL DEFAULT 0,
`starts_at` datetime DEFAULT NULL,
`expires_at` datetime DEFAULT NULL,
`transaction_id` varchar(36) DEFAULT NULL,
`accounthierarchy` varchar(1024) DEFAULT NULL,
`created` timestamp NULL DEFAULT current_timestamp(),
`createdby` varchar(255) DEFAULT NULL,
`updated` timestamp NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
`updatedby` varchar(255) DEFAULT NULL,
PRIMARY KEY (`rowID`),
UNIQUE KEY `unique_license_key` (`license_key`),
KEY `idx_version_id` (`version_id`),
KEY `idx_status` (`status`),
KEY `idx_accounthierarchy` (`accounthierarchy`(255)),
CONSTRAINT `fk_user_license_version` FOREIGN KEY (`version_id`) REFERENCES `products_software_versions` (`rowID`) ON DELETE CASCADE
) ENGINE=InnoDB AUTO_INCREMENT=65 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
-- ----------------------------------------------------------------------------
-- Table: products_software_upgrade_paths
-- ----------------------------------------------------------------------------
CREATE TABLE `products_software_upgrade_paths` (
`rowID` int(11) NOT NULL AUTO_INCREMENT,
`from_version_id` int(11) NOT NULL,
`to_version_id` int(11) NOT NULL,
`upgrade_type` enum('direct','path') NOT NULL DEFAULT 'direct',
`price` decimal(10,2) DEFAULT NULL,
`currency` varchar(3) DEFAULT 'USD',
`description` text DEFAULT NULL,
`is_active` tinyint(1) NOT NULL DEFAULT 1,
`accounthierarchy` varchar(1024) DEFAULT NULL,
`created` timestamp NULL DEFAULT current_timestamp(),
`createdby` varchar(255) DEFAULT NULL,
`updated` timestamp NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
`updatedby` varchar(255) DEFAULT NULL,
PRIMARY KEY (`rowID`),
UNIQUE KEY `unique_upgrade_path` (`from_version_id`,`to_version_id`),
KEY `idx_from_version` (`from_version_id`),
KEY `idx_to_version` (`to_version_id`),
KEY `idx_upgrade_type` (`upgrade_type`),
KEY `idx_is_active` (`is_active`),
KEY `idx_accounthierarchy` (`accounthierarchy`(255)),
CONSTRAINT `fk_upgrade_from_version` FOREIGN KEY (`from_version_id`) REFERENCES `products_software_versions` (`rowID`) ON DELETE CASCADE,
CONSTRAINT `fk_upgrade_to_version` FOREIGN KEY (`to_version_id`) REFERENCES `products_software_versions` (`rowID`) ON DELETE CASCADE
) ENGINE=InnoDB AUTO_INCREMENT=10 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
-- ----------------------------------------------------------------------------
-- Table: user_roles
-- ----------------------------------------------------------------------------
CREATE TABLE `user_roles` (
`rowID` int(11) NOT NULL AUTO_INCREMENT,
`name` varchar(100) NOT NULL,
`description` text DEFAULT NULL,
`is_active` tinyint(1) NOT NULL DEFAULT 1,
`created` timestamp NULL DEFAULT current_timestamp(),
`createdby` varchar(255) DEFAULT NULL,
`updated` timestamp NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
`updatedby` varchar(255) DEFAULT NULL,
`is_system` tinyint(1) DEFAULT NULL,
PRIMARY KEY (`rowID`),
UNIQUE KEY `unique_role_name` (`name`)
) ENGINE=InnoDB AUTO_INCREMENT=37 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
-- ----------------------------------------------------------------------------
-- Table: role_access_permissions
-- ----------------------------------------------------------------------------
CREATE TABLE `role_access_permissions` (
`rowID` int(11) NOT NULL AUTO_INCREMENT,
`role_id` int(11) NOT NULL,
`access_id` int(11) NOT NULL,
`can_create` tinyint(1) NOT NULL DEFAULT 0,
`can_read` tinyint(1) NOT NULL DEFAULT 1,
`can_update` tinyint(1) NOT NULL DEFAULT 0,
`can_delete` tinyint(1) NOT NULL DEFAULT 0,
`created` timestamp NULL DEFAULT current_timestamp(),
`createdby` varchar(255) DEFAULT NULL,
`updated` timestamp NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
`updatedby` varchar(255) DEFAULT NULL,
PRIMARY KEY (`rowID`),
UNIQUE KEY `unique_role_view` (`role_id`,`access_id`),
KEY `access_id` (`access_id`),
CONSTRAINT `role_view_permissions_ibfk_1` FOREIGN KEY (`role_id`) REFERENCES `user_roles` (`rowID`) ON DELETE CASCADE,
CONSTRAINT `role_view_permissions_ibfk_2` FOREIGN KEY (`access_id`) REFERENCES `access_elements` (`rowID`) ON DELETE CASCADE
) ENGINE=InnoDB AUTO_INCREMENT=1071 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
-- ----------------------------------------------------------------------------
-- Table: user_role_assignments
-- ----------------------------------------------------------------------------
CREATE TABLE `user_role_assignments` (
`rowID` int(11) NOT NULL AUTO_INCREMENT,
`user_id` int(11) NOT NULL,
`role_id` int(11) NOT NULL,
`is_active` tinyint(1) NOT NULL DEFAULT 1,
`assigned_by` varchar(255) DEFAULT NULL,
`assigned_at` timestamp NULL DEFAULT current_timestamp(),
`expires_at` timestamp NULL DEFAULT NULL,
`created` timestamp NULL DEFAULT current_timestamp(),
`createdby` varchar(255) DEFAULT NULL,
`updated` timestamp NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
`updatedby` varchar(255) DEFAULT NULL,
PRIMARY KEY (`rowID`),
UNIQUE KEY `unique_user_role_active` (`user_id`,`role_id`,`is_active`),
KEY `role_id` (`role_id`),
CONSTRAINT `user_role_assignments_ibfk_1` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE,
CONSTRAINT `user_role_assignments_ibfk_2` FOREIGN KEY (`role_id`) REFERENCES `user_roles` (`rowID`) ON DELETE CASCADE
) ENGINE=InnoDB AUTO_INCREMENT=326 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
-- ----------------------------------------------------------------------------
-- Table: download_logs (requires download_tokens, users, products_software_versions)
-- ----------------------------------------------------------------------------
CREATE TABLE `download_logs` (
`rowID` int(11) NOT NULL AUTO_INCREMENT,
`user_id` int(11) NOT NULL,
`version_id` int(11) NOT NULL,
`token_id` int(11) DEFAULT NULL,
`downloaded_at` datetime NOT NULL,
`ip_address` varchar(45) DEFAULT NULL,
`user_agent` text DEFAULT NULL,
`file_size` bigint(20) DEFAULT NULL,
`download_time_seconds` int(11) DEFAULT NULL,
`status` enum('success','failed','partial') NOT NULL DEFAULT 'success',
`error_message` text DEFAULT NULL,
`accounthierarchy` varchar(1024) DEFAULT NULL,
`created` timestamp NULL DEFAULT current_timestamp(),
`createdby` varchar(255) DEFAULT NULL,
`updated` timestamp NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(),
`updatedby` varchar(255) DEFAULT NULL,
PRIMARY KEY (`rowID`),
KEY `idx_user_id` (`user_id`),
KEY `idx_version_id` (`version_id`),
KEY `idx_token_id` (`token_id`),
KEY `idx_downloaded_at` (`downloaded_at`),
KEY `idx_status` (`status`),
KEY `idx_accounthierarchy` (`accounthierarchy`(255)),
CONSTRAINT `fk_download_log_token` FOREIGN KEY (`token_id`) REFERENCES `download_tokens` (`rowID`) ON DELETE SET NULL,
CONSTRAINT `fk_download_log_user` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE,
CONSTRAINT `fk_download_log_version` FOREIGN KEY (`version_id`) REFERENCES `products_software_versions` (`rowID`) ON DELETE CASCADE
) ENGINE=InnoDB AUTO_INCREMENT=168 DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci;
-- ============================================================================
-- SECTION 3: CREATE STORED PROCEDURE (if not exists)
-- Note: DEFINER removed - will use current user permissions
-- ============================================================================
DELIMITER $$
DROP PROCEDURE IF EXISTS `extract_git_commit`$$
CREATE PROCEDURE `extract_git_commit`(
IN input_string TEXT,
OUT commit_hash VARCHAR(40)
)
BEGIN
DECLARE start_pos INT;
DECLARE end_pos INT;
SET start_pos = LOCATE('commit ', input_string);
IF start_pos > 0 THEN
SET start_pos = start_pos + 7;
SET end_pos = LOCATE(' ', input_string, start_pos);
IF end_pos = 0 THEN
SET end_pos = LENGTH(input_string) + 1;
END IF;
SET commit_hash = SUBSTRING(input_string, start_pos, end_pos - start_pos);
ELSE
SET commit_hash = NULL;
END IF;
END$$
DELIMITER ;
-- ============================================================================
-- SECTION 4: VERIFICATION
-- ============================================================================
-- Verify new tables
SELECT 'NEW TABLES CREATED:' as Status;
SELECT TABLE_NAME
FROM information_schema.TABLES
WHERE TABLE_SCHEMA = DATABASE()
AND TABLE_NAME IN (
'access_elements', 'dealers', 'dealers_media', 'download_tokens',
'download_logs', 'marketing_tags', 'marketing_folders', 'marketing_files',
'marketing_file_tags', 'products_software_versions', 'products_software_assignment',
'products_software_licenses', 'products_software_upgrade_paths',
'user_roles', 'role_access_permissions', 'user_role_assignments'
)
ORDER BY TABLE_NAME;
-- Verify altered tables
SELECT 'ALTERED TABLES - NEW COLUMNS:' as Status;
SELECT TABLE_NAME, COLUMN_NAME, DATA_TYPE
FROM information_schema.COLUMNS
WHERE TABLE_SCHEMA = DATABASE()
AND (
(TABLE_NAME = 'equipment' AND COLUMN_NAME IN ('order_send_date', 'sw_version_license'))
OR (TABLE_NAME = 'partner' AND COLUMN_NAME IN ('is_dealer', 'name', 'address', 'city', 'postalcode', 'country', 'email', 'phone'))
OR (TABLE_NAME = 'products' AND COLUMN_NAME IN ('quantity', 'configurable', 'url_slug', 'product_media'))
OR (TABLE_NAME = 'products_versions' AND COLUMN_NAME = 'config')
OR (TABLE_NAME = 'transactions' AND COLUMN_NAME = 'vat_number')
)
ORDER BY TABLE_NAME, COLUMN_NAME;
SET FOREIGN_KEY_CHECKS=1;
-- ============================================================================
-- MIGRATION COMPLETE
-- ============================================================================
SELECT '========================================' as Status;
SELECT 'MIGRATION COMPLETED SUCCESSFULLY!' as Status;
SELECT '========================================' as Status;
SELECT CONCAT('Total tables in database: ', COUNT(*)) as Status
FROM information_schema.TABLES
WHERE TABLE_SCHEMA = DATABASE();
-- ============================================================================
-- POST-MIGRATION CHECKLIST
-- ============================================================================
-- [ ] Verify all 16 new tables exist
-- [ ] Verify contracts.start_date is NOT NULL
-- [ ] Verify equipment has order_send_date, sw_version_license + indexes
-- [ ] Verify partner has 8 new columns
-- [ ] Verify products has 4 new columns + 2 indexes
-- [ ] Verify products_versions has config column (software removed)
-- [ ] Verify transactions has vat_number column
-- [ ] Test application functionality
-- [ ] Monitor for errors
-- [ ] Keep backup for at least 7 days
-- ============================================================================