Skip to content
This repository has been archived by the owner on Feb 8, 2018. It is now read-only.

refactor for double-entry accounting #3618

Closed
wants to merge 12 commits into from
35 changes: 24 additions & 11 deletions docs/index.rst
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
66 changes: 20 additions & 46 deletions gratipay/billing/payday.py
Original file line number Diff line number Diff line change
Expand Up @@ -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

Expand Down Expand Up @@ -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
Expand All @@ -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()
Expand Down Expand Up @@ -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.')


Expand Down Expand Up @@ -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):
Expand Down
2 changes: 2 additions & 0 deletions gratipay/journal.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,2 @@
class Journal(object):
pass
2 changes: 1 addition & 1 deletion gratipay/testing/__init__.py
Original file line number Diff line number Diff line change
Expand Up @@ -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()


Expand Down Expand Up @@ -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):
Expand Down
143 changes: 143 additions & 0 deletions sql/branch.sql
Original file line number Diff line number Diff line change
@@ -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;
Loading