billing_type TEXT,
payment_ou INT,
billing_ou INT,
+-- Debug billing_leftover NUMERIC(8,2),
+-- Debug payment_leftover NUMERIC(8,2),
CONSTRAINT x_p_b_once UNIQUE (xact,payment,billing)
);
payment_offset INT := 0;
billing_offset INT := 0;
billing_ou INT := 0;
- payment_ou INT := 0;
+ payment_ou INT := 0;
+ fast_forward BOOLEAN := FALSE;
+ maintain_billing_remainder BOOLEAN := FALSE;
+ billing_loop INT := -1;
+ billing_row_count INT := 0;
BEGIN
/* This algorithm is fairly straight-forward. We take a transaction id
SELECT circ_lib INTO billing_ou FROM action.circulation WHERE id = p_xact;
END IF;
+ -- figure out how many billing rows there are
+ FOR current_billing IN
+ SELECT *
+ FROM money.billing
+ WHERE xact = p_xact
+ -- AND NOT voided
+ ORDER BY billing_ts
+ LOOP
+ billing_row_count = billing_row_count + 1;
+ END LOOP;
-- Loop through the positive payments
FOR current_payment IN
SELECT *
LOOP
payment_remainder = current_payment.amount;
-
+ -- With every new payment row, we need to fast forward
+ -- the billing lines up to the last paid billing row
+ fast_forward := TRUE;
IF current_payment.payment_type IN ( 'cash_payment', 'check_payment', 'credit_card_payment' ) THEN
SELECT ws.owning_lib INTO payment_ou
FROM money.bnm_desk_payment p
END IF;
-- Were we looking at a billing from a previous step in the loop?
- IF billing_remainder > 0.0 THEN
-
+ IF billing_remainder > 0.0 THEN
current_result.xact = p_xact;
current_result.payment = current_payment.id;
current_result.billing = current_billing.id;
current_result.billing_type = current_billing.billing_type;
current_result.payment_ou = payment_ou;
current_result.billing_ou = billing_ou;
+-- Debug current_result.billing_leftover = billing_remainder;
+-- Debug current_result.payment_leftover = payment_remainder;
IF billing_remainder >= payment_remainder THEN
current_result.amount = payment_remainder;
billing_remainder = billing_remainder - payment_remainder;
payment_remainder = 0.0;
payment_offset = payment_offset + 1;
+ -- If it is equal then we need to close up the billing line and move to the next
+ -- This prevents 0 amounts applied to billing lines
+ IF billing_remainder = payment_remainder THEN
+ billing_remainder = 0.0;
+ billing_offset = billing_offset + 1;
+ ELSE
+ maintain_billing_remainder := TRUE;
+ END IF;
+
ELSE
current_result.amount = billing_remainder;
payment_remainder = payment_remainder - billing_remainder;
billing_remainder = 0.0;
+ billing_offset = billing_offset + 1;
END IF;
RETURN NEXT current_result;
-
+ -- Done paying the billing rows when we run out of rows to pay (out of bounds)
+ EXIT WHEN billing_offset = billing_row_count+1;
END IF;
CONTINUE WHEN payment_remainder = 0.0;
SELECT *
FROM money.billing
WHERE xact = p_xact
- -- AND NOT voided
- ORDER BY billing_ts
+ -- AND NOT voided
+ -- Gotta put the voided billing rows at the bottom (last)
+ ORDER BY voided,billing_ts
LOOP
-
- billing_remainder = current_billing.amount;
-
+ -- Fast forward through the rows until we get to the billing row
+ -- where we left off
+ IF fast_forward THEN
+ billing_loop = billing_loop + 1; -- first iteration billing_loop=0, it starts at -1
+ CONTINUE WHEN billing_loop <> billing_offset;
+ END IF;
+
+ -- Keep the old remainder if we were in the middle of a billing row
+ IF NOT maintain_billing_remainder THEN
+ billing_remainder = current_billing.amount;
+ END IF;
+
+ maintain_billing_remainder := FALSE;
+ billing_loop := -1;
+ fast_forward := FALSE;
+
current_result.xact = p_xact;
current_result.payment = current_payment.id;
current_result.billing = current_billing.id;
current_result.billing_type = current_billing.billing_type;
current_result.payment_ou = payment_ou;
current_result.billing_ou = billing_ou;
+-- Debug current_result.billing_leftover = billing_remainder;
+-- Debug current_result.payment_leftover = payment_remainder;
IF billing_remainder >= payment_remainder THEN
current_result.amount = payment_remainder;
IF NOT current_billing.voided THEN
payment_remainder = 0.0;
END IF;
+ -- If it is equal then we need to close up the billing line and move to the next
+ -- This prevents 0 amounts applied to billing lines
+ IF billing_remainder = payment_remainder THEN
+ billing_remainder = 0.0;
+ billing_offset = billing_offset + 1;
+ END IF;
ELSE
current_result.amount = billing_remainder;
IF NOT current_billing.voided THEN
RETURN NEXT current_result;
EXIT WHEN payment_remainder = 0.0;
-
END LOOP;
payment_offset = payment_offset + 1;
+ -- Done paying the billing rows when we run out of rows to pay (out of bounds)
+ EXIT WHEN billing_offset = billing_row_count+1;
END LOOP;
billing_remainder := 0.0;
payment_offset := 0;
billing_offset := 0;
-
+ billing_row_count := 0;
+ billing_loop := -1;
+
+-- figure out how many voided billing rows there are
+ FOR current_billing IN
+ SELECT *
+ FROM money.billing
+ WHERE xact = p_xact
+ AND voided
+ ORDER BY billing_ts
+ LOOP
+ billing_row_count = billing_row_count + 1;
+ END LOOP;
+
-- Loop through the negative payments, these are refunds on voided billings
FOR current_payment IN
SELECT *
END IF;
payment_remainder = -current_payment.amount; -- invert
-
+ -- With every new payment row, we need to fast forward
+ -- the billing lines up to the last paid billing row
+ fast_forward := TRUE;
+
-- Were we looking at a billing from a previous step in the loop?
IF billing_remainder > 0.0 THEN
current_result.billing_type = current_billing.billing_type;
current_result.payment_ou = payment_ou;
current_result.billing_ou = billing_ou;
+-- Debug current_result.billing_leftover = billing_remainder;
+-- Debug current_result.payment_leftover = payment_remainder;
IF billing_remainder >= payment_remainder THEN
- current_result.amount = payment_remainder;
- billing_remainder = billing_remainder - payment_remainder;
- payment_remainder = 0.0;
- payment_offset = payment_offset + 1;
+ current_result.amount = payment_remainder;
+ billing_remainder = billing_remainder - payment_remainder;
+ payment_remainder = 0.0;
+ payment_offset = payment_offset + 1;
+ -- If it is equal then we need to close up the billing line and move to the next
+ -- This prevents 0 amounts applied to billing lines
+ IF billing_remainder = payment_remainder THEN
+ billing_remainder = 0.0;
+ billing_offset = billing_offset + 1;
+ ELSE
+ maintain_billing_remainder := TRUE;
+ END IF;
ELSE
- current_result.amount = billing_remainder;
+ current_result.amount = billing_remainder;
payment_remainder = payment_remainder - billing_remainder;
billing_remainder = 0.0;
+ billing_offset = billing_offset + 1;
END IF;
current_result.amount = -current_result.amount;
RETURN NEXT current_result;
-
+ -- Done paying the billing rows when we run out of rows to pay (out of bounds)
+ EXIT WHEN billing_offset = billing_row_count+1;
END IF;
CONTINUE WHEN payment_remainder = 0.0;
AND voided
ORDER BY billing_ts
LOOP
-
- billing_remainder = current_billing.amount;
+ -- Fast forward through the rows until we get to the billing row
+ -- where we left off
+ IF fast_forward THEN
+ billing_loop = billing_loop + 1; -- first iteration billing_loop=0, it starts at -1
+ CONTINUE WHEN billing_loop <> billing_offset;
+ END IF;
+
+ -- Keep the old remainder if we were in the middle of a billing row
+ IF NOT maintain_billing_remainder THEN
+ billing_remainder = current_billing.amount;
+ END IF;
+
+ maintain_billing_remainder := FALSE;
+ billing_loop := -1;
+ fast_forward := FALSE;
current_result.xact = p_xact;
current_result.payment = current_payment.id;
current_result.billing_type = current_billing.billing_type;
current_result.payment_ou = payment_ou;
current_result.billing_ou = billing_ou;
+-- Debug current_result.billing_leftover = billing_remainder;
+-- Debug current_result.payment_leftover = payment_remainder;
IF billing_remainder >= payment_remainder THEN
current_result.amount = payment_remainder;
billing_remainder = billing_remainder - payment_remainder;
payment_remainder = 0.0;
+ -- If it is equal then we need to close up the billing line and move to the next
+ -- This prevents 0 amounts applied to billing lines
+ IF billing_remainder = payment_remainder THEN
+ billing_remainder = 0.0;
+ billing_offset = billing_offset + 1;
+ END IF;
ELSE
current_result.amount = billing_remainder;
payment_remainder = payment_remainder - billing_remainder;
END LOOP;
payment_offset = payment_offset + 1;
+ -- Done paying the billing rows when we run out of rows to pay (out of bounds)
+ EXIT WHEN billing_offset = billing_row_count+1;
END LOOP;
AFTER INSERT OR UPDATE OR DELETE ON money.credit_card_payment
FOR EACH ROW EXECUTE PROCEDURE money.payment_by_billing_type_trigger();
-
-
COMMIT;