-- -- DeclarationTVA Module Database Schema -- French CA-3 VAT Declaration Module for Dolibarr -- Version: 1.0 -- Created: 2025-01-27 -- -- ===================================================== -- 1. CORE CONFIGURATION TABLES -- ===================================================== -- Main configuration table for PCG account mappings CREATE TABLE IF NOT EXISTS `llx_declarationtva_config` ( `rowid` int(11) NOT NULL AUTO_INCREMENT, `entity` int(11) NOT NULL DEFAULT 1, `config_key` varchar(64) NOT NULL, `config_value` text, `config_type` varchar(32) DEFAULT 'string', `config_desc` text, `is_active` tinyint(1) DEFAULT 1, `created_date` datetime DEFAULT NULL, `modified_date` datetime DEFAULT NULL, `created_by` int(11) DEFAULT NULL, `modified_by` int(11) DEFAULT NULL, PRIMARY KEY (`rowid`), UNIQUE KEY `uk_config_entity_key` (`entity`, `config_key`), KEY `idx_config_key` (`config_key`), KEY `idx_config_active` (`is_active`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- PCG Account Mappings - Multiple accounts per CA-3 line CREATE TABLE IF NOT EXISTS `llx_declarationtva_account_mappings` ( `rowid` int(11) NOT NULL AUTO_INCREMENT, `entity` int(11) NOT NULL DEFAULT 1, `ca3_line` varchar(8) NOT NULL COMMENT 'A1, A2, B1, B2, B3, B4, 05, 06, 17, 20, 21, 22, 28, 29', `account_code` varchar(32) NOT NULL COMMENT 'PCG account code from llx_accounting_account', `account_label` varchar(255) DEFAULT NULL COMMENT 'Account description', `vat_rate` decimal(5,2) DEFAULT NULL COMMENT 'VAT rate (20.00, 10.00, 5.50, 2.10, 0.00)', `account_type` varchar(32) DEFAULT NULL COMMENT 'base, vat_collected, vat_deductible, vat_due', `is_active` tinyint(1) DEFAULT 1, `weight` decimal(5,2) DEFAULT 1.00 COMMENT 'Account weighting (default 1.0)', `sort_order` int(11) DEFAULT 0 COMMENT 'Display order', `created_date` datetime DEFAULT NULL, `modified_date` datetime DEFAULT NULL, `created_by` int(11) DEFAULT NULL, `modified_by` int(11) DEFAULT NULL, PRIMARY KEY (`rowid`), UNIQUE KEY `uk_mapping_entity_line_account` (`entity`, `ca3_line`, `account_code`), KEY `idx_ca3_line` (`ca3_line`), KEY `idx_account_code` (`account_code`), KEY `idx_vat_rate` (`vat_rate`), KEY `idx_account_type` (`account_type`), KEY `idx_active` (`is_active`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ===================================================== -- 2. PERIOD MANAGEMENT -- ===================================================== -- Declaration periods management CREATE TABLE IF NOT EXISTS `llx_declarationtva_periods` ( `rowid` int(11) NOT NULL AUTO_INCREMENT, `entity` int(11) NOT NULL DEFAULT 1, `period_name` varchar(64) NOT NULL COMMENT 'Q1-2024, M01-2024, etc.', `period_type` varchar(16) NOT NULL COMMENT 'quarterly, monthly, annual', `start_date` date NOT NULL, `end_date` date NOT NULL, `status` varchar(32) DEFAULT 'draft' COMMENT 'draft, validated, submitted, approved, rejected', `is_locked` tinyint(1) DEFAULT 0 COMMENT 'Prevent modifications', `submission_date` datetime DEFAULT NULL, `approval_date` datetime DEFAULT NULL, `rejection_reason` text DEFAULT NULL, `created_date` datetime DEFAULT NULL, `modified_date` datetime DEFAULT NULL, `created_by` int(11) DEFAULT NULL, `modified_by` int(11) DEFAULT NULL, PRIMARY KEY (`rowid`), UNIQUE KEY `uk_period_entity_name` (`entity`, `period_name`), KEY `idx_period_type` (`period_type`), KEY `idx_period_dates` (`start_date`, `end_date`), KEY `idx_period_status` (`status`), KEY `idx_period_locked` (`is_locked`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ===================================================== -- 3. DECLARATION STORAGE -- ===================================================== -- Main declarations table CREATE TABLE IF NOT EXISTS `llx_declarationtva_declarations` ( `rowid` int(11) NOT NULL AUTO_INCREMENT, `entity` int(11) NOT NULL DEFAULT 1, `period_id` int(11) NOT NULL, `declaration_number` varchar(32) NOT NULL COMMENT 'Auto-generated declaration number', `status` varchar(32) DEFAULT 'draft' COMMENT 'draft, validated, submitted, approved, rejected', `declaration_type` varchar(16) DEFAULT 'ca3' COMMENT 'ca3, ca12, ca4, etc.', `total_vat_collected` decimal(15,2) DEFAULT 0.00, `total_vat_deductible` decimal(15,2) DEFAULT 0.00, `net_vat_due` decimal(15,2) DEFAULT 0.00, `vat_credit` decimal(15,2) DEFAULT 0.00, `submission_date` datetime DEFAULT NULL, `approval_date` datetime DEFAULT NULL, `rejection_reason` text DEFAULT NULL, `xml_data` longtext DEFAULT NULL COMMENT 'XML export data', `pdf_path` varchar(255) DEFAULT NULL COMMENT 'PDF file path', `created_date` datetime DEFAULT NULL, `modified_date` datetime DEFAULT NULL, `created_by` int(11) DEFAULT NULL, `modified_by` int(11) DEFAULT NULL, PRIMARY KEY (`rowid`), UNIQUE KEY `uk_declaration_entity_number` (`entity`, `declaration_number`), KEY `idx_period_id` (`period_id`), KEY `idx_status` (`status`), KEY `idx_declaration_type` (`declaration_type`), KEY `idx_submission_date` (`submission_date`), CONSTRAINT `fk_declaration_period` FOREIGN KEY (`period_id`) REFERENCES `llx_declarationtva_periods` (`rowid`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- CA-3 form lines data CREATE TABLE IF NOT EXISTS `llx_declarationtva_ca3_lines` ( `rowid` int(11) NOT NULL AUTO_INCREMENT, `declaration_id` int(11) NOT NULL, `ca3_line` varchar(8) NOT NULL COMMENT 'A1, A2, B1, B2, B3, B4, 05, 06, 17, 20, 21, 22, 28, 29', `line_label` varchar(255) DEFAULT NULL, `base_amount` decimal(15,2) DEFAULT 0.00 COMMENT 'Base HT amount', `vat_amount` decimal(15,2) DEFAULT 0.00 COMMENT 'VAT amount', `total_amount` decimal(15,2) DEFAULT 0.00 COMMENT 'Total amount (base + VAT)', `vat_rate` decimal(5,2) DEFAULT NULL COMMENT 'VAT rate applied', `account_count` int(11) DEFAULT 0 COMMENT 'Number of accounts contributing', `created_date` datetime DEFAULT NULL, `modified_date` datetime DEFAULT NULL, PRIMARY KEY (`rowid`), UNIQUE KEY `uk_declaration_line` (`declaration_id`, `ca3_line`), KEY `idx_ca3_line` (`ca3_line`), KEY `idx_vat_rate` (`vat_rate`), CONSTRAINT `fk_ca3_declaration` FOREIGN KEY (`declaration_id`) REFERENCES `llx_declarationtva_declarations` (`rowid`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Detailed account breakdown for each CA-3 line CREATE TABLE IF NOT EXISTS `llx_declarationtva_account_details` ( `rowid` int(11) NOT NULL AUTO_INCREMENT, `declaration_id` int(11) NOT NULL, `ca3_line` varchar(8) NOT NULL, `account_code` varchar(32) NOT NULL, `account_label` varchar(255) DEFAULT NULL, `base_amount` decimal(15,2) DEFAULT 0.00, `vat_amount` decimal(15,2) DEFAULT 0.00, `total_amount` decimal(15,2) DEFAULT 0.00, `transaction_count` int(11) DEFAULT 0, `created_date` datetime DEFAULT NULL, PRIMARY KEY (`rowid`), KEY `idx_declaration_id` (`declaration_id`), KEY `idx_ca3_line` (`ca3_line`), KEY `idx_account_code` (`account_code`), CONSTRAINT `fk_details_declaration` FOREIGN KEY (`declaration_id`) REFERENCES `llx_declarationtva_declarations` (`rowid`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ===================================================== -- 4. EU TRANSACTION HANDLING -- ===================================================== -- EU supplier configuration CREATE TABLE IF NOT EXISTS `llx_declarationtva_eu_suppliers` ( `rowid` int(11) NOT NULL AUTO_INCREMENT, `entity` int(11) NOT NULL DEFAULT 1, `supplier_id` int(11) NOT NULL COMMENT 'Reference to llx_societe', `country_code` varchar(2) NOT NULL COMMENT 'EU country code', `vat_number` varchar(32) DEFAULT NULL, `is_eu_supplier` tinyint(1) DEFAULT 1, `autoliquidation_enabled` tinyint(1) DEFAULT 1, `transaction_type` varchar(16) DEFAULT 'b2b' COMMENT 'b2b, b2c, special', `oss_threshold` decimal(15,2) DEFAULT 10000.00 COMMENT 'OSS threshold amount', `deb_des_required` tinyint(1) DEFAULT 0, `created_date` datetime DEFAULT NULL, `modified_date` datetime DEFAULT NULL, `created_by` int(11) DEFAULT NULL, `modified_by` int(11) DEFAULT NULL, PRIMARY KEY (`rowid`), UNIQUE KEY `uk_eu_supplier_entity` (`entity`, `supplier_id`), KEY `idx_supplier_id` (`supplier_id`), KEY `idx_country_code` (`country_code`), KEY `idx_is_eu_supplier` (`is_eu_supplier`), KEY `idx_transaction_type` (`transaction_type`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- EU transaction tracking CREATE TABLE IF NOT EXISTS `llx_declarationtva_eu_transactions` ( `rowid` int(11) NOT NULL AUTO_INCREMENT, `entity` int(11) NOT NULL DEFAULT 1, `invoice_id` int(11) NOT NULL COMMENT 'Reference to llx_facture or llx_facture_fourn', `transaction_type` varchar(16) NOT NULL COMMENT 'incoming, outgoing', `customer_type` varchar(8) DEFAULT NULL COMMENT 'b2b, b2c', `country_code` varchar(2) NOT NULL, `base_amount` decimal(15,2) DEFAULT 0.00, `vat_amount` decimal(15,2) DEFAULT 0.00, `vat_rate` decimal(5,2) DEFAULT NULL, `autoliquidation_applied` tinyint(1) DEFAULT 0, `deb_des_required` tinyint(1) DEFAULT 0, `period_id` int(11) DEFAULT NULL, `created_date` datetime DEFAULT NULL, `modified_date` datetime DEFAULT NULL, PRIMARY KEY (`rowid`), KEY `idx_invoice_id` (`invoice_id`), KEY `idx_transaction_type` (`transaction_type`), KEY `idx_customer_type` (`customer_type`), KEY `idx_country_code` (`country_code`), KEY `idx_period_id` (`period_id`), CONSTRAINT `fk_eu_period` FOREIGN KEY (`period_id`) REFERENCES `llx_declarationtva_periods` (`rowid`) ON DELETE SET NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ===================================================== -- 5. WORKFLOW INTEGRATION -- ===================================================== -- Workflow triggers and automation CREATE TABLE IF NOT EXISTS `llx_declarationtva_workflow_log` ( `rowid` int(11) NOT NULL AUTO_INCREMENT, `entity` int(11) NOT NULL DEFAULT 1, `trigger_type` varchar(32) NOT NULL COMMENT 'invoice_validate, supplier_invoice_validate, etc.', `object_id` int(11) NOT NULL COMMENT 'ID of the triggered object', `object_type` varchar(32) NOT NULL COMMENT 'invoice, supplier_invoice, etc.', `action_taken` varchar(64) DEFAULT NULL, `vat_processed` decimal(15,2) DEFAULT 0.00, `status` varchar(16) DEFAULT 'success' COMMENT 'success, error, warning', `error_message` text DEFAULT NULL, `processed_date` datetime DEFAULT NULL, `created_date` datetime DEFAULT NULL, PRIMARY KEY (`rowid`), KEY `idx_trigger_type` (`trigger_type`), KEY `idx_object_id` (`object_id`), KEY `idx_object_type` (`object_type`), KEY `idx_status` (`status`), KEY `idx_processed_date` (`processed_date`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ===================================================== -- 6. AUDIT AND COMPLIANCE -- ===================================================== -- Audit trail for all changes CREATE TABLE IF NOT EXISTS `llx_declarationtva_audit_trail` ( `rowid` int(11) NOT NULL AUTO_INCREMENT, `entity` int(11) NOT NULL DEFAULT 1, `table_name` varchar(64) NOT NULL, `record_id` int(11) NOT NULL, `action` varchar(16) NOT NULL COMMENT 'INSERT, UPDATE, DELETE', `old_values` longtext DEFAULT NULL COMMENT 'JSON of old values', `new_values` longtext DEFAULT NULL COMMENT 'JSON of new values', `user_id` int(11) DEFAULT NULL, `ip_address` varchar(45) DEFAULT NULL, `user_agent` varchar(255) DEFAULT NULL, `created_date` datetime DEFAULT NULL, PRIMARY KEY (`rowid`), KEY `idx_table_record` (`table_name`, `record_id`), KEY `idx_action` (`action`), KEY `idx_user_id` (`user_id`), KEY `idx_created_date` (`created_date`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- Compliance validation results CREATE TABLE IF NOT EXISTS `llx_declarationtva_compliance` ( `rowid` int(11) NOT NULL AUTO_INCREMENT, `entity` int(11) NOT NULL DEFAULT 1, `declaration_id` int(11) NOT NULL, `validation_type` varchar(32) NOT NULL COMMENT 'vat_calculation, period_validation, etc.', `validation_status` varchar(16) DEFAULT 'pending' COMMENT 'pending, passed, failed', `validation_message` text DEFAULT NULL, `validation_details` longtext DEFAULT NULL COMMENT 'JSON with validation details', `validated_date` datetime DEFAULT NULL, `validated_by` int(11) DEFAULT NULL, `created_date` datetime DEFAULT NULL, PRIMARY KEY (`rowid`), KEY `idx_declaration_id` (`declaration_id`), KEY `idx_validation_type` (`validation_type`), KEY `idx_validation_status` (`validation_status`), CONSTRAINT `fk_compliance_declaration` FOREIGN KEY (`declaration_id`) REFERENCES `llx_declarationtva_declarations` (`rowid`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ===================================================== -- 7. INTEGRATION AND EXPORT -- ===================================================== -- Export history and tracking CREATE TABLE IF NOT EXISTS `llx_declarationtva_exports` ( `rowid` int(11) NOT NULL AUTO_INCREMENT, `entity` int(11) NOT NULL DEFAULT 1, `declaration_id` int(11) NOT NULL, `export_type` varchar(16) NOT NULL COMMENT 'pdf, xml, csv, excel', `export_format` varchar(32) DEFAULT NULL, `file_path` varchar(255) DEFAULT NULL, `file_size` int(11) DEFAULT NULL, `export_status` varchar(16) DEFAULT 'success' COMMENT 'success, error, pending', `error_message` text DEFAULT NULL, `exported_date` datetime DEFAULT NULL, `exported_by` int(11) DEFAULT NULL, `created_date` datetime DEFAULT NULL, PRIMARY KEY (`rowid`), KEY `idx_declaration_id` (`declaration_id`), KEY `idx_export_type` (`export_type`), KEY `idx_export_status` (`export_status`), KEY `idx_exported_date` (`exported_date`), CONSTRAINT `fk_export_declaration` FOREIGN KEY (`declaration_id`) REFERENCES `llx_declarationtva_declarations` (`rowid`) ON DELETE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- ===================================================== -- 8. INITIAL DATA AND CONFIGURATION -- ===================================================== -- Insert default configuration INSERT INTO `llx_declarationtva_config` (`entity`, `config_key`, `config_value`, `config_type`, `config_desc`, `created_date`) VALUES (1, 'module_version', '1.0.0', 'string', 'Module version', NOW()), (1, 'default_period_type', 'quarterly', 'string', 'Default declaration period type', NOW()), (1, 'auto_calculation', '1', 'boolean', 'Enable automatic VAT calculations', NOW()), (1, 'eu_autoliquidation', '1', 'boolean', 'Enable EU autoliquidation automation', NOW()), (1, 'oss_threshold', '10000.00', 'decimal', 'OSS threshold for B2C sales', NOW()), (1, 'vat_rates', '20.00,10.00,5.50,2.10,0.00', 'string', 'Supported VAT rates', NOW()), (1, 'declaration_language', 'fr', 'string', 'Default declaration language', NOW()), (1, 'pdf_template', 'ca3_standard', 'string', 'PDF template for declarations', NOW()), (1, 'xml_export', '1', 'boolean', 'Enable XML export for tax authorities', NOW()), (1, 'email_notifications', '1', 'boolean', 'Enable email notifications', NOW()); -- ===================================================== -- 9. INDEXES FOR PERFORMANCE -- ===================================================== -- Additional indexes for performance optimization CREATE INDEX `idx_declarationtva_periods_dates` ON `llx_declarationtva_periods` (`start_date`, `end_date`); CREATE INDEX `idx_declarationtva_declarations_period_status` ON `llx_declarationtva_declarations` (`period_id`, `status`); CREATE INDEX `idx_declarationtva_account_mappings_line_active` ON `llx_declarationtva_account_mappings` (`ca3_line`, `is_active`); CREATE INDEX `idx_declarationtva_eu_transactions_period_type` ON `llx_declarationtva_eu_transactions` (`period_id`, `transaction_type`); CREATE INDEX `idx_declarationtva_workflow_log_trigger_date` ON `llx_declarationtva_workflow_log` (`trigger_type`, `processed_date`); CREATE INDEX `idx_declarationtva_audit_trail_table_date` ON `llx_declarationtva_audit_trail` (`table_name`, `created_date`); -- ===================================================== -- 10. VIEWS FOR REPORTING -- ===================================================== -- View for declaration summary CREATE VIEW `v_declarationtva_summary` AS SELECT d.rowid, d.entity, d.declaration_number, d.status, p.period_name, p.period_type, p.start_date, p.end_date, d.total_vat_collected, d.total_vat_deductible, d.net_vat_due, d.vat_credit, d.submission_date, d.approval_date, d.created_date, d.modified_date FROM `llx_declarationtva_declarations` d LEFT JOIN `llx_declarationtva_periods` p ON d.period_id = p.rowid; -- View for account mapping summary CREATE VIEW `v_declarationtva_account_mappings` AS SELECT am.rowid, am.entity, am.ca3_line, am.account_code, am.account_label, am.vat_rate, am.account_type, am.is_active, am.weight, am.sort_order, aa.label as account_full_label, aa.account_number as account_number FROM `llx_declarationtva_account_mappings` am LEFT JOIN `llx_accounting_account` aa ON am.account_code = aa.account_number; -- ===================================================== -- END OF SCHEMA -- =====================================================