Fixes and tests for indirect transfers. Extended balance.

TrsrDB:
    fixed Id -> credId
    autobalance -> make_transfers

TrsrDB::Account:
    added history accessor
TrsrDB::Balance:
    added fieds earned spent and even_until, renamed credit to available
TrsrDB::CurrentArrears:
    fixed account -> debtor in relation declaration
schema.sql:
    fixed triggers
    deactivated trigger enforceFixedCredit
    extended Balance with some more fields
t/schema.{sql,out}
    trivial fixes
t/schema.t added tests:
    Get balances after transfers
    partial use of credit,
    indirect transfers
This commit is contained in:
Florian "flowdy" Heß 2016-07-06 22:28:56 +02:00
parent bc37ee316b
commit 8459e9ae48
8 changed files with 137 additions and 76 deletions

View File

@ -23,7 +23,7 @@ sub import {
);
}
sub autobalance {
sub make_transfers {
my ($self, @pairs) = @_;
my $from_to = [
@ -32,7 +32,7 @@ sub autobalance {
];
my $to_from = [
undef, CurrentArrears => 'billId',
payable_with => 'Id', undef
payable_with => 'credId', undef
];
my $transfers = $self->resultset('Transfer');

View File

@ -30,5 +30,9 @@ __PACKAGE__->has_many(
__PACKAGE__->has_one(
balance => 'TrsrDB::Balance', 'ID'
);
__PACKAGE__->has_many(
history => 'TrsrDB::History',
{ 'foreign.account' => 'self.ID' }
);
1;

View File

@ -4,7 +4,7 @@ package TrsrDB::Balance;
use base qw/DBIx::Class::Core/;
__PACKAGE__->table("Balance");
__PACKAGE__->add_columns(qw/ID credit promised arrears/);
__PACKAGE__->add_columns(qw/ ID available earned promised spent arrears even_until /);
__PACKAGE__->set_primary_key("ID");
__PACKAGE__->belongs_to(

View File

@ -8,12 +8,12 @@ __PACKAGE__->add_columns(qw/billId debtor targetCredit date purpose difference/)
__PACKAGE__->set_primary_key("billId");
__PACKAGE__->belongs_to(
account => 'TrsrDB::Account',
{ 'foreign.ID' => 'self.account' }
debtor => 'TrsrDB::Account',
{ 'foreign.ID' => 'self.debtor' }
);
__PACKAGE__->many_to_many(
payable_with => account => 'available_credits'
payable_with => debtor => 'available_credits'
);
1;

View File

@ -84,20 +84,14 @@ BEGIN
END
WHERE billId=NEW.billId;
UPDATE Credit
SET value = value + (SELECT m FROM _temp)
WHERE credId = (
SELECT targetCredit
FROM Debit
WHERE billId=NEW.billId
);
UPDATE Credit
SET spent = spent + CASE
WHEN (SELECT c FROM _temp) <= 0
THEN RAISE(FAIL, "Credit spent")
ELSE
(SELECT m FROM _temp)
ELSE IFNULL(
(SELECT m FROM _temp),
RAISE(FAIL,"Oops, lost _temp record before increasing spent")
)
END
WHERE credId=NEW.credId;
@ -106,6 +100,17 @@ BEGIN
WHERE billId=NEW.billId AND credId=NEW.credId
;
UPDATE Credit
SET value = value + IFNULL(
(SELECT m FROM _temp),
RAISE(FAIL, "Oops, lost _temp record before increasing value")
)
WHERE credId = (
SELECT targetCredit
FROM Debit
WHERE billId=NEW.billId
);
DELETE FROM _temp;
END;
@ -245,12 +250,12 @@ 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 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 checkIBANatTransfer
BEFORE INSERT ON Debit
@ -283,11 +288,43 @@ CREATE VIEW AvailableCredits AS
WHERE value != spent
;
-- Log of internal transfers
CREATE VIEW History AS
-- internal transfers with account as source
SELECT DATE(timestamp) AS date,
d.purpose AS purpose,
d.debtor AS account,
NULL AS credit,
t.amount AS debit,
c.account AS contra,
d.billId AS billId
FROM Transfer t
LEFT JOIN Debit AS d ON d.billId = t.billId
LEFT JOIN Credit AS c ON c.credId = d.targetCredit
-- internal transfers with account as target
UNION
SELECT DATE(timestamp) AS date,
d.purpose AS purpose,
c.account AS account,
t.amount AS credit,
NULL AS debit,
d.debtor AS contra,
d.billId AS billId
FROM Transfer t
LEFT JOIN Debit AS d ON d.billId = t.billId
LEFT JOIN Credit AS c ON c.credId = d.targetCredit
ORDER BY date ASC
;
CREATE VIEW Balance AS
SELECT Account.ID AS ID,
IFNULL(ac.allCredits,0) AS credit,
IFNULL(ac.allCredits,0) AS available,
IFNULL(hi.credit,0) AS earned,
IFNULL(hi.debit,0) AS spent,
IFNULL(pr.allPromises, 0) AS promised,
IFNULL(ca.allArrears, 0) AS arrears
IFNULL(ca.allArrears, 0) AS arrears,
even.until AS even_until
FROM Account
LEFT OUTER JOIN (
SELECT debtor, sum(difference) AS allArrears
@ -306,6 +343,21 @@ CREATE VIEW Balance AS
JOIN Account a ON a.ID = c.account
GROUP BY a.ID
) AS pr ON Account.ID=pr.ID
LEFT OUTER JOIN (
SELECT account,
sum(credit) AS credit,
sum(debit) AS debit
FROM History
GROUP BY account
) AS hi ON Account.ID=hi.account
LEFT OUTER JOIN (
SELECT d.debtor AS account,
max(d.date) AS until
FROM Debit d
LEFT OUTER JOIN CurrentArrears ca ON d.debtor = ca.debtor
GROUP BY d.debtor, ca.debtor
HAVING d.date <= IFNULL( min(ca.date), d.date )
) AS even ON Account.ID=even.account
;
CREATE VIEW ReconstructedBankStatement AS
@ -328,41 +380,3 @@ CREATE VIEW ReconstructedBankStatement AS
WHERE targetCredit IS NULL -- exclude internal transfers
ORDER BY date ASC
;
-- History view: All incoming, outgoing payments and internal transfers
CREATE VIEW History AS
SELECT c.date AS date,
c.purpose AS purpose,
account,
c.value AS credit,
NULL AS debit,
NULL AS contra,
NULL AS billId
FROM Credit AS c
LEFT OUTER JOIN Debit AS d ON c.credId=d.targetCredit
GROUP BY c.credId
HAVING count(d.billId) == 0 -- exclude internal transfers
UNION -- internal transfers with account as source
SELECT DATE(timestamp) AS date,
d.purpose AS purpose,
d.debtor AS account,
NULL AS credit,
t.amount AS debit,
c.account AS contra,
d.billId AS billId
FROM Transfer t
LEFT JOIN Credit AS c ON c.credId = t.credId
LEFT JOIN Debit AS d ON d.billId = t.billId
UNION -- internal transfers with account as target
SELECT DATE(timestamp) AS date,
d.purpose AS purpose,
c.account AS account,
t.amount AS credit,
NULL AS debit,
d.debtor AS contra,
d.billId AS billId
FROM Transfer t
LEFT JOIN Debit AS d ON d.billId = t.billId
LEFT JOIN Credit AS c ON c.credId = t.credId
ORDER BY date ASC
;

View File

@ -1,4 +1,4 @@
ID: credit promise debt
ID: availbl promise debt
--------------------------------
Club: 0 +7200 -23450
john: 7200 +0 -7200

View File

@ -24,18 +24,18 @@ INSERT INTO Debit VALUES ("MB1605-john", "john", 1, "2016-05-01", "Membership fe
("TWX2016/123", "Club", 3, "2016-01-15", "Server Hosting 2016", 23450, 0);
.separator " "
SELECT "ID: credit promise debt";
SELECT "ID: availbl promise debt";
SELECT "--------------------------------";
SELECT ID || ":", credit, '+' || promised, arrears * -1 FROM Balance WHERE ID in ("john", "Club");
SELECT ID || ":", available, '+' || promised, arrears * -1 FROM Balance WHERE ID in ("john", "Club");
SELECT "# Reflect john paying its bills all at once ...";
INSERT INTO Transfer (billId, credId) VALUES ("MB1605-john", 2), ("MB1606-john", 2), ("MB1607-john", 2), ("MB1608-john", 2), ("MB1609-john", 2), ("MB1610-john", 2), ("MB1611-john", 2), ("MB1612-john", 2), ("MB1701-john", 2), ("MB1702-john", 2), ("MB1703-john", 2), ("MB1704-john", 2);
SELECT ID || ":", credit, '+' || promised, arrears * -1 FROM Balance WHERE ID in ("john", "Club");
SELECT ID || ":", available, '+' || promised, arrears * -1 FROM Balance WHERE ID in ("john", "Club");
SELECT "# Charge Club with server hosting provided by alex ...";
INSERT INTO Transfer (billId, credId) VALUES ("TWX2016/123", 1);
SELECT ID || ":", credit, '+' || promised, arrears * -1 FROM Balance WHERE ID in ("Club", "alex");
SELECT ID || ":", available, '+' || promised, arrears * -1 FROM Balance WHERE ID in ("Club", "alex");
SELECT "# Some updates and deletes that could, unless denied, destroy consistency ...";
UPDATE Debit SET paid = 20000 WHERE billId="TWX2016/123";
@ -47,11 +47,11 @@ BEGIN TRANSACTION;
DELETE FROM Transfer WHERE billId="TWX2016/123";
UPDATE Debit SET value = 20000 WHERE billId="TWX2016/123";
DELETE FROM Debit WHERE billId="TWX2016/123"; -- *SHOULD* work
SELECT ID || ":", credit, '+' || promised, arrears * -1 FROM Balance WHERE ID in ("Club", "alex");
SELECT ID || ":", available, '+' || promised, arrears * -1 FROM Balance WHERE ID in ("Club", "alex");
ROLLBACK TRANSACTION;
SELECT '# But let''s rollback that what-if excurse. This is how it currently is ...';
SELECT ID || ":", credit, '+' || promised, arrears * -1 FROM Balance WHERE ID in ("Club", "alex");
SELECT ID || ":", available, '+' || promised, arrears * -1 FROM Balance WHERE ID in ("Club", "alex");
SELECT '###################################################################';
SELECT '# Now it is your turn: Study the sql code yielding the output above';

View File

@ -46,7 +46,7 @@ my %months = (
while ( my ($num, $month) = each %months ) {
my $yy = substr $month, -2;
$db->resultset("Debit")->create({
billId => "MB$yy$num-john",
billId => "MB$yy$num/john",
debtor => "john",
targetCredit => 1,
date => "16-05-01",
@ -70,17 +70,60 @@ is $db->resultset("Debit")->search({ debtor => 'Club' })->single->billId, "TWX20
is_deeply {
map { $_->ID => {$_->get_columns} }
$db->resultset("Balance")->all
$db->resultset("Balance")->search(
{}, { columns => [qw|ID available arrears promised|] }
)
}, {
john => { ID => 'john', credit => 7200, arrears => 7200, promised => 0 },
Club => { ID => 'Club', credit => 0, arrears => 23450, promised => 7200 },
alex => { ID => 'alex', credit => 0, arrears => 0, promised => 23450 },
john => { ID=>'john', available=>7200, arrears=>7200, promised=>0 },
Club => { ID=>'Club', available=>0, arrears=>23450, promised=>7200 },
alex => { ID=>'alex', available=>0, arrears=>0, promised=>23450 },
},
"Get balances"
"Get balances before transfers"
;
# Transfer 72 Euro (6 Euro per month) from john's to Club account.
# Transfer same 72 Euro from Club account to alex hosting the web site.
is $db->autobalance( (q{*} => q{*}) x 2 ), 14400, 'Automatically balanced credits and debits';
is $db->make_transfers( (q{*} => q{*}) x 2 ), 14400, 'Automatically balanced credits and debits';
is_deeply {
map { $_->ID => {$_->get_columns} }
$db->resultset("Balance")->search(
{}, { columns => [qw|ID available arrears promised|] }
)
}, {
john => { ID=>'john', available=>0, arrears=>0, promised=>0 },
Club => { ID=>'Club', available=>0, arrears=>16250, promised=>0 },
alex => { ID=>'alex', available=>7200, arrears=>0, promised=>16250 },
},
"Get balances after transfers"
;
$db->resultset("Account")->create({ ID => "rose", altId => 45, type => 'member' });
%months = (
'07' => 'July 2016', '08' => 'August 2016',
'09' => 'September 2016', '10' => 'October 2016', '11' => 'November 2016', '12' => 'December 2016',
);
while ( my ($num, $month) = each %months ) {
my $yy = substr $month, -2;
$db->resultset("Debit")->create({
billId => "MB$yy$num/rose",
debtor => "rose",
targetCredit => 1,
date => "16-07-10",
purpose => "Membership fee $month",
value => 600
});
}
my $rose = $db->resultset("Account")->find("rose");
$rose->add_to_credits({
value => 7200, purpose => "Membership fees until 6/17",
date => '16-08-12'
});
$db->make_transfers( q{*} => q{*} );
is $rose->available_credits->get_column("difference")->sum, 3600, "partial use of credit";
is $db->resultset("Balance")->find("alex")->earned, '10800', 'indirect transfers';
done_testing();