From 3773c3f1235a1a04b0c4ffb851facc92928a1c62 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Florian=20=22flowdy=22=20He=C3=9F?= Date: Sat, 14 Jan 2017 09:50:16 +0100 Subject: [PATCH] Various changes and fixes: Added report, etc. Tests pass. * reworked and used TrsrDB::expand_ids more tightly * account item selection in TrsrDB::make_transfers * web_auth / User relation for coming HTTP interface * income and target inter-relations between TrsrDB::Credit and TrsrDB::Debit * Transfer note * reactivated enforceFixedCredit to take effect unless _temp table is empty * added CreditsInFocus and Report views --- TrsrDB.pm | 45 +++++++++++++++++---------- TrsrDB/Account.pm | 4 +++ TrsrDB/Credit.pm | 7 ++++- TrsrDB/Debit.pm | 5 +++ TrsrDB/Transfer.pm | 1 + schema.sql | 77 +++++++++++++++++++++++++++++++++++++++------- t/schema.t | 2 +- 7 files changed, 111 insertions(+), 30 deletions(-) diff --git a/TrsrDB.pm b/TrsrDB.pm index 4c89a8d..d3af68f 100644 --- a/TrsrDB.pm +++ b/TrsrDB.pm @@ -6,7 +6,7 @@ use Carp qw/croak/; __PACKAGE__->load_classes(qw| Account Debit Credit Transfer CurrentArrears AvailableCredits - Balance ReconstructedBankStatement History + Balance Report ReconstructedBankStatement History User |); sub import { @@ -41,15 +41,15 @@ sub make_transfers { while ( my ($src, $tgt) = splice @pairs, 0, 2 ) { - $rs = $self->resultset("AvailableCredits")->search({ - credId => [ -or => _expand_ids($src) ] - }); + $rs = $self->resultset("AvailableCredits")->search( + expand_ids($src => 'credId' ) + ); $src = [ $rs->get_column('credId')->all ]; $src_total += $rs->get_column('difference')->sum; - $rs = $self->resultset("CurrentArrears")->search({ - billId => [ -or => _expand_ids( $tgt ) ] - }); + $rs = $self->resultset("CurrentArrears")->search( + expand_ids( $tgt => 'billId' ) + ); $tgt = [ $rs->get_column('billId')->all ]; $tgt_total += $rs->get_column('difference')->sum; @@ -99,31 +99,42 @@ sub make_transfers { } -sub _expand_ids { - my ($ids) = @_; +sub expand_ids { + my ($ids, $default_slot) = @_; my @ids = map { m{ \A (\d+) - (\d+) \z }xms ? [ $1 .. $2 ] : $_ } ref $ids ? @$ids : split q{,}, $ids ; - my (@alternatives, @raws); + my (@alternatives, %raws); for my $id ( @ids ) { + + my $slot = ref $id ? $default_slot + : $id =~ s{^p(urpose)?:}{}i ? "purpose" + : $id =~ s{^d(ate)?:}{}i ? "date" + : $id =~ s{^v(alue)?:}{}i ? "value" + : $default_slot + ; + if ( ref $id eq 'ARRAY' ) { - push @raws, @$ids; + $raws{$slot}{'-in'}, @$ids; } elsif ( $id eq '*' ) { - @alternatives = ({ -not_in => [] }); + @alternatives = ( $slot => { -not_in => [] }); } elsif ( $id =~ s{([%*_?])}{ $1 eq '*' ? '%' : $1 eq '?' ? '_' : $1 }eg ) { - push @alternatives, { -like => $id }; - } - else { - push @raws, $id; + push @alternatives, { $slot => { -like => $id } }; } + else { push @{ $raws{$slot}{'-like'} }, $id } } - push @alternatives, @raws ? { -in => \@raws } : (); + while ( my @v = each %raws ) { push @alternatives, { @v } } return \@alternatives; } + +sub user { + shift->resultset("User")->find(shift); +} + 1; diff --git a/TrsrDB/Account.pm b/TrsrDB/Account.pm index 6607f06..357a65c 100644 --- a/TrsrDB/Account.pm +++ b/TrsrDB/Account.pm @@ -34,5 +34,9 @@ __PACKAGE__->has_many( history => 'TrsrDB::History', { 'foreign.account' => 'self.ID' } ); +__PACKAGE__->has_many( + report => 'TrsrDB::Report', + { 'foreign.account' => 'self.ID' } +); 1; diff --git a/TrsrDB/Credit.pm b/TrsrDB/Credit.pm index a2d76cf..0809c2d 100644 --- a/TrsrDB/Credit.pm +++ b/TrsrDB/Credit.pm @@ -19,7 +19,12 @@ __PACKAGE__->belongs_to( __PACKAGE__->has_many( outgoings => 'TrsrDB::Transfer', - { 'foreign.fromCredit' => 'self.Id' } + { 'foreign.fromCredit' => 'self.credId' } +); + +__PACKAGE__->has_many( + income => 'TrsrDB::Debit', + { 'foreign.targetCredit' => 'self.credId' } ); __PACKAGE__->many_to_many( diff --git a/TrsrDB/Debit.pm b/TrsrDB/Debit.pm index edf83bb..6ca498b 100644 --- a/TrsrDB/Debit.pm +++ b/TrsrDB/Debit.pm @@ -18,6 +18,11 @@ __PACKAGE__->belongs_to( { 'foreign.ID' => 'self.debtor' } ); +__PACKAGE__->might_have( + target => 'TrsrDB::Credit', + { 'foreign.credId' => 'self.targetCredit' } +); + __PACKAGE__->has_many( incomings => 'TrsrDB::Transfer', 'billId' ); diff --git a/TrsrDB/Transfer.pm b/TrsrDB/Transfer.pm index a826ae3..fe99cf3 100644 --- a/TrsrDB/Transfer.pm +++ b/TrsrDB/Transfer.pm @@ -8,6 +8,7 @@ __PACKAGE__->add_column("timestamp" => { data_type => 'TIMESTAMP' }); __PACKAGE__->add_column("billId"); __PACKAGE__->add_column("credId" => { data_type => 'INTEGER' }); __PACKAGE__->add_column("amount" => { data_type => 'INTEGER', nullable => 1 }); +__PACKAGE__->add_column("note" => { nullable => 1 }); __PACKAGE__->set_primary_key("billId", "credId"); __PACKAGE__->belongs_to( diff --git a/schema.sql b/schema.sql index 240e812..40ffb34 100644 --- a/schema.sql +++ b/schema.sql @@ -43,12 +43,18 @@ CREATE TABLE Transfer ( billId INTEGER NOT NULL, credId INTEGER NOT NULL, amount INTEGER, -- for later traceability, necessary when revoking transfers + note, FOREIGN KEY (billId) REFERENCES Debit(billId), FOREIGN KEY (credId) REFERENCES Credit(credId), UNIQUE (billId, credId) ); -CREATE TABLE IF NOT EXISTS _temp (d, c, m); +-- For internal purposes: Memory of rebalance triggers +CREATE TABLE _temp (d, c, m); + +-- Only for use of HTTP interface +CREATE TABLE web_auth ( user_id primary key, password, grade not null, username, email ); + CREATE TRIGGER balanceTransfer AFTER INSERT ON Transfer BEGIN @@ -149,7 +155,7 @@ BEGIN SELECT RAISE(FAIL, "Transfer cannot be updated, but needs to be replaced to make triggers run"); END; -CREATE TRIGGER enforceiZeroPaidAtStart +CREATE TRIGGER enforceZeroPaidAtStart BEFORE INSERT ON Debit BEGIN SELECT RAISE(FAIL, "Debt must be initially unpaid") @@ -226,8 +232,8 @@ BEGIN END; -CREATE TRIGGER enforceFixedDebits - BEFORE UPDATE OF value ON Debit +CREATE TRIGGER enforceFixedDebit + BEFORE UPDATE OF debtor, transferCredit, value ON Debit WHEN EXISTS (SELECT * FROM Transfer WHERE billId=NEW.billId) BEGIN SELECT RAISE(FAIL, "Debt is involved in transfers to revoke at first"); @@ -250,12 +256,13 @@ BEGIN WHERE (NEW.spent + IFNULL((SELECT m FROM _temp WHERE c IS NULL AND d IS NULL),0) ) <> OLD.spent; END; --- CREATE TRIGGER enforceFixedCredit --- BEFORE UPDATE OF value ON Credit --- BEGIN --- SELECT RAISE(FAIL, "Credit involved in transactions to revoke at first") --- WHERE EXISTS (SELECT * FROM Transfer WHERE credId=NEW.credId); --- END; +CREATE TRIGGER enforceFixedCredit + BEFORE UPDATE OF account, value ON Credit + WHEN NOT EXISTS (SELECT * FROM _temp) +BEGIN + SELECT RAISE(FAIL, "Credit involved in transactions to revoke at first") + WHERE EXISTS (SELECT * FROM Transfer WHERE credId=NEW.credId); +END; CREATE TRIGGER checkIBANatTransfer BEFORE INSERT ON Debit @@ -367,7 +374,7 @@ CREATE VIEW ReconstructedBankStatement AS c.value AS credit, NULL AS debit FROM Credit AS c - LEFT OUTER JOIN Debit AS d ON c.credId=d.targetCredit + LEFT OUTER JOIN Debit AS d ON c.credId = d.targetCredit GROUP BY c.credId HAVING count(d.billId) == 0 -- exclude internal transfers UNION @@ -380,3 +387,51 @@ CREATE VIEW ReconstructedBankStatement AS WHERE targetCredit IS NULL -- exclude internal transfers ORDER BY date ASC ; + +-- Credits that have not been used yet and any subsequent ones +CREATE VIEW CreditsInFocus AS + SELECT account, date, credId, value, purpose + FROM Credit + WHERE value > spent + UNION + SELECT c.account, date, credId, value, purpose + FROM Credit c + JOIN Balance b ON b.ID = c.account + WHERE c.date >= b.even_until + GROUP BY c.credId +; + +-- Report view may be of use in communication with club members who are due +-- of outstanding fees, listing what they have paid and what is yet to pay. +CREATE VIEW Report AS + SELECT * + FROM ( + SELECT account, date, credId, value, purpose -- relevant incomes + FROM CreditsInFocus + UNION + SELECT debtor AS account, -- partial payments + DATE(t.timestamp) + AS date, + t.credId AS credId, + t.amount * -1 AS value, + d.purpose || ' [' || d.billId || ']' + || CASE WHEN t.note IS NULL + THEN '' + ELSE ( x'0a' || '(' || t.note || ')' ) + END + AS purpose + FROM Debit d + JOIN Transfer t ON t.billId = d.billId + JOIN CreditsInFocus fc ON fc.credId=t.credId + UNION + SELECT debtor AS account, -- current arrears + date, + NULL AS credId, + difference * -1 AS value, + purpose || ' [' || billId || ']' + || x'0a' || '(YET TO PAY)' + FROM CurrentArrears + ) + ORDER BY account, credId IS NULL, credId, + value < 0, date ASC +; diff --git a/t/schema.t b/t/schema.t index 162527f..c059b37 100644 --- a/t/schema.t +++ b/t/schema.t @@ -49,7 +49,7 @@ while ( my ($num, $month) = each %months ) { billId => "MB$yy$num/john", debtor => "john", targetCredit => 1, - date => "16-05-01", + date => "$yy-$num-01", purpose => "Membership fee $month", value => 600 });