- Bump DESK_MOLONI version to 3.0.1 across module - Normalize hooks to after_client_* and instantiate PerfexHooks safely - Fix OAuthController view path and API client class name - Add missing admin views for webhook config/logs; adjust view loading - Harden client portal routes and admin routes mapping - Make Dashboard/Logs/Queue tolerant to optional model methods - Align log details query with existing schema; avoid broken joins This makes the module operational in Perfex (admin + client), reduces 404s, and avoids fatal errors due to inconsistent tables/methods.
263 lines
11 KiB
SQL
263 lines
11 KiB
SQL
-- Desk-Moloni v3.0 Critical Issues Migration
|
|
-- Fixes all identified critical problems from foundation audit
|
|
-- Date: 2025-09-10
|
|
-- Version: 3.0.0-critical-fixes
|
|
|
|
-- ============================================================================
|
|
-- CRITICAL FIXES MIGRATION
|
|
-- ============================================================================
|
|
|
|
-- Ensure all tables use the correct naming convention (tbldeskmoloni_*)
|
|
-- This migration is idempotent and can be run multiple times safely
|
|
|
|
SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0;
|
|
SET @OLD_SQL_MODE=@@SQL_MODE, SQL_MODE='NO_AUTO_VALUE_ON_ZERO';
|
|
|
|
-- ============================================================================
|
|
-- 1. CONFIG TABLE FIXES
|
|
-- ============================================================================
|
|
|
|
-- Create or update config table with correct structure
|
|
CREATE TABLE IF NOT EXISTS `tbldeskmoloni_config` (
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`setting_key` varchar(255) NOT NULL,
|
|
`setting_value` longtext DEFAULT NULL,
|
|
`encrypted` tinyint(1) NOT NULL DEFAULT 0,
|
|
`created_at` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
`updated_at` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
|
PRIMARY KEY (`id`),
|
|
UNIQUE KEY `uk_setting_key` (`setting_key`),
|
|
KEY `idx_setting_key` (`setting_key`),
|
|
KEY `idx_encrypted` (`encrypted`)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
|
|
COMMENT='Secure storage of API credentials and module configuration';
|
|
|
|
-- Migrate data from old table if exists
|
|
INSERT IGNORE INTO `tbldeskmoloni_config`
|
|
SELECT * FROM `tbldesk_moloni_config`
|
|
WHERE EXISTS (SELECT 1 FROM information_schema.tables
|
|
WHERE table_name = 'tbldesk_moloni_config'
|
|
AND table_schema = DATABASE());
|
|
|
|
-- Drop old table after migration
|
|
DROP TABLE IF EXISTS `tbldesk_moloni_config`;
|
|
|
|
-- ============================================================================
|
|
-- 2. MAPPING TABLE FIXES
|
|
-- ============================================================================
|
|
|
|
-- Create or update mapping table with correct structure
|
|
CREATE TABLE IF NOT EXISTS `tbldeskmoloni_mapping` (
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`entity_type` enum('client','product','invoice','estimate','credit_note') NOT NULL,
|
|
`perfex_id` int(11) NOT NULL,
|
|
`moloni_id` int(11) NOT NULL,
|
|
`sync_direction` enum('perfex_to_moloni','moloni_to_perfex','bidirectional') NOT NULL DEFAULT 'bidirectional',
|
|
`last_sync_at` timestamp NULL DEFAULT NULL,
|
|
`created_at` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
`updated_at` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
|
PRIMARY KEY (`id`),
|
|
UNIQUE KEY `unique_perfex_mapping` (`entity_type`, `perfex_id`),
|
|
UNIQUE KEY `unique_moloni_mapping` (`entity_type`, `moloni_id`),
|
|
KEY `idx_entity_perfex` (`entity_type`, `perfex_id`),
|
|
KEY `idx_entity_moloni` (`entity_type`, `moloni_id`),
|
|
KEY `idx_last_sync` (`last_sync_at`)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
|
|
COMMENT='Bidirectional entity mapping between Perfex and Moloni';
|
|
|
|
-- Migrate data from old table if exists
|
|
INSERT IGNORE INTO `tbldeskmoloni_mapping`
|
|
SELECT * FROM `tbldesk_moloni_mapping`
|
|
WHERE EXISTS (SELECT 1 FROM information_schema.tables
|
|
WHERE table_name = 'tbldesk_moloni_mapping'
|
|
AND table_schema = DATABASE());
|
|
|
|
-- Drop old table after migration
|
|
DROP TABLE IF EXISTS `tbldesk_moloni_mapping`;
|
|
|
|
-- ============================================================================
|
|
-- 3. SYNC QUEUE TABLE FIXES
|
|
-- ============================================================================
|
|
|
|
-- Create or update sync queue table with correct structure
|
|
CREATE TABLE IF NOT EXISTS `tbldeskmoloni_sync_queue` (
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`task_type` enum('sync_client','sync_product','sync_invoice','sync_estimate','sync_credit_note','status_update') NOT NULL,
|
|
`entity_type` enum('client','product','invoice','estimate','credit_note') NOT NULL,
|
|
`entity_id` int(11) NOT NULL,
|
|
`priority` tinyint(4) DEFAULT 5 COMMENT 'Task priority (1=highest, 9=lowest)',
|
|
`payload` json DEFAULT NULL COMMENT 'Task execution data and parameters',
|
|
`status` enum('pending','processing','completed','failed','retry') DEFAULT 'pending',
|
|
`attempts` int(11) DEFAULT 0,
|
|
`max_attempts` int(11) DEFAULT 3,
|
|
`scheduled_at` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
`started_at` timestamp NULL DEFAULT NULL,
|
|
`completed_at` timestamp NULL DEFAULT NULL,
|
|
`error_message` text DEFAULT NULL,
|
|
`created_at` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
`updated_at` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
|
PRIMARY KEY (`id`),
|
|
KEY `idx_status_priority` (`status`, `priority`, `scheduled_at`),
|
|
KEY `idx_entity` (`entity_type`, `entity_id`),
|
|
KEY `idx_scheduled` (`scheduled_at`),
|
|
KEY `idx_status_attempts` (`status`, `attempts`)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
|
|
COMMENT='Asynchronous task queue for synchronization operations';
|
|
|
|
-- Migrate data from old table if exists (with column mapping)
|
|
INSERT IGNORE INTO `tbldeskmoloni_sync_queue`
|
|
(`task_type`, `entity_type`, `entity_id`, `priority`, `payload`, `status`, `attempts`, `max_attempts`,
|
|
`scheduled_at`, `started_at`, `completed_at`, `error_message`, `created_at`, `updated_at`)
|
|
SELECT
|
|
CASE
|
|
WHEN IFNULL(action, 'sync') = 'sync' THEN CONCAT('sync_', entity_type)
|
|
ELSE action
|
|
END as task_type,
|
|
entity_type,
|
|
entity_id,
|
|
CASE priority
|
|
WHEN 'critical' THEN 1
|
|
WHEN 'high' THEN 2
|
|
WHEN 'normal' THEN 5
|
|
WHEN 'low' THEN 8
|
|
ELSE 5
|
|
END as priority,
|
|
CASE
|
|
WHEN data IS NOT NULL AND data != '' THEN CAST(data as JSON)
|
|
ELSE JSON_OBJECT()
|
|
END as payload,
|
|
status,
|
|
attempts,
|
|
max_attempts,
|
|
created_at as scheduled_at,
|
|
updated_at as started_at,
|
|
CASE WHEN status = 'completed' THEN updated_at ELSE NULL END as completed_at,
|
|
error_message,
|
|
created_at,
|
|
updated_at
|
|
FROM `tbldesk_moloni_sync_queue`
|
|
WHERE EXISTS (SELECT 1 FROM information_schema.tables
|
|
WHERE table_name = 'tbldesk_moloni_sync_queue'
|
|
AND table_schema = DATABASE());
|
|
|
|
-- Drop old table after migration
|
|
DROP TABLE IF EXISTS `tbldesk_moloni_sync_queue`;
|
|
|
|
-- ============================================================================
|
|
-- 4. SYNC LOG TABLE FIXES
|
|
-- ============================================================================
|
|
|
|
-- Create or update sync log table with correct structure
|
|
CREATE TABLE IF NOT EXISTS `tbldeskmoloni_sync_log` (
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`operation_type` enum('create','update','delete','status_change') NOT NULL,
|
|
`entity_type` enum('client','product','invoice','estimate','credit_note') NOT NULL,
|
|
`perfex_id` int(11) DEFAULT NULL,
|
|
`moloni_id` int(11) DEFAULT NULL,
|
|
`direction` enum('perfex_to_moloni','moloni_to_perfex') NOT NULL,
|
|
`status` enum('success','error','warning') NOT NULL,
|
|
`request_data` json DEFAULT NULL COMMENT 'Full API request for debugging',
|
|
`response_data` json DEFAULT NULL COMMENT 'Full API response for debugging',
|
|
`error_message` text DEFAULT NULL,
|
|
`execution_time_ms` int(11) DEFAULT NULL COMMENT 'Performance monitoring',
|
|
`created_at` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
|
PRIMARY KEY (`id`),
|
|
KEY `idx_entity_status` (`entity_type`, `status`, `created_at`),
|
|
KEY `idx_perfex_entity` (`perfex_id`, `entity_type`),
|
|
KEY `idx_moloni_entity` (`moloni_id`, `entity_type`),
|
|
KEY `idx_created_at` (`created_at`),
|
|
KEY `idx_status_direction` (`status`, `direction`)
|
|
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci
|
|
COMMENT='Comprehensive audit log of all synchronization operations';
|
|
|
|
-- Migrate data from old table if exists
|
|
INSERT IGNORE INTO `tbldeskmoloni_sync_log`
|
|
SELECT * FROM `tbldesk_moloni_sync_log`
|
|
WHERE EXISTS (SELECT 1 FROM information_schema.tables
|
|
WHERE table_name = 'tbldesk_moloni_sync_log'
|
|
AND table_schema = DATABASE());
|
|
|
|
-- Drop old table after migration
|
|
DROP TABLE IF EXISTS `tbldesk_moloni_sync_log`;
|
|
|
|
-- ============================================================================
|
|
-- 5. PERFORMANCE OPTIMIZATIONS
|
|
-- ============================================================================
|
|
|
|
-- Add composite indexes for common query patterns
|
|
ALTER TABLE `tbldeskmoloni_sync_queue`
|
|
ADD INDEX IF NOT EXISTS `idx_queue_processing` (`status`, `priority`, `scheduled_at`, `attempts`)
|
|
COMMENT 'Optimized index for queue processing queries';
|
|
|
|
ALTER TABLE `tbldeskmoloni_sync_log`
|
|
ADD INDEX IF NOT EXISTS `idx_log_analytics` (`created_at`, `status`, `entity_type`, `execution_time_ms`)
|
|
COMMENT 'Optimized index for analytics and reporting';
|
|
|
|
-- ============================================================================
|
|
-- 6. DATA INTEGRITY CONSTRAINTS
|
|
-- ============================================================================
|
|
|
|
-- Add foreign key constraints where possible (commented for compatibility)
|
|
-- Note: These may need adjustment based on actual Perfex CRM table structure
|
|
|
|
-- ALTER TABLE `tbldeskmoloni_mapping`
|
|
-- ADD CONSTRAINT `fk_mapping_perfex_client`
|
|
-- FOREIGN KEY (`perfex_id`) REFERENCES `tblclients`(`userid`)
|
|
-- ON DELETE CASCADE ON UPDATE CASCADE;
|
|
|
|
-- ============================================================================
|
|
-- 7. INITIALIZE CRITICAL CONFIGURATION
|
|
-- ============================================================================
|
|
|
|
-- Insert default configuration values if not exists
|
|
INSERT IGNORE INTO `tbldeskmoloni_config` (`setting_key`, `setting_value`, `encrypted`) VALUES
|
|
('module_version', '3.0.0', 0),
|
|
('api_base_url', 'https://api.moloni.pt/v1', 0),
|
|
('oauth_redirect_uri', '', 0),
|
|
('oauth_client_id', '', 1),
|
|
('oauth_client_secret', '', 1),
|
|
('oauth_access_token', '', 1),
|
|
('oauth_refresh_token', '', 1),
|
|
('oauth_token_expires_at', '', 1),
|
|
('moloni_company_id', '', 1),
|
|
('rate_limit_requests_per_minute', '60', 0),
|
|
('sync_batch_size', '50', 0),
|
|
('queue_processing_interval', '60', 0),
|
|
('pdf_storage_path', 'uploads/desk_moloni/pdfs/', 0),
|
|
('encryption_key_version', '1', 0),
|
|
('last_system_health_check', '', 0),
|
|
('sync_enabled', '1', 0),
|
|
('oauth_timeout', '30', 0),
|
|
('use_pkce', '1', 0),
|
|
('redis_password', '', 1),
|
|
('auto_sync_delay', '300', 0);
|
|
|
|
-- ============================================================================
|
|
-- 8. VALIDATION AND CLEANUP
|
|
-- ============================================================================
|
|
|
|
-- Verify table structures are correct
|
|
SELECT
|
|
table_name,
|
|
table_rows,
|
|
table_comment
|
|
FROM information_schema.tables
|
|
WHERE table_schema = DATABASE()
|
|
AND table_name LIKE 'tbldeskmoloni_%'
|
|
ORDER BY table_name;
|
|
|
|
-- Verify configuration is loaded
|
|
SELECT
|
|
COUNT(*) as config_entries,
|
|
SUM(CASE WHEN encrypted = 1 THEN 1 ELSE 0 END) as encrypted_entries,
|
|
SUM(CASE WHEN setting_value != '' THEN 1 ELSE 0 END) as populated_entries
|
|
FROM `tbldeskmoloni_config`;
|
|
|
|
-- Reset SQL modes and foreign key checks
|
|
SET SQL_MODE=@OLD_SQL_MODE;
|
|
SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS;
|
|
|
|
-- Migration completed successfully
|
|
SELECT 'Desk-Moloni Critical Issues Migration Completed Successfully' as status,
|
|
NOW() as completed_at,
|
|
'3.0.0-critical-fixes' as version; |