Skip to content
This repository has been archived by the owner on Nov 22, 2023. It is now read-only.

Commit

Permalink
bookings: Fix get_wallet_balance that would sum all deposits
Browse files Browse the repository at this point in the history
And by "all", I mean all deposits. Of all users. Which made for a
substantial wallet balance...
  • Loading branch information
dbaty committed Feb 11, 2021
1 parent 023874e commit e916cfc
Show file tree
Hide file tree
Showing 2 changed files with 57 additions and 1 deletion.
56 changes: 56 additions & 0 deletions src/pcapi/alembic/versions/514dfbeddddf_fix_get_wallet_balance.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,56 @@
"""Update `check_booking`
Revision ID: 514dfbeddddf
Revises: 0867450b4c30
Create Date: 2021-02-08 10:58:14.217608
"""
from alembic import op


# revision identifiers, used by Alembic.
revision = "514dfbeddddf"
down_revision = "0867450b4c30"
branch_labels = None
depends_on = None


def upgrade():
op.execute(
"""
CREATE OR REPLACE FUNCTION get_wallet_balance(user_id BIGINT, only_used_bookings BOOLEAN)
RETURNS NUMERIC(10,2) AS $$
DECLARE
sum_deposits NUMERIC ;
sum_bookings NUMERIC ;
BEGIN
SELECT COALESCE(SUM(amount), 0)
INTO sum_deposits
FROM deposit
WHERE "userId"=user_id
AND ("expirationDate" > now() OR "expirationDate" IS NULL);
CASE
only_used_bookings
WHEN true THEN
SELECT COALESCE(SUM(amount * quantity), 0)
INTO sum_bookings
FROM booking
WHERE "userId"=user_id AND NOT "isCancelled" AND "isUsed" = true;
WHEN false THEN
SELECT COALESCE(SUM(amount * quantity), 0)
INTO sum_bookings
FROM booking
WHERE "userId"=user_id AND NOT "isCancelled";
END CASE;
RETURN (sum_deposits - sum_bookings);
END; $$
LANGUAGE plpgsql;
"""
)


def downgrade():
# No downgrade, since the previous version of the SQL function has a huge bug.
pass
2 changes: 1 addition & 1 deletion src/pcapi/core/bookings/models.py
Original file line number Diff line number Diff line change
Expand Up @@ -143,7 +143,7 @@ def isConfirmed(self):
INTO sum_deposits
FROM deposit
WHERE "userId"=user_id
AND "expirationDate" > now() OR "expirationDate" IS NULL;
AND ("expirationDate" > now() OR "expirationDate" IS NULL);
CASE
only_used_bookings
Expand Down

0 comments on commit e916cfc

Please sign in to comment.