diff --git a/docs/index.rst b/docs/index.rst index f31009dcd1..796e4e6358 100644 --- a/docs/index.rst +++ b/docs/index.rst @@ -11,20 +11,33 @@ Welcome! This is the documentation for programmers working on `gratipay.com`_ DB Schema --------- -is_suspipicous on participant can be None, True or False. It represents unknown, -blacklisted or whitelisted user. +You should think of Gratipay as a PostgreSQL application, because Postgres is +our data store, and we depend heavily on it. We write SQL. We use Postgres +features. We have our own Postgres library for Python. If you want to +understand Gratipay, you should start by understanding our schema. - * whitelisted can transfer money out of gratipay - * unknown can move money within gratipay - * blacklisted cannot do anything +There are three main parts to our schema: + - The ``journal``. Gratipay implements a full-fledged double-entry accounting + system, and the ``journal`` table is at the heart of it. -The exchanges table records movements of money into and out of Gratipay. The -``amount`` column shows a positive amount for payins and a negative amount for -payouts. The ``fee`` column is always positive. For both payins and payouts, -the ``amount`` does not include the ``fee`` (e.g., a $10 payin would result in -an ``amount`` of ``9.41`` and a ``fee`` of ``0.59``, and a $100 payout with a -2% fee would result in an ``amount`` of ``-98.04`` and a fee of ``1.96``). + - **~user**-related tables. The primary table for users is ``participants``. + A number of other tables record additional information related to users, + such as accounts elsewhere (``accounts_elsewhere``), and payment routes + (``exchange_routes``). + + - **Team**-related tables. The primary table for Teams is ``teams``. The + ``subscriptions`` and ``payroll`` tables record recurring payments to and + takes from Teams, respectively. + +We also have an ``email_queue`` table for outbound mail, and the weekly payday +process generates several temporary tables, prefixed with ``payday_``. In +addition to these tables, we have a number of views, all prefixed with +``current_``. + +One pattern to watch for: three-state booleans. We sometimes use ``NULL`` with +``boolean`` to represent an unknown state, e.g., with +``participants.is_suspicious`` Contents diff --git a/gratipay/billing/payday.py b/gratipay/billing/payday.py index 38edded359..fdcfc37a2a 100644 --- a/gratipay/billing/payday.py +++ b/gratipay/billing/payday.py @@ -21,7 +21,6 @@ from gratipay.billing.exchanges import ( cancel_card_hold, capture_card_hold, create_card_hold, upcharge, ) -from gratipay.exceptions import NegativeBalance from gratipay.models import check_db from psycopg2 import IntegrityError @@ -77,7 +76,7 @@ class Payday(object): transfer_takes process_draws settle_card_holds - update_balances + make_journal_entries take_over_balances update_stats update_cached_amounts @@ -103,15 +102,9 @@ def start(cls): """, back_as=dict) log("Starting a new payday.") except IntegrityError: # Collision, we have a Payday already. - d = cls.db.one(""" - SELECT id, (ts_start AT TIME ZONE 'UTC') AS ts_start, stage - FROM paydays - WHERE ts_end='1970-01-01T00:00:00+00'::timestamptz - """, back_as=dict) + d = cls.db.one("SELECT current_payday();", back_as=dict) log("Picking up with an existing payday.") - d['ts_start'] = d['ts_start'].replace(tzinfo=aspen.utils.utc) - log("Payday started at %s." % d['ts_start']) payday = Payday() @@ -154,33 +147,33 @@ def payin(self): money internally between participants. """ with self.db.get_cursor() as cursor: - self.prepare(cursor, self.ts_start) + self.prepare(cursor) holds = self.create_card_holds(cursor) self.process_subscriptions(cursor) self.transfer_takes(cursor, self.ts_start) self.process_draws(cursor) - payments = cursor.all(""" - SELECT * FROM payments WHERE "timestamp" > %s + entries = cursor.all(""" + SELECT * FROM journal WHERE "timestamp" > %s """, (self.ts_start,)) try: self.settle_card_holds(cursor, holds) - self.update_balances(cursor) + self.make_journal_entries(cursor) check_db(cursor) except: # Dump payments for debugging import csv from time import time - with open('%s_payments.csv' % time(), 'wb') as f: - csv.writer(f).writerows(payments) + with open('%s_journal.csv' % time(), 'wb') as f: + csv.writer(f).writerows(entries) raise self.take_over_balances() @staticmethod - def prepare(cursor, ts_start): + def prepare(cursor): """Prepare the DB: we need temporary tables with indexes and triggers. """ - cursor.run(PAYDAY, dict(ts_start=ts_start)) + cursor.run(PAYDAY) log('Prepared the DB.') @@ -325,35 +318,16 @@ def capture(p): @staticmethod - def update_balances(cursor): - log("Updating balances.") - participants = cursor.all(""" - - UPDATE participants p - SET balance = (balance + p2.new_balance - p2.old_balance) - FROM payday_participants p2 - WHERE p.id = p2.id - AND p2.new_balance <> p2.old_balance - RETURNING p.id - , p.username - , balance AS new_balance - , ( SELECT balance - FROM participants p3 - WHERE p3.id = p.id - ) AS cur_balance; - - """) - # Check that balances aren't becoming (more) negative - for p in participants: - if p.new_balance < 0 and p.new_balance < p.cur_balance: - log(p) - raise NegativeBalance() - cursor.run(""" - INSERT INTO payments (timestamp, participant, team, amount, direction, payday) - SELECT *, (SELECT id FROM paydays WHERE extract(year from ts_end) = 1970) - FROM payday_payments; - """) - log("Updated the balances of %i participants." % len(participants)) + def make_journal_entries(cursor): + log("Making journal entries.") + nentries = len(cursor.all(""" + INSERT INTO journal + (ts, amount, debit, credit, payday) + (SELECT * FROM payday_journal) + RETURNING id; + """)) + log("Journal entries recorded: %i." % nentries) + return nentries def take_over_balances(self): diff --git a/gratipay/journal.py b/gratipay/journal.py new file mode 100644 index 0000000000..5b3ca1a9df --- /dev/null +++ b/gratipay/journal.py @@ -0,0 +1,2 @@ +class Journal(object): + pass diff --git a/gratipay/testing/__init__.py b/gratipay/testing/__init__.py index 0963299dcf..dbd2903ca8 100644 --- a/gratipay/testing/__init__.py +++ b/gratipay/testing/__init__.py @@ -68,7 +68,6 @@ class Harness(unittest.TestCase): @classmethod def setUpClass(cls): - cls.db.run("ALTER SEQUENCE exchanges_id_seq RESTART WITH 1") cls.setUpVCR() @@ -112,6 +111,7 @@ def clear_tables(self): except (IntegrityError, InternalError): tablenames.insert(0, tablename) self.db.run("ALTER SEQUENCE participants_id_seq RESTART WITH 1") + self.db.run("SELECT create_system_accounts()") # repopulate the `accounts` table def make_elsewhere(self, platform, user_id, user_name, **kw): diff --git a/sql/branch.sql b/sql/branch.sql new file mode 100644 index 0000000000..f5db2e7bb1 --- /dev/null +++ b/sql/branch.sql @@ -0,0 +1,143 @@ +BEGIN; + + DROP TABLE payments; + DROP TABLE exchanges; + + + CREATE FUNCTION current_payday() RETURNS SETOF paydays AS $$ + SELECT * + FROM paydays + WHERE ts_end='1970-01-01T00:00:00+00'::timestamptz; + $$ LANGUAGE sql; + + CREATE FUNCTION current_payday_id() RETURNS int AS $$ + -- This is a function so we can use it in DEFAULTS for a column. + SELECT id FROM current_payday(); + $$ LANGUAGE sql; + + + -- Accounts + + CREATE TYPE account_type AS ENUM ('asset', 'liability', 'income', 'expense'); + + CREATE TABLE accounts + ( id serial PRIMARY KEY + , type account_type NOT NULL + , system text DEFAULT NULL UNIQUE + , participant text DEFAULT NULL UNIQUE REFERENCES participants + ON UPDATE CASCADE ON DELETE RESTRICT + , team text DEFAULT NULL UNIQUE REFERENCES teams + ON UPDATE CASCADE ON DELETE RESTRICT + + , CONSTRAINT exactly_one_foreign_key CHECK ( + CASE WHEN system IS NULL THEN 0 ELSE 1 END + + CASE WHEN participant IS NULL THEN 0 ELSE 1 END + + CASE WHEN team IS NULL THEN 0 ELSE 1 END = 1 + ) + ); + + CREATE FUNCTION create_system_accounts() RETURNS void AS $$ + BEGIN + INSERT INTO accounts (type, system) VALUES ('asset', 'cash'); + INSERT INTO accounts (type, system) VALUES ('asset', 'accounts receivable'); + INSERT INTO accounts (type, system) VALUES ('liability', 'accounts payable'); + INSERT INTO accounts (type, system) VALUES ('income', 'processing fee revenues'); + INSERT INTO accounts (type, system) VALUES ('expense', 'processing fee expenses'); + INSERT INTO accounts (type, system) VALUES ('income', 'earned interest'); + INSERT INTO accounts (type, system) VALUES ('expense', 'chargeback expenses'); + END; + $$ LANGUAGE plpgsql; + SELECT create_system_accounts(); + + + CREATE FUNCTION create_account_for_participant() RETURNS trigger AS $$ + BEGIN + INSERT INTO accounts (type, participant) VALUES ('liability', NEW.username); + RETURN NULL; + END; + $$ LANGUAGE plpgsql; + + CREATE TRIGGER create_account_for_participant AFTER INSERT ON participants + FOR EACH ROW EXECUTE PROCEDURE create_account_for_participant(); + + + CREATE FUNCTION create_account_for_team() RETURNS trigger AS $$ + BEGIN + INSERT INTO accounts (type, team) VALUES ('liability', NEW.slug); + RETURN NULL; + END; + $$ LANGUAGE plpgsql; + + CREATE TRIGGER create_account_for_team AFTER INSERT ON teams + FOR EACH ROW EXECUTE PROCEDURE create_account_for_team(); + + + -- The Journal + + CREATE TABLE journal + ( id bigserial PRIMARY KEY + , ts timestamptz NOT NULL DEFAULT CURRENT_TIMESTAMP + , amount numeric(35, 2) NOT NULL + , debit bigint NOT NULL REFERENCES accounts + , credit bigint NOT NULL REFERENCES accounts + , payday int DEFAULT NULL REFERENCES paydays + , route bigint DEFAULT NULL REFERENCES exchange_routes + , status exchange_status DEFAULT NULL + , recorder text DEFAULT NULL REFERENCES participants + ON UPDATE CASCADE ON DELETE RESTRICT + ); + + CREATE FUNCTION update_balance() RETURNS trigger AS $$ + DECLARE + to_debit text; + to_credit text; + to_update text; + delta numeric(35, 2); + BEGIN + + to_debit = (SELECT participant FROM accounts WHERE id=NEW.debit); + to_credit = (SELECT participant FROM accounts WHERE id=NEW.credit); + + IF (to_debit IS NULL) AND (to_credit IS NULL) THEN + -- No participants involved in this journal entry. + RETURN NULL; + END IF; + + IF (to_debit IS NOT NULL) AND (to_credit IS NOT NULL) THEN + -- Two participants involved in this journal entry! + -- This is a bug: we don't allow direct transfers from one ~user to another. + RAISE USING MESSAGE = + 'Both ' || to_debit || ' and ' || to_credit || ' are participants.'; + END IF; + + IF to_debit IS NOT NULL THEN + -- Debiting a liability decreases it. + to_update = to_debit; + delta = -NEW.amount; + ELSE + -- Crediting a liability increases it. + to_update = to_credit; + delta = NEW.amount; + END IF; + + UPDATE participants SET balance = balance + delta WHERE username=to_update; + + RETURN NULL; + END; + $$ LANGUAGE plpgsql; + + CREATE TRIGGER update_balance AFTER INSERT ON journal + FOR EACH ROW EXECUTE PROCEDURE update_balance(); + + + -- Journal Notes + + CREATE TABLE journal_notes + ( id bigserial PRIMARY KEY + , body text NOT NULL + , author text NOT NULL REFERENCES participants + ON UPDATE CASCADE ON DELETE RESTRICT + , is_private boolean NOT NULL DEFAULT TRUE + ); + +END; diff --git a/sql/payday.sql b/sql/payday.sql index c6ffba5de2..67cd08d9ef 100644 --- a/sql/payday.sql +++ b/sql/payday.sql @@ -1,4 +1,4 @@ --- Recreate the necessary tables and indexes +-- Participants DROP TABLE IF EXISTS payday_participants; CREATE TABLE payday_participants AS @@ -18,12 +18,28 @@ CREATE TABLE payday_participants AS , braintree_customer_id FROM participants p WHERE is_suspicious IS NOT true - AND claimed_time < %(ts_start)s + AND claimed_time < (SELECT ts_start FROM current_payday()) ORDER BY claimed_time; CREATE UNIQUE INDEX ON payday_participants (id); CREATE UNIQUE INDEX ON payday_participants (username); +CREATE OR REPLACE FUNCTION protect_balances() RETURNS trigger AS $$ +BEGIN + IF NEW.new_balance < LEAST(0, OLD.new_balance) THEN + RAISE 'You''re trying to make balance more negative for %.', NEW.username + USING ERRCODE = '23000'; + END IF; + RETURN NULL; +END; +$$ LANGUAGE plpgsql; + +CREATE TRIGGER protect_balances AFTER UPDATE ON payday_participants + FOR EACH ROW EXECUTE PROCEDURE protect_balances(); + + +-- Teams + DROP TABLE IF EXISTS payday_teams; CREATE TABLE payday_teams AS SELECT t.id @@ -47,29 +63,41 @@ CREATE TABLE payday_teams AS ) > 0 ; -DROP TABLE IF EXISTS payday_payments_done; -CREATE TABLE payday_payments_done AS - SELECT * - FROM payments p - WHERE p.timestamp > %(ts_start)s; +CREATE OR REPLACE FUNCTION protect_team_balances() RETURNS trigger AS $$ +BEGIN + IF NEW.balance < 0 THEN + RAISE 'You''re trying to set a negative balance for the % team.', NEW.slug + USING ERRCODE = '23000'; + END IF; + RETURN NULL; +END; +$$ LANGUAGE plpgsql; + +CREATE TRIGGER protect_team_balances AFTER UPDATE ON payday_teams + FOR EACH ROW EXECUTE PROCEDURE protect_team_balances(); + + +-- Subscriptions + +DROP TABLE IF EXISTS payday_journal_so_far; +CREATE TABLE payday_journal_so_far AS + SELECT * FROM journal WHERE payday = (SELECT id FROM current_payday()); DROP TABLE IF EXISTS payday_subscriptions; CREATE TABLE payday_subscriptions AS SELECT subscriber, team, amount FROM ( SELECT DISTINCT ON (subscriber, team) * FROM subscriptions - WHERE mtime < %(ts_start)s + WHERE mtime < (SELECT ts_start FROM current_payday()) ORDER BY subscriber, team, mtime DESC ) s JOIN payday_participants p ON p.username = s.subscriber - JOIN payday_teams t ON t.slug = s.team WHERE s.amount > 0 AND ( SELECT id - FROM payday_payments_done done - WHERE s.subscriber = done.participant - AND s.team = done.team - AND direction = 'to-team' - ) IS NULL + FROM payday_journal_so_far so_far + WHERE so_far.debit = (SELECT id FROM accounts WHERE team=s.team) + AND so_far.credit = (SELECT id FROM accounts WHERE participant=s.subscriber) + ) IS NULL ORDER BY p.claimed_time ASC, s.ctime ASC; CREATE INDEX ON payday_subscriptions (subscriber); @@ -84,6 +112,9 @@ UPDATE payday_participants WHERE subscriber = username ), 0); + +-- Takes + DROP TABLE IF EXISTS payday_takes; CREATE TABLE payday_takes ( team text @@ -91,53 +122,96 @@ CREATE TABLE payday_takes , amount numeric(35,2) ); -DROP TABLE IF EXISTS payday_payments; -CREATE TABLE payday_payments -( timestamp timestamptz DEFAULT now() -, participant text NOT NULL -, team text NOT NULL -, amount numeric(35,2) NOT NULL -, direction payment_direction NOT NULL + +-- Journal + +DROP TABLE IF EXISTS payday_journal; +CREATE TABLE payday_journal +( ts timestamptz DEFAULT now() +, amount numeric(35,2) NOT NULL +, debit bigint NOT NULL +, credit bigint NOT NULL +, payday int NOT NULL DEFAULT current_payday_id() ); +CREATE OR REPLACE FUNCTION payday_update_balance() RETURNS trigger AS $$ +DECLARE + to_debit text; + to_credit text; +BEGIN + to_debit = (SELECT participant FROM accounts WHERE id=NEW.debit); + IF to_debit IS NOT NULL THEN + + -- Fulfillment of a subscription from a ~user to a Team. + + to_credit = (SELECT team FROM accounts WHERE id=NEW.credit); + + UPDATE payday_participants + SET new_balance = new_balance - NEW.amount + WHERE username = to_debit; + + UPDATE payday_teams + SET balance = balance + NEW.amount + WHERE slug = to_credit; + + ELSE + + -- Payroll from a Team to a ~user. + + to_debit = (SELECT team FROM accounts WHERE id=NEW.debit); + to_credit = (SELECT participant FROM accounts WHERE id=NEW.credit); + + UPDATE payday_teams + SET balance = balance - NEW.amount + WHERE slug = to_debit; + + UPDATE payday_participants + SET new_balance = new_balance + NEW.amount + WHERE username = to_credit; --- Prepare a statement that makes and records a payment + END IF; + + RETURN NULL; +END; +$$ LANGUAGE plpgsql; + +CREATE TRIGGER payday_update_balance AFTER INSERT ON payday_journal + FOR EACH ROW EXECUTE PROCEDURE payday_update_balance(); + + +-- Prepare a statement that makes a journal entry CREATE OR REPLACE FUNCTION pay(text, text, numeric, payment_direction) RETURNS void AS $$ DECLARE - participant_delta numeric; - team_delta numeric; + participant_account bigint; + team_account bigint; + to_debit bigint; + to_credit bigint; BEGIN IF ($3 = 0) THEN RETURN; END IF; + participant_account := (SELECT id FROM accounts WHERE participant=$1); + team_account := (SELECT id FROM accounts WHERE team=$2); + + IF participant_account IS NULL THEN + RAISE 'Unknown participant: %.', $1; + END IF; + IF team_account IS NULL THEN + RAISE 'Unknown team: %', $2; + END IF; + IF ($4 = 'to-team') THEN - participant_delta := -$3; - team_delta := $3; + to_debit := participant_account; + to_credit := team_account; ELSE - participant_delta := $3; - team_delta := -$3; + to_debit := team_account; + to_credit := participant_account; END IF; - UPDATE payday_participants - SET new_balance = (new_balance + participant_delta) - WHERE username = $1; - UPDATE payday_teams - SET balance = (balance + team_delta) - WHERE slug = $2; - INSERT INTO payday_payments - (participant, team, amount, direction) - VALUES ( ( SELECT p.username - FROM participants p - JOIN payday_participants p2 ON p.id = p2.id - WHERE p2.username = $1 ) - , ( SELECT t.slug - FROM teams t - JOIN payday_teams t2 ON t.id = t2.id - WHERE t2.slug = $2 ) - , $3 - , $4 - ); + INSERT INTO payday_journal + (amount, debit, credit) + VALUES ($3, to_debit, to_credit); END; $$ LANGUAGE plpgsql; diff --git a/tests/py/test_billing_payday.py b/tests/py/test_billing_payday.py index ea51263496..c889137050 100644 --- a/tests/py/test_billing_payday.py +++ b/tests/py/test_billing_payday.py @@ -7,6 +7,7 @@ import braintree import mock import pytest +from psycopg2 import IntegrityError from gratipay.billing.exchanges import create_card_hold from gratipay.billing.payday import NoPayday, Payday @@ -171,17 +172,16 @@ def test_start_prepare(self, log): self.make_participant('carl', balance=10, claimed_time='now') payday = Payday.start() - ts_start = payday.ts_start get_participants = lambda c: c.all("SELECT * FROM payday_participants") with self.db.get_cursor() as cursor: - payday.prepare(cursor, ts_start) + payday.prepare(cursor) participants = get_participants(cursor) expected_logging_call_args = [ ('Starting a new payday.'), - ('Payday started at {}.'.format(ts_start)), + ('Payday started at {}.'.format(payday.ts_start)), ('Prepared the DB.'), ] expected_logging_call_args.reverse() @@ -191,13 +191,12 @@ def test_start_prepare(self, log): log.reset_mock() # run a second time, we should see it pick up the existing payday - payday = Payday.start() - second_ts_start = payday.ts_start + second_payday = Payday.start() with self.db.get_cursor() as cursor: - payday.prepare(cursor, second_ts_start) + payday.prepare(cursor) second_participants = get_participants(cursor) - assert ts_start == second_ts_start + assert payday.ts_start == second_payday.ts_start participants = list(participants) second_participants = list(second_participants) @@ -207,7 +206,7 @@ def test_start_prepare(self, log): expected_logging_call_args = [ ('Picking up with an existing payday.'), - ('Payday started at {}.'.format(second_ts_start)), + ('Payday started at {}.'.format(second_payday.ts_start)), ('Prepared the DB.'), ] expected_logging_call_args.reverse() @@ -238,7 +237,7 @@ class TestPayin(BillingHarness): def create_card_holds(self): payday = Payday.start() with self.db.get_cursor() as cursor: - payday.prepare(cursor, payday.ts_start) + payday.prepare(cursor) return payday.create_card_holds(cursor) @mock.patch.object(Payday, 'fetch_card_holds') @@ -363,20 +362,43 @@ def test_payin_cancels_uncaptured_holds(self, log): assert Participant.from_id(self.janet.id).balance == 8 assert Participant.from_id(self.homer.id).balance == 42 - def test_payin_cant_make_balances_more_negative(self): - self.db.run(""" - UPDATE participants SET balance = -10 WHERE username='janet' - """) + + # protect_balances - pb + + def test_pb_doesnt_allow_taking_a_balance_negative(self): + self.make_participant('alice', claimed_time='now', balance=10) + payday = Payday.start() + with self.db.get_cursor() as cursor: + payday.prepare(cursor) + with pytest.raises(IntegrityError): + cursor.run(""" + UPDATE payday_participants + SET new_balance = -8 + WHERE username = 'alice'; + """) + + def test_pb_allows_making_a_balance_less_negative(self): + self.make_participant('alice', claimed_time='now', balance=-10) + payday = Payday.start() + with self.db.get_cursor() as cursor: + payday.prepare(cursor) + cursor.run(""" + UPDATE payday_participants + SET new_balance = -8 + WHERE username = 'alice'; + """) + + def test_pb_allows_taking_a_balance_to_zero(self): + self.make_participant('alice', claimed_time='now', balance=10) payday = Payday.start() with self.db.get_cursor() as cursor: - payday.prepare(cursor, payday.ts_start) + payday.prepare(cursor) cursor.run(""" UPDATE payday_participants - SET new_balance = -50 - WHERE username IN ('janet', 'homer') + SET new_balance = 0 + WHERE username = 'alice'; """) - with self.assertRaises(NegativeBalance): - payday.update_balances(cursor) + @mock.patch.object(Payday, 'fetch_card_holds') @mock.patch('braintree.Transaction.sale') @@ -400,6 +422,87 @@ def test_payin_doesnt_make_null_payments(self): payments = self.db.all("SELECT * FROM payments WHERE amount = 0") assert not payments + + def test_payday_journal_updates_participant_and_team_balances_for_payroll(self): + self.make_team(is_approved=True) + assert Participant.from_username('hannibal').balance == 0 + + payday = Payday.start() + with self.db.get_cursor() as cursor: + payday.prepare(cursor) + + cursor.run("UPDATE payday_teams SET balance=20 WHERE slug='TheATeam'") + cursor.run(""" + INSERT INTO payday_journal + (amount, debit, credit) + VALUES ( 10.77 + , (SELECT id FROM accounts WHERE team='TheATeam') + , (SELECT id FROM accounts WHERE participant='hannibal') + ) + """) + assert cursor.one("SELECT balance FROM payday_teams " + "WHERE slug='TheATeam'") == D('9.23') + assert cursor.one("SELECT new_balance FROM payday_participants " + "WHERE username='hannibal'") == D('10.77') + assert self.db.one("SELECT balance FROM participants " + "WHERE username='hannibal'") == 0 + + def test_payday_journal_updates_participant_and_team_balances_for_subscriptions(self): + self.make_team(is_approved=True) + self.make_participant('alice', claimed_time='now', balance=20) + + payday = Payday.start() + with self.db.get_cursor() as cursor: + payday.prepare(cursor) + + cursor.run(""" + INSERT INTO payday_journal + (amount, debit, credit) + VALUES ( 10.77 + , (SELECT id FROM accounts WHERE participant='alice') + , (SELECT id FROM accounts WHERE team='TheATeam') + ) + """) + assert cursor.one("SELECT balance FROM payday_teams " + "WHERE slug='TheATeam'") == D('10.77') + assert cursor.one("SELECT new_balance FROM payday_participants " + "WHERE username='alice'") == D('9.23') + + def test_payday_journal_disallows_negative_payday_team_balance(self): + self.make_team(is_approved=True) + + payday = Payday.start() + with self.db.get_cursor() as cursor: + payday.prepare(cursor) + cursor.run("UPDATE payday_teams SET balance=10 WHERE slug='TheATeam'") + with pytest.raises(IntegrityError): + cursor.run(""" + INSERT INTO payday_journal + (amount, debit, credit) + VALUES ( 10.77 + , (SELECT id FROM accounts WHERE team='TheATeam') + , (SELECT id FROM accounts WHERE participant='hannibal') + ) + """) + + def test_payday_journal_disallows_negative_payday_participant_balance(self): + self.make_team() + self.make_participant('alice', claimed_time='now', balance=10) + + payday = Payday.start() + with self.db.get_cursor() as cursor: + payday.prepare(cursor) + with pytest.raises(IntegrityError): + cursor.run(""" + INSERT INTO payday_journal + (amount, debit, credit) + VALUES ( 10.77 + , (SELECT id FROM accounts WHERE participant='alice') + , (SELECT id FROM accounts WHERE team='TheATeam') + ) + """) + + def test_process_subscriptions(self): alice = self.make_participant('alice', claimed_time='now', balance=1) hannibal = self.make_participant('hannibal', claimed_time='now', last_paypal_result='') @@ -411,19 +514,20 @@ def test_process_subscriptions(self): payday = Payday.start() with self.db.get_cursor() as cursor: - payday.prepare(cursor, payday.ts_start) + payday.prepare(cursor) payday.process_subscriptions(cursor) assert cursor.one("select balance from payday_teams where slug='TheATeam'") == D('0.51') assert cursor.one("select balance from payday_teams where slug='TheBTeam'") == 0 - payday.update_balances(cursor) + payday.make_journal_entries(cursor) - assert Participant.from_id(alice.id).balance == D('0.49') + assert Participant.from_username('alice').balance == D('0.49') assert Participant.from_username('hannibal').balance == 0 assert Participant.from_username('lecter').balance == 0 - payment = self.db.one("SELECT * FROM payments") - assert payment.amount == D('0.51') - assert payment.direction == 'to-team' + entries = self.db.one("SELECT * FROM journal") + assert entries.amount == D('0.51') + assert entries.debit == self.db.one("SELECT id FROM accounts WHERE participant='alice'") + assert entries.credit == self.db.one("SELECT id FROM accounts WHERE team='TheATeam'") @pytest.mark.xfail(reason="haven't migrated_transfer_takes yet") def test_transfer_takes(self): @@ -442,9 +546,9 @@ def test_transfer_takes(self): # have already been processed for i in range(3): with self.db.get_cursor() as cursor: - payday.prepare(cursor, payday.ts_start) + payday.prepare(cursor) payday.transfer_takes(cursor, payday.ts_start) - payday.update_balances(cursor) + payday.make_journal_entries(cursor) participants = self.db.all("SELECT username, balance FROM participants") @@ -466,20 +570,21 @@ def test_process_draws(self): payday = Payday.start() with self.db.get_cursor() as cursor: - payday.prepare(cursor, payday.ts_start) + payday.prepare(cursor) payday.process_subscriptions(cursor) payday.transfer_takes(cursor, payday.ts_start) payday.process_draws(cursor) assert cursor.one("select new_balance from payday_participants " "where username='hannibal'") == D('0.51') assert cursor.one("select balance from payday_teams where slug='TheATeam'") == 0 - payday.update_balances(cursor) + assert payday.make_journal_entries(cursor) == 2 assert Participant.from_id(alice.id).balance == D('0.49') assert Participant.from_username('hannibal').balance == D('0.51') - payment = self.db.one("SELECT * FROM payments WHERE direction='to-participant'") - assert payment.amount == D('0.51') + entry = self.db.one("SELECT * FROM journal " + "WHERE credit=(SELECT id FROM accounts WHERE participant='hannibal')") + assert entry.amount == D('0.51') @pytest.mark.xfail(reason="haven't migrated_transfer_takes yet") @mock.patch.object(Payday, 'fetch_card_holds') @@ -504,14 +609,14 @@ def test_take_over_during_payin(self): alice.set_tip_to(bob, 18) payday = Payday.start() with self.db.get_cursor() as cursor: - payday.prepare(cursor, payday.ts_start) + payday.prepare(cursor) bruce = self.make_participant('bruce', claimed_time='now') bruce.take_over(('twitter', str(bob.id)), have_confirmation=True) payday.process_subscriptions(cursor) bruce.delete_elsewhere('twitter', str(bob.id)) billy = self.make_participant('billy', claimed_time='now') billy.take_over(('github', str(bruce.id)), have_confirmation=True) - payday.update_balances(cursor) + payday.make_journal_entries(cursor) payday.take_over_balances() assert Participant.from_id(bob.id).balance == 0 assert Participant.from_id(bruce.id).balance == 0 diff --git a/tests/py/test_journal.py b/tests/py/test_journal.py new file mode 100644 index 0000000000..7d88e26524 --- /dev/null +++ b/tests/py/test_journal.py @@ -0,0 +1,105 @@ +from __future__ import absolute_import, division, print_function, unicode_literals + +from decimal import Decimal as D + +from gratipay.testing import Harness +from gratipay.models.participant import Participant +from pytest import raises +from psycopg2 import IntegrityError + + +class TestJournal(Harness): + + def test_journal_has_system_accounts(self): + system_accounts = self.db.all('SELECT type, system FROM accounts') + assert system_accounts == [ ('asset', 'cash') + , ('asset', 'accounts receivable') + , ('liability', 'accounts payable') + , ('income', 'processing fee revenues') + , ('expense', 'processing fee expenses') + , ('income', 'earned interest') + , ('expense', 'chargeback expenses') + ] + + def test_journal_creates_accounts_automatically_for_participants(self): + self.make_participant('alice') + account = self.db.one("SELECT * FROM accounts WHERE participant IS NOT NULL") + assert account.participant == 'alice' + assert account.type == 'liability' + + def test_journal_creates_accounts_automatically_for_teams(self): + self.make_team() + account = self.db.one("SELECT * FROM accounts WHERE team IS NOT NULL") + assert account.team == 'TheATeam' + assert account.type == 'liability' + + def test_journal_is_okay_with_teams_and_participants_with_same_name(self): + self.make_participant('alice') + account = self.db.one("SELECT * FROM accounts WHERE participant IS NOT NULL") + assert account.participant == 'alice' + + self.make_team('alice') + account = self.db.one("SELECT * FROM accounts WHERE team IS NOT NULL") + assert account.team == 'alice' + + def test_journal_catches_system_account_collision(self): + with raises(IntegrityError): + self.db.one("INSERT INTO accounts (type, system) VALUES ('asset', 'cash')") + + def test_journal_catches_participant_account_collision(self): + self.make_participant('alice') + with raises(IntegrityError): + self.db.one("INSERT INTO accounts (type, participant) VALUES ('liability', 'alice')") + + def test_journal_catches_team_account_collision(self): + self.make_team() + with raises(IntegrityError): + self.db.one("INSERT INTO accounts (type, team) VALUES ('liability', 'TheATeam')") + + def test_journal_increments_participant_balance(self): + self.make_team() + alice = self.make_participant('alice') + assert alice.balance == 0 + + self.db.run(""" + INSERT INTO journal + (amount, debit, credit) + VALUES ( 10.77 + , (SELECT id FROM accounts WHERE team='TheATeam') + , (SELECT id FROM accounts WHERE participant='alice') + ) + """) + + assert Participant.from_username('alice').balance == D('10.77') + + def test_journal_decrements_participant_balance(self): + self.make_team() + alice = self.make_participant('alice', balance=20) + assert alice.balance == D('20.00') + + self.db.run(""" + INSERT INTO journal + (amount, debit, credit) + VALUES ( 10.77 + , (SELECT id FROM accounts WHERE participant='alice') + , (SELECT id FROM accounts WHERE team='TheATeam') + ) + """) + + assert Participant.from_username('alice').balance == D('9.23') + + def test_journal_allows_negative_balance(self): + self.make_team() + alice = self.make_participant('alice', balance=10) + assert alice.balance == D('10.00') + + self.db.run(""" + INSERT INTO journal + (amount, debit, credit) + VALUES ( 10.77 + , (SELECT id FROM accounts WHERE participant='alice') + , (SELECT id FROM accounts WHERE team='TheATeam') + ) + """) + + assert Participant.from_username('alice').balance == D('-0.77')