Remove data.csv file and update README to reflect new features including CSV import and banking account management. Enhance TransactionsTable and KreditorTable components with banking account handling, including UI updates and validation logic. Update SQL schema to support banking accounts and adjust API routes for improved data handling. Implement new document rendering logic for banking transactions and enhance recipient rendering with banking account status. Add new views and indexes for better transaction management.
This commit is contained in:
124
src/database/csv_transactions_schema.sql
Normal file
124
src/database/csv_transactions_schema.sql
Normal file
@@ -0,0 +1,124 @@
|
||||
-- CSV Transactions Import Schema
|
||||
-- This script creates a table to store imported CSV transaction data
|
||||
|
||||
-- Create CSVTransactions table to store imported CSV data
|
||||
CREATE TABLE fibdash.CSVTransactions (
|
||||
id INT IDENTITY(1,1) PRIMARY KEY,
|
||||
|
||||
-- Original CSV columns (German names as they appear in CSV)
|
||||
buchungstag NVARCHAR(50), -- "Buchungstag"
|
||||
wertstellung NVARCHAR(50), -- "Wertstellung"
|
||||
umsatzart NVARCHAR(100), -- "Umsatzart"
|
||||
betrag DECIMAL(15,2), -- "Betrag" (numeric value)
|
||||
betrag_original NVARCHAR(50), -- Original string from CSV
|
||||
waehrung NVARCHAR(10), -- "Waehrung"
|
||||
beguenstigter_zahlungspflichtiger NVARCHAR(500), -- "Beguenstigter/Zahlungspflichtiger"
|
||||
kontonummer_iban NVARCHAR(50), -- "Kontonummer/IBAN"
|
||||
bic NVARCHAR(20), -- "BIC"
|
||||
verwendungszweck NVARCHAR(1000), -- "Verwendungszweck"
|
||||
|
||||
-- Processed/computed fields
|
||||
parsed_date DATE, -- Parsed buchungstag
|
||||
numeric_amount DECIMAL(15,2), -- Processed amount
|
||||
|
||||
-- Import metadata
|
||||
import_date DATETIME2 NOT NULL DEFAULT GETDATE(),
|
||||
import_batch_id NVARCHAR(100), -- To group imports from same file
|
||||
source_filename NVARCHAR(255), -- Original CSV filename
|
||||
source_row_number INT, -- Row number in original CSV
|
||||
|
||||
-- Processing status
|
||||
is_processed BIT NOT NULL DEFAULT 0, -- Whether this transaction has been processed
|
||||
processing_notes NVARCHAR(500), -- Any processing notes or errors
|
||||
|
||||
-- Create indexes for performance
|
||||
INDEX IX_CSVTransactions_IBAN (kontonummer_iban),
|
||||
INDEX IX_CSVTransactions_Date (parsed_date),
|
||||
INDEX IX_CSVTransactions_Amount (numeric_amount),
|
||||
INDEX IX_CSVTransactions_ImportBatch (import_batch_id),
|
||||
INDEX IX_CSVTransactions_Processed (is_processed)
|
||||
);
|
||||
|
||||
-- Update BankingAccountTransactions to reference CSVTransactions
|
||||
-- Add a new column to support both AccountingItems and CSVTransactions
|
||||
ALTER TABLE fibdash.BankingAccountTransactions
|
||||
ADD csv_transaction_id INT NULL;
|
||||
|
||||
-- Add foreign key constraint
|
||||
ALTER TABLE fibdash.BankingAccountTransactions
|
||||
ADD CONSTRAINT FK_BankingAccountTransactions_CSVTransactions
|
||||
FOREIGN KEY (csv_transaction_id) REFERENCES fibdash.CSVTransactions(id);
|
||||
|
||||
-- Create index for the new column
|
||||
CREATE INDEX IX_BankingAccountTransactions_CSVTransactionId
|
||||
ON fibdash.BankingAccountTransactions(csv_transaction_id);
|
||||
|
||||
-- Update the view to include CSV transactions
|
||||
DROP VIEW IF EXISTS fibdash.vw_TransactionsWithKreditors;
|
||||
GO
|
||||
|
||||
CREATE VIEW fibdash.vw_TransactionsWithKreditors AS
|
||||
-- AccountingItems transactions
|
||||
SELECT
|
||||
'AccountingItems' as source_table,
|
||||
ai.id as transaction_id,
|
||||
NULL as csv_transaction_id,
|
||||
ai.umsatz_brutto as amount,
|
||||
ai.buchungsdatum as transaction_date,
|
||||
NULL as kontonummer_iban, -- AccountingItems uses gegenkonto
|
||||
ai.buchungstext as description,
|
||||
k.name as kreditor_name,
|
||||
k.kreditorId as kreditor_id,
|
||||
k.is_banking as kreditor_is_banking,
|
||||
bat.assigned_kreditor_id,
|
||||
ak.name as assigned_kreditor_name,
|
||||
ak.kreditorId as assigned_kreditor_id_code,
|
||||
bat.assigned_date,
|
||||
bat.notes as assignment_notes,
|
||||
CASE
|
||||
WHEN k.is_banking = 1 AND bat.assigned_kreditor_id IS NOT NULL THEN 'banking_assigned'
|
||||
WHEN k.is_banking = 1 AND bat.assigned_kreditor_id IS NULL THEN 'banking_unassigned'
|
||||
WHEN k.is_banking = 0 THEN 'regular_kreditor'
|
||||
ELSE 'no_kreditor'
|
||||
END as transaction_type
|
||||
FROM fibdash.AccountingItems ai
|
||||
LEFT JOIN fibdash.Kreditor k ON ai.gegenkonto = k.kreditorId
|
||||
LEFT JOIN fibdash.BankingAccountTransactions bat ON ai.id = bat.transaction_id
|
||||
LEFT JOIN fibdash.Kreditor ak ON bat.assigned_kreditor_id = ak.id
|
||||
|
||||
UNION ALL
|
||||
|
||||
-- CSV transactions
|
||||
SELECT
|
||||
'CSVTransactions' as source_table,
|
||||
NULL as transaction_id,
|
||||
csv.id as csv_transaction_id,
|
||||
csv.numeric_amount as amount,
|
||||
csv.parsed_date as transaction_date,
|
||||
csv.kontonummer_iban,
|
||||
csv.verwendungszweck as description,
|
||||
k.name as kreditor_name,
|
||||
k.kreditorId as kreditor_id,
|
||||
k.is_banking as kreditor_is_banking,
|
||||
bat.assigned_kreditor_id,
|
||||
ak.name as assigned_kreditor_name,
|
||||
ak.kreditorId as assigned_kreditor_id_code,
|
||||
bat.assigned_date,
|
||||
bat.notes as assignment_notes,
|
||||
CASE
|
||||
WHEN k.is_banking = 1 AND bat.assigned_kreditor_id IS NOT NULL THEN 'banking_assigned'
|
||||
WHEN k.is_banking = 1 AND bat.assigned_kreditor_id IS NULL THEN 'banking_unassigned'
|
||||
WHEN k.is_banking = 0 THEN 'regular_kreditor'
|
||||
ELSE 'no_kreditor'
|
||||
END as transaction_type
|
||||
FROM fibdash.CSVTransactions csv
|
||||
LEFT JOIN fibdash.Kreditor k ON csv.kontonummer_iban = k.iban
|
||||
LEFT JOIN fibdash.BankingAccountTransactions bat ON csv.id = bat.csv_transaction_id
|
||||
LEFT JOIN fibdash.Kreditor ak ON bat.assigned_kreditor_id = ak.id;
|
||||
|
||||
GO
|
||||
|
||||
PRINT 'CSV Transactions schema created successfully!';
|
||||
PRINT 'Created CSVTransactions table';
|
||||
PRINT 'Updated BankingAccountTransactions table';
|
||||
PRINT 'Updated vw_TransactionsWithKreditors view';
|
||||
@@ -9,17 +9,20 @@ GO
|
||||
|
||||
-- Create Kreditor table
|
||||
-- Multiple IBANs can have the same kreditor name and kreditorId
|
||||
-- IBAN can be NULL for Kreditors that don't have an IBAN (for banking account assignments)
|
||||
-- is_banking flag indicates if this IBAN represents a banking account (like PayPal) rather than a direct creditor
|
||||
CREATE TABLE fibdash.Kreditor (
|
||||
id INT IDENTITY(1,1) PRIMARY KEY,
|
||||
iban NVARCHAR(34) NOT NULL,
|
||||
iban NVARCHAR(34) NULL, -- Nullable to allow Kreditors without IBAN
|
||||
name NVARCHAR(255) NOT NULL,
|
||||
kreditorId NVARCHAR(50) NOT NULL
|
||||
kreditorId NVARCHAR(50) NOT NULL,
|
||||
is_banking BIT NOT NULL DEFAULT 0 -- 1 = banking account, 0 = regular creditor
|
||||
);
|
||||
|
||||
-- Create unique index on IBAN to prevent duplicate IBANs
|
||||
-- but allow same kreditorId and name for multiple IBANs
|
||||
ALTER TABLE fibdash.Kreditor
|
||||
ADD CONSTRAINT UQ_Kreditor_IBAN UNIQUE (iban);
|
||||
-- Create unique index on IBAN to prevent duplicate IBANs (allows NULL values)
|
||||
CREATE UNIQUE INDEX UQ_Kreditor_IBAN_NotNull
|
||||
ON fibdash.Kreditor(iban)
|
||||
WHERE iban IS NOT NULL;
|
||||
|
||||
-- Create AccountingItems table
|
||||
-- Based on CSV structure: umsatz brutto, soll/haben kz, konto, gegenkonto, bu, buchungsdatum, rechnungsnummer, buchungstext, beleglink
|
||||
@@ -86,10 +89,14 @@ CSV
|
||||
-- Create indexes for better performance
|
||||
CREATE INDEX IX_Kreditor_IBAN ON fibdash.Kreditor(iban);
|
||||
CREATE INDEX IX_Kreditor_KreditorId ON fibdash.Kreditor(kreditorId);
|
||||
CREATE INDEX IX_Kreditor_IsBanking ON fibdash.Kreditor(is_banking);
|
||||
CREATE INDEX IX_AccountingItems_Buchungsdatum ON fibdash.AccountingItems(buchungsdatum);
|
||||
CREATE INDEX IX_AccountingItems_Konto ON fibdash.AccountingItems(konto);
|
||||
CREATE INDEX IX_AccountingItems_Rechnungsnummer ON fibdash.AccountingItems(rechnungsnummer);
|
||||
CREATE INDEX IX_AccountingItems_SollHabenKz ON fibdash.AccountingItems(soll_haben_kz);
|
||||
CREATE INDEX IX_BankingAccountTransactions_TransactionId ON fibdash.BankingAccountTransactions(transaction_id);
|
||||
CREATE INDEX IX_BankingAccountTransactions_BankingIban ON fibdash.BankingAccountTransactions(banking_iban);
|
||||
CREATE INDEX IX_BankingAccountTransactions_AssignedKreditorId ON fibdash.BankingAccountTransactions(assigned_kreditor_id);
|
||||
|
||||
-- Add FK from AccountingItems.bu -> BU(bu)
|
||||
ALTER TABLE fibdash.AccountingItems
|
||||
@@ -106,6 +113,25 @@ ALTER TABLE fibdash.AccountingItems
|
||||
ADD CONSTRAINT FK_AccountingItems_Konto_Konto
|
||||
FOREIGN KEY (konto) REFERENCES fibdash.Konto(konto);
|
||||
|
||||
-- Create BankingAccountTransactions table to map banking account transactions to Kreditors
|
||||
-- This table handles cases where an IBAN is a banking account (like PayPal) and needs
|
||||
-- to be mapped to the actual creditor for accounting purposes
|
||||
CREATE TABLE fibdash.BankingAccountTransactions (
|
||||
id INT IDENTITY(1,1) PRIMARY KEY,
|
||||
transaction_id INT NOT NULL, -- References AccountingItems.id
|
||||
banking_iban NVARCHAR(34) NOT NULL, -- The banking account IBAN (e.g., PayPal)
|
||||
assigned_kreditor_id INT NOT NULL, -- References Kreditor.id for the actual creditor
|
||||
assigned_date DATETIME2 NOT NULL DEFAULT GETDATE(),
|
||||
assigned_by NVARCHAR(100), -- User who made the assignment
|
||||
notes NVARCHAR(500), -- Optional notes about the assignment
|
||||
|
||||
-- Foreign key constraints
|
||||
CONSTRAINT FK_BankingAccountTransactions_AccountingItems
|
||||
FOREIGN KEY (transaction_id) REFERENCES fibdash.AccountingItems(id),
|
||||
CONSTRAINT FK_BankingAccountTransactions_Kreditor
|
||||
FOREIGN KEY (assigned_kreditor_id) REFERENCES fibdash.Kreditor(id)
|
||||
);
|
||||
|
||||
-- Add vst column to existing BU table (for databases created before this update)
|
||||
-- IF NOT EXISTS (SELECT * FROM sys.columns WHERE object_id = OBJECT_ID('fibdash.BU') AND name = 'vst')
|
||||
-- BEGIN
|
||||
@@ -124,4 +150,28 @@ FOREIGN KEY (konto) REFERENCES fibdash.Konto(konto);
|
||||
-- ('9', '19% VST', 19.00),
|
||||
-- ('8', '7% VST', 7.00),
|
||||
-- ('506', 'Dienstleistung aus EU', NULL),
|
||||
-- ('511', 'Dienstleistung außerhalb EU', NULL);
|
||||
-- ('511', 'Dienstleistung außerhalb EU', NULL);
|
||||
|
||||
-- Create view to easily query transactions with their assigned Kreditors
|
||||
-- This view combines regular transactions with banking account assignments
|
||||
CREATE VIEW fibdash.vw_TransactionsWithKreditors AS
|
||||
SELECT
|
||||
ai.*,
|
||||
k.name as kreditor_name,
|
||||
k.kreditorId as kreditor_id,
|
||||
k.is_banking as kreditor_is_banking,
|
||||
bat.assigned_kreditor_id,
|
||||
ak.name as assigned_kreditor_name,
|
||||
ak.kreditorId as assigned_kreditor_id_code,
|
||||
bat.assigned_date,
|
||||
bat.notes as assignment_notes,
|
||||
CASE
|
||||
WHEN k.is_banking = 1 AND bat.assigned_kreditor_id IS NOT NULL THEN 'banking_assigned'
|
||||
WHEN k.is_banking = 1 AND bat.assigned_kreditor_id IS NULL THEN 'banking_unassigned'
|
||||
WHEN k.is_banking = 0 THEN 'regular_kreditor'
|
||||
ELSE 'no_kreditor'
|
||||
END as transaction_type
|
||||
FROM fibdash.AccountingItems ai
|
||||
LEFT JOIN fibdash.Kreditor k ON ai.gegenkonto = k.kreditorId
|
||||
LEFT JOIN fibdash.BankingAccountTransactions bat ON ai.id = bat.transaction_id
|
||||
LEFT JOIN fibdash.Kreditor ak ON bat.assigned_kreditor_id = ak.id;
|
||||
Reference in New Issue
Block a user