diff --git a/gratipay/billing/payday.py b/gratipay/billing/payday.py index 77bdb58d05..4262c95cba 100644 --- a/gratipay/billing/payday.py +++ b/gratipay/billing/payday.py @@ -399,14 +399,21 @@ def update_stats(self): -- Participants who have either received/given money - SELECT participant, team, amount, direction FROM payments WHERE payday = %(payday)s + SELECT p.id as participant_id + , t.id as team_id + , amount + , direction + FROM payments + JOIN participants p ON p.username = payments.participant + JOIN teams t ON t.slug = payments.team + WHERE payday = %(payday)s UNION -- Participants who weren't charged due to amount + due < MINIMUM_CHARGE - SELECT payload->>'participant' AS participant - , payload->>'team' AS team + SELECT (payload->>'participant_id')::bigint AS participant_id + , (payload->>'team_id')::bigint AS team_id , '0' AS amount , 'to-team' AS direction FROM events @@ -427,7 +434,7 @@ def update_stats(self): SELECT COUNT(*) FROM current_exchange_routes r JOIN participants p ON p.id = r.participant - WHERE p.username = payload->>'participant' + WHERE p.id = (payload->>'participant_id')::bigint AND network = 'braintree-cc' AND error = '' ) > 0 @@ -435,10 +442,10 @@ def update_stats(self): UPDATE paydays p SET nusers = ( - SELECT COUNT(DISTINCT(participant)) FROM payments_and_dues + SELECT COUNT(DISTINCT(participant_id)) FROM payments_and_dues ) , nteams = ( - SELECT COUNT(DISTINCT(team)) FROM payments_and_dues + SELECT COUNT(DISTINCT(team_id)) FROM payments_and_dues ) , volume = ( SELECT COALESCE(sum(amount), 0) FROM payments_and_dues WHERE direction='to-team' @@ -480,17 +487,17 @@ def notify_participants(self): p = e.participant if p.notify_charge & i == 0: continue - username = p.username + participant_id = p.id nteams, top_team = self.db.one(""" WITH tippees AS ( SELECT t.slug, amount - FROM ( SELECT DISTINCT ON (team) team, amount + FROM ( SELECT DISTINCT ON (team_id) team_id, amount FROM payment_instructions WHERE mtime < %(ts_start)s - AND participant = %(username)s - ORDER BY team, mtime DESC + AND participant_id = %(participant_id)s + ORDER BY team_id, mtime DESC ) s - JOIN teams t ON s.team = t.slug + JOIN teams t ON s.team_id = t.id JOIN participants p ON t.owner = p.username WHERE s.amount > 0 AND t.is_approved IS true diff --git a/gratipay/models/participant/__init__.py b/gratipay/models/participant/__init__.py index 9828a8aa80..7431690b82 100644 --- a/gratipay/models/participant/__init__.py +++ b/gratipay/models/participant/__init__.py @@ -322,13 +322,13 @@ def clear_payment_instructions(self, cursor): SELECT ( SELECT teams.*::teams FROM teams - WHERE slug=team + WHERE id=team_id ) AS team FROM current_payment_instructions - WHERE participant = %s + WHERE participant_id = %s AND amount > 0 - """, (self.username,)) + """, (self.id,)) for team in teams: self.set_payment_instruction(team, '0.00', update_self=False, cursor=cursor) @@ -842,7 +842,9 @@ def set_payment_instruction(self, team, amount, update_self=True, update_team=Tr (ctime, participant, participant_id, team, team_id, amount) VALUES ( COALESCE (( SELECT ctime FROM payment_instructions - WHERE (participant=%(participant)s AND team=%(team)s) + WHERE ( participant_id=%(participant_id)s + AND team_id=%(team_id)s + ) LIMIT 1 ), CURRENT_TIMESTAMP) , %(participant)s, %(participant_id)s, %(team)s, %(team_id)s, %(amount)s @@ -857,9 +859,9 @@ def set_payment_instruction(self, team, amount, update_self=True, update_team=Tr if amount > 0: # Carry over any existing due - self._update_due(t_dict['team'], t_dict['id'], cursor) + self._update_due(t_dict['team_id'], t_dict['id'], cursor) else: - self._reset_due(t_dict['team'], cursor=cursor) + self._reset_due(t_dict['team_id'], cursor=cursor) if update_self: # Update giving amount of participant @@ -882,12 +884,12 @@ def get_payment_instruction(self, team): SELECT * FROM payment_instructions - WHERE participant=%s - AND team=%s + WHERE participant_id=%s + AND team_id=%s ORDER BY mtime DESC LIMIT 1 - """, (self.username, team.slug), back_as=dict, default=default) + """, (self.id, team.id), back_as=dict, default=default) def get_due(self, team): @@ -897,10 +899,10 @@ def get_due(self, team): SELECT due FROM current_payment_instructions - WHERE participant = %s - AND team = %s + WHERE participant_id = %s + AND team_id = %s - """, (self.username, team.slug)) + """, (self.id, team.id)) def get_giving_for_profile(self): @@ -910,26 +912,26 @@ def get_giving_for_profile(self): GIVING = """\ SELECT * FROM ( - SELECT DISTINCT ON (pi.team) - pi.team AS team_slug + SELECT DISTINCT ON (pi.team_id) + t.slug AS team_slug , pi.amount , pi.due , pi.ctime , pi.mtime , t.name AS team_name FROM payment_instructions pi - JOIN teams t ON pi.team = t.slug - WHERE participant = %s + JOIN teams t ON pi.team_id = t.id + WHERE participant_id = %s AND t.is_approved is true AND t.is_closed is not true - ORDER BY pi.team + ORDER BY pi.team_id , pi.mtime DESC ) AS foo ORDER BY amount DESC , team_slug """ - giving = self.db.all(GIVING, (self.username,)) + giving = self.db.all(GIVING, (self.id,)) # Compute the totals. @@ -963,7 +965,7 @@ def update_giving_and_teams(self): with self.db.get_cursor() as cursor: updated_giving = self.update_giving(cursor) for payment_instruction in updated_giving: - Team.from_slug(payment_instruction.team).update_receiving(cursor) + Team.from_id(payment_instruction.team_id).update_receiving(cursor) def update_giving(self, cursor=None): @@ -972,17 +974,17 @@ def update_giving(self, cursor=None): updated = (cursor or self.db).all(""" UPDATE payment_instructions SET is_funded = %(has_credit_card)s - WHERE participant = %(username)s + WHERE participant_id = %(participant_id)s AND is_funded <> %(has_credit_card)s RETURNING * - """, dict(username=self.username, has_credit_card=has_credit_card)) + """, dict(participant_id=self.id, has_credit_card=has_credit_card)) r = (cursor or self.db).one(""" WITH pi AS ( SELECT amount FROM current_payment_instructions cpi - JOIN teams t ON t.slug = cpi.team - WHERE participant = %(username)s + JOIN teams t ON t.id = cpi.team_id + WHERE participant_id = %(participant_id)s AND amount > 0 AND is_funded AND t.is_approved @@ -990,14 +992,14 @@ def update_giving(self, cursor=None): UPDATE participants p SET giving = COALESCE((SELECT sum(amount) FROM pi), 0) , ngiving_to = COALESCE((SELECT count(amount) FROM pi), 0) - WHERE p.username=%(username)s + WHERE p.id=%(participant_id)s RETURNING giving, ngiving_to - """, dict(username=self.username)) + """, dict(participant_id=self.id)) self.set_attributes(giving=r.giving, ngiving_to=r.ngiving_to) return updated - def _update_due(self, team, id, cursor=None): + def _update_due(self, team_id, id, cursor=None): """Transfer existing due value to newly inserted record """ # Copy due to new record @@ -1006,33 +1008,33 @@ def _update_due(self, team, id, cursor=None): SET due = COALESCE(( SELECT due FROM payment_instructions s - WHERE participant=%(username)s - AND team = %(team)s + WHERE participant_id = %(participant_id)s + AND team_id = %(team_id)s AND due > 0 ), 0) WHERE p.id = %(id)s - """, dict(username=self.username,team=team,id=id)) + """, dict(participant_id=self.id, team_id=team_id, id=id)) # Reset older due values to 0 - self._reset_due(team, except_for=id, cursor=cursor) + self._reset_due(team_id, except_for=id, cursor=cursor) (cursor or self.db).run(""" UPDATE payment_instructions p SET due = 0 - WHERE participant = %(username)s - AND team = %(team)s + WHERE participant_id = %(participant_id)s + AND team_id = %(team_id)s AND due > 0 AND p.id != %(id)s - """, dict(username=self.username,team=team,id=id)) + """, dict(participant_id=self.id, team_id=team_id, id=id)) - def _reset_due(self, team, except_for=-1, cursor=None): + def _reset_due(self, team_id, except_for=-1, cursor=None): (cursor or self.db).run(""" UPDATE payment_instructions p SET due = 0 - WHERE participant = %(username)s - AND team = %(team)s + WHERE participant_id = %(participant_id)s + AND team_id = %(team_id)s AND due > 0 AND p.id != %(id)s - """, dict(username=self.username,team=team,id=except_for)) + """, dict(participant_id=self.id, team_id=team_id, id=except_for)) def update_taking(self, cursor=None): (cursor or self.db).run(""" diff --git a/gratipay/models/team.py b/gratipay/models/team.py index 298dd7ee87..ef25881c65 100644 --- a/gratipay/models/team.py +++ b/gratipay/models/team.py @@ -112,15 +112,15 @@ def get_payment_distribution(self): SQL = """ SELECT amount , count(amount) AS nreceiving_from - FROM ( SELECT DISTINCT ON (participant) + FROM ( SELECT DISTINCT ON (participant_id) amount - , participant + , participant_id FROM payment_instructions - JOIN participants p ON p.username = participant - WHERE team=%s + JOIN participants p ON p.id = participant_id + WHERE team_id=%s AND is_funded AND p.is_suspicious IS NOT true - ORDER BY participant + ORDER BY participant_id , mtime DESC ) AS foo WHERE amount > 0 @@ -132,7 +132,7 @@ def get_payment_distribution(self): npatrons = 0.0 # float to trigger float division total_amount = Decimal('0.00') - for rec in self.db.all(SQL, (self.slug,)): + for rec in self.db.all(SQL, (self.id,)): tip_amounts.append([ rec.amount , rec.nreceiving_from , rec.amount * rec.nreceiving_from @@ -180,7 +180,7 @@ def get_dues(self): WITH our_cpi AS ( SELECT due, is_funded FROM current_payment_instructions cpi - WHERE team=%(slug)s + WHERE team_id=%(team_id)s ) SELECT ( SELECT COALESCE(SUM(due), 0) @@ -192,7 +192,7 @@ def get_dues(self): FROM our_cpi WHERE NOT is_funded ) AS unfunded - """, {'slug': self.slug}) + """, {'team_id': self.id}) return rec.funded, rec.unfunded @@ -201,16 +201,16 @@ def get_upcoming_payment(self): return self.db.one(""" SELECT COALESCE(SUM(amount + due), 0) FROM current_payment_instructions cpi - JOIN participants p ON cpi.participant = p.username - WHERE team = %(slug)s - AND is_funded -- Check whether the payment is funded - AND ( -- Check whether the user will hit the minimum charge + JOIN participants p ON cpi.participant_id = p.id + WHERE team_id = %(team_id)s + AND is_funded -- Check whether the payment is funded + AND ( -- Check whether the user will hit the minimum charge SELECT SUM(amount + due) FROM current_payment_instructions cpi2 - WHERE cpi2.participant = p.username + WHERE cpi2.participant_id = p.id AND cpi2.is_funded ) >= %(mcharge)s - """, {'slug': self.slug, 'mcharge': MINIMUM_CHARGE}) + """, {'team_id': self.id, 'mcharge': MINIMUM_CHARGE}) def create_github_review_issue(self): @@ -257,8 +257,8 @@ def update_receiving(self, cursor=None): WITH our_receiving AS ( SELECT amount FROM current_payment_instructions - JOIN participants p ON p.username = participant - WHERE team = %(slug)s + JOIN participants p ON p.id = participant_id + WHERE team_id = %(team_id)s AND p.is_suspicious IS NOT true AND amount > 0 AND is_funded @@ -268,9 +268,9 @@ def update_receiving(self, cursor=None): , nreceiving_from = COALESCE((SELECT count(*) FROM our_receiving), 0) , distributing = COALESCE((SELECT sum(amount) FROM our_receiving), 0) , ndistributing_to = 1 - WHERE t.slug = %(slug)s + WHERE t.id = %(team_id)s RETURNING receiving, nreceiving_from, distributing, ndistributing_to - """, dict(slug=self.slug)) + """, dict(team_id=self.id)) # This next step is easy for now since we don't have payroll. @@ -316,7 +316,7 @@ def migrate_tips(self): payment_instructions = self.db.all(""" SELECT pi.* FROM payment_instructions pi - JOIN teams t ON t.slug = pi.team + JOIN teams t ON t.id = pi.team_id WHERE t.owner = %s AND pi.ctime < t.ctime """, (self.owner, )) @@ -413,14 +413,14 @@ def migrate_all_tips(db, print=print): """ teams = db.all(""" - SELECT distinct ON (t.slug) t.*::teams + SELECT distinct ON (t.id) t.*::teams FROM teams t JOIN tips ON t.owner = tips.tippee -- Only fetch teams whose owners had tips under Gratipay 1.0 WHERE t.is_approved IS TRUE -- Only fetch approved teams AND NOT EXISTS ( -- Make sure tips haven't been migrated for any teams with same owner SELECT 1 FROM payment_instructions pi - JOIN teams t2 ON t2.slug = pi.team + JOIN teams t2 ON t2.id = pi.team_id WHERE t2.owner = t.owner AND pi.ctime < t2.ctime ) diff --git a/sql/branch.sql b/sql/branch.sql index d9663c8aee..15328d5ace 100644 --- a/sql/branch.sql +++ b/sql/branch.sql @@ -1,4 +1,4 @@ -BEGIN; +BEGIN; -- Step 1 ALTER TABLE payment_instructions ADD COLUMN participant_id bigint DEFAULT NULL REFERENCES participants(id) ON UPDATE RESTRICT ON DELETE RESTRICT; @@ -6,3 +6,26 @@ BEGIN; REFERENCES teams(id) ON UPDATE RESTRICT ON DELETE RESTRICT; END; + + +BEGIN; -- Step 2 + + DROP VIEW current_payment_instructions; + + UPDATE payment_instructions AS pi + SET participant_id = (SELECT id FROM participants p WHERE p.username = pi.participant) + , team_id = (SELECT id FROM teams t WHERE t.slug = pi.team); + + ALTER TABLE payment_instructions ALTER COLUMN participant_id SET NOT NULL; + ALTER TABLE payment_instructions ALTER COLUMN team_id SET NOT NULL; + + CREATE VIEW current_payment_instructions AS + SELECT DISTINCT ON (participant_id, team_id) * + FROM payment_instructions + ORDER BY participant_id, team_id, mtime DESC; + + CREATE TRIGGER update_current_payment_instruction + INSTEAD OF UPDATE ON current_payment_instructions + FOR EACH ROW EXECUTE PROCEDURE update_payment_instruction(); + +END; diff --git a/sql/payday.sql b/sql/payday.sql index 91f372defb..38fee52285 100644 --- a/sql/payday.sql +++ b/sql/payday.sql @@ -55,25 +55,25 @@ CREATE TABLE payday_payments_done AS DROP TABLE IF EXISTS payday_payment_instructions; CREATE TABLE payday_payment_instructions AS - SELECT s.id, participant, team, amount, due - FROM ( SELECT DISTINCT ON (participant, team) * + SELECT s.id, participant_id, team_id, amount, due + FROM ( SELECT DISTINCT ON (participant_id, team_id) * FROM payment_instructions WHERE mtime < (SELECT ts_start FROM current_payday()) - ORDER BY participant, team, mtime DESC + ORDER BY participant_id, team_id, mtime DESC ) s - JOIN payday_participants p ON p.username = s.participant - JOIN payday_teams t ON t.slug = s.team + JOIN payday_participants p ON p.id = s.participant_id + JOIN payday_teams t ON t.id = s.team_id WHERE s.amount > 0 AND ( SELECT id FROM payday_payments_done done - WHERE s.participant = done.participant - AND s.team = done.team + WHERE p.username = done.participant + AND t.slug = done.team AND direction = 'to-team' ) IS NULL ORDER BY p.claimed_time ASC, s.ctime ASC; -CREATE INDEX ON payday_payment_instructions (participant); -CREATE INDEX ON payday_payment_instructions (team); +CREATE INDEX ON payday_payment_instructions (participant_id); +CREATE INDEX ON payday_payment_instructions (team_id); ALTER TABLE payday_payment_instructions ADD COLUMN is_funded boolean; ALTER TABLE payday_participants ADD COLUMN giving_today numeric(35,2); @@ -81,7 +81,7 @@ UPDATE payday_participants pp SET giving_today = COALESCE(( SELECT sum(amount + due) FROM payday_payment_instructions - WHERE participant = pp.username + WHERE participant_id = pp.id ), 0); DROP TABLE IF EXISTS payday_takes; @@ -103,7 +103,7 @@ CREATE TABLE payday_payments -- Prepare a statement that makes and records a payment -CREATE OR REPLACE FUNCTION pay(text, text, numeric, payment_direction) +CREATE OR REPLACE FUNCTION pay(bigint, bigint, numeric, payment_direction) RETURNS void AS $$ DECLARE participant_delta numeric; @@ -122,17 +122,17 @@ RETURNS void AS $$ UPDATE payday_participants SET new_balance = (new_balance + participant_delta) - WHERE username = $1; + WHERE id = $1; UPDATE payday_teams SET balance = (balance + team_delta) - WHERE slug = $2; + WHERE id = $2; UPDATE current_payment_instructions SET due = 0 - WHERE participant = $1 - AND team = $2 + WHERE participant_id = $1 + AND team_id = $2 AND due > 0; IF ($4 = 'to-team') THEN - payload = '{"action":"pay","participant":"' || $1 || '", "team":"' + payload = '{"action":"pay","participant_id":"' || $1 || '", "team_id":"' || $2 || '", "amount":' || $3 || '}'; INSERT INTO events(type, payload) VALUES ('payday',payload); @@ -142,11 +142,11 @@ RETURNS void AS $$ VALUES ( ( SELECT p.username FROM participants p JOIN payday_participants p2 ON p.id = p2.id - WHERE p2.username = $1 ) + WHERE p2.id = $1 ) , ( SELECT t.slug FROM teams t JOIN payday_teams t2 ON t.id = t2.id - WHERE t2.slug = $2 ) + WHERE t2.id = $2 ) , $3 , $4 ); @@ -155,7 +155,7 @@ $$ LANGUAGE plpgsql; -- Add payments that were not met on to due -CREATE OR REPLACE FUNCTION park(text, text, numeric) +CREATE OR REPLACE FUNCTION park(bigint, bigint, numeric) RETURNS void AS $$ DECLARE payload json; BEGIN @@ -163,10 +163,10 @@ RETURNS void AS $$ UPDATE current_payment_instructions SET due = $3 - WHERE participant = $1 - AND team = $2; + WHERE participant_id = $1 + AND team_id = $2; - payload = '{"action":"due","participant":"' || $1 || '", "team":"' + payload = '{"action":"due","participant_id":"' || $1 || '", "team_id":"' || $2 || '", "due":' || $3 || '}'; INSERT INTO events(type, payload) VALUES ('payday',payload); @@ -184,14 +184,14 @@ CREATE OR REPLACE FUNCTION process_payment_instruction() RETURNS trigger AS $$ participant := ( SELECT p.*::payday_participants FROM payday_participants p - WHERE username = NEW.participant + WHERE id = NEW.participant_id ); IF (NEW.amount + NEW.due <= participant.new_balance OR participant.card_hold_ok) THEN - EXECUTE pay(NEW.participant, NEW.team, NEW.amount + NEW.due, 'to-team'); + EXECUTE pay(NEW.participant_id, NEW.team_id, NEW.amount + NEW.due, 'to-team'); RETURN NEW; ELSIF participant.has_credit_card THEN - EXECUTE park(NEW.participant, NEW.team, NEW.amount + NEW.due); + EXECUTE park(NEW.participant_id, NEW.team_id, NEW.amount + NEW.due); RETURN NULL; END IF; @@ -234,7 +234,11 @@ CREATE TRIGGER process_take AFTER INSERT ON payday_takes CREATE OR REPLACE FUNCTION process_draw() RETURNS trigger AS $$ BEGIN - EXECUTE pay(NEW.owner, NEW.slug, NEW.balance, 'to-participant'); + EXECUTE pay( (SELECT id FROM participants WHERE username=NEW.owner) + , NEW.id + , NEW.balance + , 'to-participant' + ); RETURN NULL; END; $$ LANGUAGE plpgsql; diff --git a/www/about/payment-distribution.json.spt b/www/about/payment-distribution.json.spt index 9b04d1252a..ac88922f3e 100644 --- a/www/about/payment-distribution.json.spt +++ b/www/about/payment-distribution.json.spt @@ -8,8 +8,8 @@ amounts = website.db.all(""" SELECT amount FROM (SELECT amount FROM current_payment_instructions cpi - JOIN participants p ON p.username = cpi.participant - JOIN teams t ON t.slug = cpi.team + JOIN participants p ON p.id = cpi.participant_id + JOIN teams t ON t.id = cpi.team_id WHERE cpi.is_funded AND t.is_approved AND NOT (p.is_suspicious IS true) diff --git a/www/dashboard/index.spt b/www/dashboard/index.spt index 5fd04beb25..e572ec9731 100644 --- a/www/dashboard/index.spt +++ b/www/dashboard/index.spt @@ -9,8 +9,8 @@ unreviewed = website.db.all(""" SELECT username , balance - , (SELECT SUM(amount) FROM current_payment_instructions WHERE participant = p.username) AS giving - , (SELECT COUNT(*) FROM current_payment_instructions WHERE participant = p.username AND amount > 0) AS ngiving_to + , (SELECT SUM(amount) FROM current_payment_instructions WHERE participant_id = p.id) AS giving + , (SELECT COUNT(*) FROM current_payment_instructions WHERE participant_id = p.id AND amount > 0) AS ngiving_to FROM participants p WHERE is_suspicious IS NULL AND ( -- They have a payin/payout route set up.