Files
Novault-backend/database/sql/schema.sql
2026-01-25 21:59:00 +08:00

525 lines
26 KiB
SQL

-- Database Schema for Accounting App
-- Generated based on GORM models
CREATE DATABASE IF NOT EXISTS `accounting_app` DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
USE `accounting_app`;
-- Users table
CREATE TABLE IF NOT EXISTS `users` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`created_at` datetime(3) DEFAULT NULL,
`updated_at` datetime(3) DEFAULT NULL,
`deleted_at` datetime(3) DEFAULT NULL,
`email` varchar(255) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`password_hash` varchar(255) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`username` varchar(100) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`avatar` varchar(500) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`is_active` tinyint(1) DEFAULT '1',
PRIMARY KEY (`id`),
UNIQUE KEY `idx_users_email` (`email`),
KEY `idx_users_deleted_at` (`deleted_at`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- OAuth Accounts table
CREATE TABLE IF NOT EXISTS `oauth_accounts` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`user_id` bigint(20) unsigned DEFAULT NULL,
`provider` varchar(50) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`provider_id` varchar(255) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`access_token` varchar(500) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`created_at` datetime(3) DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `idx_oauth_accounts_user_id` (`user_id`),
KEY `idx_oauth_accounts_provider` (`provider`),
KEY `idx_oauth_accounts_provider_id` (`provider_id`),
CONSTRAINT `fk_users_oauth_accounts` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Accounts table
CREATE TABLE IF NOT EXISTS `accounts` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`created_at` datetime(3) DEFAULT NULL,
`updated_at` datetime(3) DEFAULT NULL,
`deleted_at` datetime(3) DEFAULT NULL,
`user_id` bigint(20) unsigned NOT NULL,
`name` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL,
`type` varchar(20) COLLATE utf8mb4_unicode_ci NOT NULL,
`balance` decimal(15,2) DEFAULT '0.00',
`currency` varchar(10) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT 'CNY',
`icon` varchar(50) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`billing_date` bigint(20) DEFAULT NULL,
`payment_date` bigint(20) DEFAULT NULL,
`is_credit` tinyint(1) DEFAULT '0',
`sort_order` bigint(20) DEFAULT '0',
`warning_threshold` decimal(15,2) DEFAULT NULL,
`last_sync_time` datetime(3) DEFAULT NULL,
`account_code` varchar(50) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`account_type` varchar(20) COLLATE utf8mb4_unicode_ci DEFAULT 'asset',
`parent_account_id` bigint(20) unsigned DEFAULT NULL,
`sub_account_type` varchar(20) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`frozen_balance` decimal(15,2) DEFAULT '0.00',
`available_balance` decimal(15,2) DEFAULT '0.00',
`target_amount` decimal(15,2) DEFAULT NULL,
`target_date` date DEFAULT NULL,
`annual_rate` decimal(5,4) DEFAULT NULL,
`interest_enabled` tinyint(1) DEFAULT '0',
PRIMARY KEY (`id`),
KEY `idx_accounts_deleted_at` (`deleted_at`),
KEY `idx_accounts_user_id` (`user_id`),
KEY `idx_accounts_parent_account_id` (`parent_account_id`),
CONSTRAINT `fk_accounts_parent_account` FOREIGN KEY (`parent_account_id`) REFERENCES `accounts` (`id`) ON DELETE SET NULL ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Ledgers table
CREATE TABLE IF NOT EXISTS `ledgers` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`created_at` datetime(3) DEFAULT NULL,
`updated_at` datetime(3) DEFAULT NULL,
`deleted_at` datetime(3) DEFAULT NULL,
`user_id` bigint(20) unsigned NOT NULL,
`name` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL,
`theme` varchar(50) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`cover_image` varchar(255) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`is_default` tinyint(1) DEFAULT '0',
`sort_order` bigint(20) DEFAULT '0',
PRIMARY KEY (`id`),
KEY `idx_ledgers_deleted_at` (`deleted_at`),
KEY `idx_ledgers_user_id` (`user_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Categories table
CREATE TABLE IF NOT EXISTS `categories` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`user_id` bigint(20) unsigned NOT NULL,
`name` varchar(50) COLLATE utf8mb4_unicode_ci NOT NULL,
`icon` varchar(50) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`type` varchar(20) COLLATE utf8mb4_unicode_ci NOT NULL,
`parent_id` bigint(20) unsigned DEFAULT NULL,
`sort_order` bigint(20) DEFAULT '0',
`created_at` datetime(3) DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `idx_categories_user_id` (`user_id`),
KEY `idx_categories_parent_id` (`parent_id`),
CONSTRAINT `fk_categories_parent` FOREIGN KEY (`parent_id`) REFERENCES `categories` (`id`) ON DELETE SET NULL ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Tags table
CREATE TABLE IF NOT EXISTS `tags` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`user_id` bigint(20) unsigned NOT NULL,
`name` varchar(50) COLLATE utf8mb4_unicode_ci NOT NULL,
`color` varchar(20) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`created_at` datetime(3) DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `idx_tags_user_id` (`user_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Transactions table
CREATE TABLE IF NOT EXISTS `transactions` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`created_at` datetime(3) DEFAULT NULL,
`updated_at` datetime(3) DEFAULT NULL,
`deleted_at` datetime(3) DEFAULT NULL,
`user_id` bigint(20) unsigned NOT NULL,
`amount` decimal(15,2) NOT NULL,
`type` varchar(20) COLLATE utf8mb4_unicode_ci NOT NULL,
`category_id` bigint(20) unsigned NOT NULL,
`account_id` bigint(20) unsigned NOT NULL,
`currency` varchar(10) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT 'CNY',
`transaction_date` date NOT NULL,
`note` varchar(500) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`image_path` varchar(255) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`recurring_id` bigint(20) unsigned DEFAULT NULL,
`to_account_id` bigint(20) unsigned DEFAULT NULL,
`ledger_id` bigint(20) unsigned DEFAULT NULL,
`transaction_time` time DEFAULT NULL,
`sub_type` varchar(20) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`reimbursement_status` varchar(20) COLLATE utf8mb4_unicode_ci DEFAULT 'none',
`reimbursement_amount` decimal(15,2) DEFAULT NULL,
`reimbursement_income_id` bigint(20) unsigned DEFAULT NULL,
`refund_status` varchar(20) COLLATE utf8mb4_unicode_ci DEFAULT 'none',
`refund_amount` decimal(15,2) DEFAULT NULL,
`refund_income_id` bigint(20) unsigned DEFAULT NULL,
`original_transaction_id` bigint(20) unsigned DEFAULT NULL,
`income_type` varchar(20) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `idx_transactions_deleted_at` (`deleted_at`),
KEY `idx_transactions_user_id` (`user_id`),
KEY `idx_transactions_category_id` (`category_id`),
KEY `idx_transactions_account_id` (`account_id`),
KEY `idx_transactions_transaction_date` (`transaction_date`),
KEY `idx_transactions_recurring_id` (`recurring_id`),
KEY `idx_transactions_to_account_id` (`to_account_id`),
KEY `idx_transactions_ledger_id` (`ledger_id`),
KEY `idx_transactions_reimbursement_income_id` (`reimbursement_income_id`),
KEY `idx_transactions_refund_income_id` (`refund_income_id`),
KEY `idx_transactions_original_transaction_id` (`original_transaction_id`),
CONSTRAINT `fk_accounts_transactions` FOREIGN KEY (`account_id`) REFERENCES `accounts` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `fk_categories_transactions` FOREIGN KEY (`category_id`) REFERENCES `categories` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `fk_ledgers_transactions` FOREIGN KEY (`ledger_id`) REFERENCES `ledgers` (`id`) ON DELETE SET NULL ON UPDATE CASCADE,
CONSTRAINT `fk_original_transactions` FOREIGN KEY (`original_transaction_id`) REFERENCES `transactions` (`id`) ON DELETE SET NULL ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Transaction Tags table (Many-to-Many)
CREATE TABLE IF NOT EXISTS `transaction_tags` (
`transaction_id` bigint(20) unsigned NOT NULL,
`tag_id` bigint(20) unsigned NOT NULL,
PRIMARY KEY (`transaction_id`,`tag_id`),
KEY `fk_transaction_tags_tag` (`tag_id`),
CONSTRAINT `fk_transaction_tags_tag` FOREIGN KEY (`tag_id`) REFERENCES `tags` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `fk_transaction_tags_transaction` FOREIGN KEY (`transaction_id`) REFERENCES `transactions` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Transaction Images table
CREATE TABLE IF NOT EXISTS `transaction_images` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`transaction_id` bigint(20) unsigned NOT NULL,
`file_path` varchar(255) COLLATE utf8mb4_unicode_ci NOT NULL,
`file_name` varchar(100) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`file_size` bigint(20) DEFAULT NULL,
`mime_type` varchar(50) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`created_at` datetime(3) DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `idx_transaction_images_transaction_id` (`transaction_id`),
CONSTRAINT `fk_transactions_images` FOREIGN KEY (`transaction_id`) REFERENCES `transactions` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Recurring Transactions table
CREATE TABLE IF NOT EXISTS `recurring_transactions` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`created_at` datetime(3) DEFAULT NULL,
`updated_at` datetime(3) DEFAULT NULL,
`deleted_at` datetime(3) DEFAULT NULL,
`user_id` bigint(20) unsigned NOT NULL,
`amount` decimal(15,2) NOT NULL,
`type` varchar(20) COLLATE utf8mb4_unicode_ci NOT NULL,
`category_id` bigint(20) unsigned NOT NULL,
`account_id` bigint(20) unsigned NOT NULL,
`currency` varchar(10) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT 'CNY',
`note` varchar(500) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`frequency` varchar(20) COLLATE utf8mb4_unicode_ci NOT NULL,
`start_date` date NOT NULL,
`end_date` date DEFAULT NULL,
`next_occurrence` date NOT NULL,
`is_active` tinyint(1) DEFAULT '1',
PRIMARY KEY (`id`),
KEY `idx_recurring_transactions_deleted_at` (`deleted_at`),
KEY `idx_recurring_transactions_user_id` (`user_id`),
KEY `idx_recurring_transactions_category_id` (`category_id`),
KEY `idx_recurring_transactions_account_id` (`account_id`),
CONSTRAINT `fk_accounts_recurring_transactions` FOREIGN KEY (`account_id`) REFERENCES `accounts` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `fk_categories_recurring_transactions` FOREIGN KEY (`category_id`) REFERENCES `categories` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Add foreign key for transaction recurring_id (circular dependency)
ALTER TABLE `transactions` ADD CONSTRAINT `fk_recurring_transactions` FOREIGN KEY (`recurring_id`) REFERENCES `recurring_transactions` (`id`) ON DELETE SET NULL ON UPDATE CASCADE;
-- System Categories table
CREATE TABLE IF NOT EXISTS `system_categories` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`code` varchar(50) COLLATE utf8mb4_unicode_ci NOT NULL,
`name` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL,
`icon` varchar(100) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`type` varchar(20) COLLATE utf8mb4_unicode_ci NOT NULL,
`is_system` tinyint(1) DEFAULT '1',
PRIMARY KEY (`id`),
UNIQUE KEY `idx_system_categories_code` (`code`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Budgets table
CREATE TABLE IF NOT EXISTS `budgets` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`created_at` datetime(3) DEFAULT NULL,
`updated_at` datetime(3) DEFAULT NULL,
`deleted_at` datetime(3) DEFAULT NULL,
`user_id` bigint(20) unsigned NOT NULL,
`name` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL,
`amount` decimal(15,2) NOT NULL,
`period_type` varchar(20) COLLATE utf8mb4_unicode_ci NOT NULL,
`category_id` bigint(20) unsigned DEFAULT NULL,
`account_id` bigint(20) unsigned DEFAULT NULL,
`is_rolling` tinyint(1) DEFAULT '0',
`start_date` date NOT NULL,
`end_date` date DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `idx_budgets_deleted_at` (`deleted_at`),
KEY `idx_budgets_user_id` (`user_id`),
KEY `idx_budgets_category_id` (`category_id`),
KEY `idx_budgets_account_id` (`account_id`),
CONSTRAINT `fk_accounts_budgets` FOREIGN KEY (`account_id`) REFERENCES `accounts` (`id`) ON DELETE SET NULL ON UPDATE CASCADE,
CONSTRAINT `fk_categories_budgets` FOREIGN KEY (`category_id`) REFERENCES `categories` (`id`) ON DELETE SET NULL ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Piggy Banks table
CREATE TABLE IF NOT EXISTS `piggy_banks` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`created_at` datetime(3) DEFAULT NULL,
`updated_at` datetime(3) DEFAULT NULL,
`deleted_at` datetime(3) DEFAULT NULL,
`user_id` bigint(20) unsigned NOT NULL,
`name` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL,
`target_amount` decimal(15,2) NOT NULL,
`current_amount` decimal(15,2) DEFAULT '0.00',
`type` varchar(20) COLLATE utf8mb4_unicode_ci NOT NULL,
`target_date` date DEFAULT NULL,
`linked_account_id` bigint(20) unsigned DEFAULT NULL,
`auto_rule` varchar(255) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `idx_piggy_banks_deleted_at` (`deleted_at`),
KEY `idx_piggy_banks_user_id` (`user_id`),
KEY `idx_piggy_banks_linked_account_id` (`linked_account_id`),
CONSTRAINT `fk_accounts_piggy_banks` FOREIGN KEY (`linked_account_id`) REFERENCES `accounts` (`id`) ON DELETE SET NULL ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Allocation Rules table
CREATE TABLE IF NOT EXISTS `allocation_rules` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`created_at` datetime(3) DEFAULT NULL,
`updated_at` datetime(3) DEFAULT NULL,
`deleted_at` datetime(3) DEFAULT NULL,
`user_id` bigint(20) unsigned NOT NULL,
`name` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL,
`trigger_type` varchar(20) COLLATE utf8mb4_unicode_ci NOT NULL,
`source_account_id` bigint(20) unsigned DEFAULT NULL,
`is_active` tinyint(1) DEFAULT '1',
PRIMARY KEY (`id`),
KEY `idx_allocation_rules_deleted_at` (`deleted_at`),
KEY `idx_allocation_rules_user_id` (`user_id`),
KEY `idx_allocation_rules_source_account_id` (`source_account_id`),
CONSTRAINT `fk_accounts_allocation_rules` FOREIGN KEY (`source_account_id`) REFERENCES `accounts` (`id`) ON DELETE SET NULL ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Allocation Targets table
CREATE TABLE IF NOT EXISTS `allocation_targets` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`rule_id` bigint(20) unsigned NOT NULL,
`target_type` varchar(20) COLLATE utf8mb4_unicode_ci NOT NULL,
`target_id` bigint(20) unsigned NOT NULL,
`percentage` decimal(5,2) DEFAULT NULL,
`fixed_amount` decimal(15,2) DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `idx_allocation_targets_rule_id` (`rule_id`),
CONSTRAINT `fk_allocation_rules_targets` FOREIGN KEY (`rule_id`) REFERENCES `allocation_rules` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Allocation Records table
CREATE TABLE IF NOT EXISTS `allocation_records` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`user_id` bigint(20) unsigned NOT NULL,
`rule_id` bigint(20) unsigned NOT NULL,
`rule_name` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL,
`source_account_id` bigint(20) unsigned NOT NULL,
`total_amount` decimal(15,2) NOT NULL,
`allocated_amount` decimal(15,2) NOT NULL,
`remaining_amount` decimal(15,2) NOT NULL,
`note` varchar(500) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`created_at` datetime(3) DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `idx_allocation_records_user_id` (`user_id`),
KEY `idx_allocation_records_rule_id` (`rule_id`),
KEY `idx_allocation_records_source_account_id` (`source_account_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Allocation Record Details table
CREATE TABLE IF NOT EXISTS `allocation_record_details` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`record_id` bigint(20) unsigned NOT NULL,
`target_type` varchar(20) COLLATE utf8mb4_unicode_ci NOT NULL,
`target_id` bigint(20) unsigned NOT NULL,
`target_name` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL,
`amount` decimal(15,2) NOT NULL,
`percentage` decimal(5,2) DEFAULT NULL,
`fixed_amount` decimal(15,2) DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `idx_allocation_record_details_record_id` (`record_id`),
CONSTRAINT `fk_allocation_records_details` FOREIGN KEY (`record_id`) REFERENCES `allocation_records` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Exchange Rates table
CREATE TABLE IF NOT EXISTS `exchange_rates` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`from_currency` varchar(10) COLLATE utf8mb4_unicode_ci NOT NULL,
`to_currency` varchar(10) COLLATE utf8mb4_unicode_ci NOT NULL,
`rate` decimal(15,6) NOT NULL,
`effective_date` date NOT NULL,
PRIMARY KEY (`id`),
KEY `idx_currency_pair` (`from_currency`,`to_currency`),
KEY `idx_exchange_rates_effective_date` (`effective_date`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Classification Rules table
CREATE TABLE IF NOT EXISTS `classification_rules` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`user_id` bigint(20) unsigned NOT NULL,
`keyword` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL,
`category_id` bigint(20) unsigned NOT NULL,
`min_amount` decimal(15,2) DEFAULT NULL,
`max_amount` decimal(15,2) DEFAULT NULL,
`hit_count` bigint(20) DEFAULT '0',
PRIMARY KEY (`id`),
KEY `idx_classification_rules_user_id` (`user_id`),
KEY `idx_classification_rules_keyword` (`keyword`),
KEY `idx_classification_rules_category_id` (`category_id`),
CONSTRAINT `fk_categories_classification_rules` FOREIGN KEY (`category_id`) REFERENCES `categories` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Credit Card Bills table
CREATE TABLE IF NOT EXISTS `credit_card_bills` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`created_at` datetime(3) DEFAULT NULL,
`updated_at` datetime(3) DEFAULT NULL,
`deleted_at` datetime(3) DEFAULT NULL,
`user_id` bigint(20) unsigned NOT NULL,
`account_id` bigint(20) unsigned NOT NULL,
`billing_date` date NOT NULL,
`payment_due_date` date NOT NULL,
`previous_balance` decimal(15,2) DEFAULT '0.00',
`total_spending` decimal(15,2) DEFAULT '0.00',
`total_payment` decimal(15,2) DEFAULT '0.00',
`current_balance` decimal(15,2) DEFAULT '0.00',
`minimum_payment` decimal(15,2) DEFAULT '0.00',
`status` varchar(20) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT 'pending',
`paid_amount` decimal(15,2) DEFAULT '0.00',
`paid_at` datetime(3) DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `idx_credit_card_bills_deleted_at` (`deleted_at`),
KEY `idx_credit_card_bills_user_id` (`user_id`),
KEY `idx_credit_card_bills_account_id` (`account_id`),
KEY `idx_credit_card_bills_billing_date` (`billing_date`),
KEY `idx_credit_card_bills_payment_due_date` (`payment_due_date`),
CONSTRAINT `fk_accounts_credit_card_bills` FOREIGN KEY (`account_id`) REFERENCES `accounts` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Repayment Plans table
CREATE TABLE IF NOT EXISTS `repayment_plans` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`created_at` datetime(3) DEFAULT NULL,
`updated_at` datetime(3) DEFAULT NULL,
`deleted_at` datetime(3) DEFAULT NULL,
`user_id` bigint(20) unsigned NOT NULL,
`bill_id` bigint(20) unsigned NOT NULL,
`total_amount` decimal(15,2) NOT NULL,
`remaining_amount` decimal(15,2) NOT NULL,
`installment_count` bigint(20) NOT NULL,
`installment_amount` decimal(15,2) NOT NULL,
`status` varchar(20) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT 'active',
PRIMARY KEY (`id`),
UNIQUE KEY `idx_repayment_plans_bill_id` (`bill_id`),
KEY `idx_repayment_plans_deleted_at` (`deleted_at`),
KEY `idx_repayment_plans_user_id` (`user_id`),
CONSTRAINT `fk_credit_card_bills_repayment_plan` FOREIGN KEY (`bill_id`) REFERENCES `credit_card_bills` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Repayment Installments table
CREATE TABLE IF NOT EXISTS `repayment_installments` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`created_at` datetime(3) DEFAULT NULL,
`updated_at` datetime(3) DEFAULT NULL,
`deleted_at` datetime(3) DEFAULT NULL,
`plan_id` bigint(20) unsigned NOT NULL,
`due_date` date NOT NULL,
`amount` decimal(15,2) NOT NULL,
`paid_amount` decimal(15,2) DEFAULT '0.00',
`status` varchar(20) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT 'pending',
`paid_at` datetime(3) DEFAULT NULL,
`sequence` bigint(20) NOT NULL,
PRIMARY KEY (`id`),
KEY `idx_repayment_installments_deleted_at` (`deleted_at`),
KEY `idx_repayment_installments_plan_id` (`plan_id`),
KEY `idx_repayment_installments_due_date` (`due_date`),
CONSTRAINT `fk_repayment_plans_installments` FOREIGN KEY (`plan_id`) REFERENCES `repayment_plans` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Payment Reminders table
CREATE TABLE IF NOT EXISTS `payment_reminders` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`bill_id` bigint(20) unsigned NOT NULL,
`installment_id` bigint(20) unsigned DEFAULT NULL,
`reminder_date` date NOT NULL,
`message` varchar(500) COLLATE utf8mb4_unicode_ci NOT NULL,
`is_read` tinyint(1) DEFAULT '0',
`created_at` datetime(3) DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `idx_payment_reminders_bill_id` (`bill_id`),
KEY `idx_payment_reminders_installment_id` (`installment_id`),
KEY `idx_payment_reminders_reminder_date` (`reminder_date`),
CONSTRAINT `fk_credit_card_bills_reminders` FOREIGN KEY (`bill_id`) REFERENCES `credit_card_bills` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `fk_repayment_installments_reminder` FOREIGN KEY (`installment_id`) REFERENCES `repayment_installments` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- App Locks table
CREATE TABLE IF NOT EXISTS `app_locks` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`user_id` bigint(20) unsigned NOT NULL,
`password_hash` varchar(255) COLLATE utf8mb4_unicode_ci NOT NULL,
`is_enabled` tinyint(1) DEFAULT '0',
`failed_attempts` bigint(20) DEFAULT '0',
`locked_until` datetime(3) DEFAULT NULL,
`last_failed_attempt` datetime(3) DEFAULT NULL,
`created_at` datetime(3) DEFAULT NULL,
`updated_at` datetime(3) DEFAULT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `idx_app_locks_user_id` (`user_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Transaction Templates table
CREATE TABLE IF NOT EXISTS `transaction_templates` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`user_id` bigint(20) unsigned DEFAULT NULL,
`name` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL,
`amount` decimal(15,2) DEFAULT NULL,
`type` varchar(20) COLLATE utf8mb4_unicode_ci NOT NULL,
`category_id` bigint(20) unsigned NOT NULL,
`account_id` bigint(20) unsigned NOT NULL,
`currency` varchar(10) COLLATE utf8mb4_unicode_ci NOT NULL DEFAULT 'CNY',
`note` varchar(500) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`sort_order` bigint(20) DEFAULT '0',
`created_at` datetime(3) DEFAULT NULL,
`updated_at` datetime(3) DEFAULT NULL,
PRIMARY KEY (`id`),
KEY `idx_transaction_templates_user_id` (`user_id`),
CONSTRAINT `fk_accounts_templates` FOREIGN KEY (`account_id`) REFERENCES `accounts` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `fk_categories_templates` FOREIGN KEY (`category_id`) REFERENCES `categories` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- User Preferences table
CREATE TABLE IF NOT EXISTS `user_preferences` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`user_id` bigint(20) unsigned DEFAULT NULL,
`last_account_id` bigint(20) unsigned DEFAULT NULL,
`last_category_id` bigint(20) unsigned DEFAULT NULL,
`frequent_accounts` varchar(500) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`frequent_categories` varchar(500) COLLATE utf8mb4_unicode_ci DEFAULT NULL,
`created_at` datetime(3) DEFAULT NULL,
`updated_at` datetime(3) DEFAULT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `idx_user_preferences_user_id` (`user_id`),
KEY `idx_user_preferences_last_account_id` (`last_account_id`),
KEY `idx_user_preferences_last_category_id` (`last_category_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- User Settings table
CREATE TABLE IF NOT EXISTS `user_settings` (
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT,
`user_id` bigint(20) unsigned DEFAULT NULL,
`precise_time_enabled` tinyint(1) DEFAULT '1',
`icon_layout` varchar(10) COLLATE utf8mb4_unicode_ci DEFAULT 'five',
`image_compression` varchar(10) COLLATE utf8mb4_unicode_ci DEFAULT 'medium',
`show_reimbursement_btn` tinyint(1) DEFAULT '1',
`show_refund_btn` tinyint(1) DEFAULT '1',
`current_ledger_id` bigint(20) unsigned DEFAULT NULL,
`default_expense_account_id` bigint(20) unsigned DEFAULT NULL,
`default_income_account_id` bigint(20) unsigned DEFAULT NULL,
`created_at` datetime(3) DEFAULT NULL,
`updated_at` datetime(3) DEFAULT NULL,
PRIMARY KEY (`id`),
UNIQUE KEY `idx_user_settings_user_id` (`user_id`),
KEY `idx_user_settings_current_ledger_id` (`current_ledger_id`),
KEY `idx_user_settings_default_expense_account` (`default_expense_account_id`),
KEY `idx_user_settings_default_income_account` (`default_income_account_id`),
CONSTRAINT `fk_users_settings` FOREIGN KEY (`user_id`) REFERENCES `users` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `fk_user_settings_default_expense` FOREIGN KEY (`default_expense_account_id`) REFERENCES `accounts` (`id`) ON DELETE SET NULL ON UPDATE CASCADE,
CONSTRAINT `fk_user_settings_default_income` FOREIGN KEY (`default_income_account_id`) REFERENCES `accounts` (`id`) ON DELETE SET NULL ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;