Add authorization holding for payments

This is the mode they want to work with, but i could not test it because
they do not have it enabled in Redsys.  For now, just add the status and
the code to handle the responses.

Now i store all responses, if they are for a valid payment, just in case
i fucked something up. I also needed it because an authorization hold
needs at least two responses: one to accept the hold, and another for
the settlement.
This commit is contained in:
jordi fita mas 2024-02-15 15:17:21 +01:00
parent f2143cd0e6
commit 3bc4175580
8 changed files with 116 additions and 37 deletions

View File

@ -7,27 +7,35 @@ begin;
insert into camper.payment_status (payment_status, name)
values ('draft', 'Draft')
, ('pending', 'Pending')
, ('preauth', 'Authorization held')
, ('failed', 'Failed')
, ('completed', 'Completed')
, ('refunded', 'Refunded')
, ('voided', 'Voided')
;
insert into camper.payment_status_i18n (payment_status, lang_tag, name)
values ('draft', 'ca', 'Esborrany')
, ('pending', 'ca', 'Pendent')
, ('preauth', 'ca', 'Autorització retinguda')
, ('failed', 'ca', 'No realitzat')
, ('completed', 'ca', 'Completat')
, ('refunded', 'ca', 'Reemborsat')
, ('voided', 'ca', 'Anul·lat')
, ('draft', 'es', 'Borrador')
, ('pending', 'es', 'Pendiente')
, ('preauth', 'es', 'Autorización retenida')
, ('failed', 'es', 'Fallido')
, ('completed', 'es', 'Completado')
, ('refunded', 'es', 'Reembolsado')
, ('voided', 'es', 'Anulado')
, ('draft', 'fr', 'Brouillon')
, ('pending', 'fr', 'En attente')
, ('preauth', 'fr', 'Autorisation détenue')
, ('failed', 'fr', 'Échouée')
, ('completed', 'fr', 'Terminée')
, ('refunded', 'fr', 'Remboursée')
, ('voided', 'fr', 'Annulé')
;
commit;

View File

@ -9,7 +9,8 @@ begin;
set search_path to camper, public;
create table payment_redsys_response (
payment_id integer primary key references payment,
payment_redsys_response_id integer generated by default as identity primary key,
payment_id integer not null references payment,
response_code integer not null,
date_time timestamp without time zone not null,
secure_payment boolean not null,

View File

@ -17,22 +17,40 @@ declare
pid integer;
next_status text;
begin
if response.transaction_type <> 0 then
if response.transaction_type not in (0, 1, 2, 3, 9) then
raise invalid_parameter_value using message = response.transaction_type || ' is not a processable transaction type';
end if;
update payment
set payment_status = case when response.response_code < 100 then 'completed' else 'failed' end
, updated_at = current_timestamp
where slug = payment_slug
and payment_status in ('pending', 'failed')
returning payment_id, payment_status
into pid, next_status;
select payment_id into pid from payment where slug = payment_slug;
if pid is null then
return '';
end if;
update payment
set payment_status = case response.transaction_type
when 0 then -- charge
case when response.response_code < 100 then 'completed' else 'failed' end
when 1 then -- authorization hold
case when response.response_code < 100 then 'preauth' else 'failed' end
when 2 then -- confirm authorization hold
case when response.response_code = 900 then 'completed' else payment_status end
when 3 then -- refund
case when response.response_code = 900 then 'refunded' else payment_status end
when 9 then -- void authorization hold
case when response.response_code = 400 then 'voided' else payment_status end
else
payment_status
end
, updated_at = current_timestamp
where payment_id = pid
and (
(response.transaction_type in (0, 1) and payment_status in ('pending', 'failed'))
or (response.transaction_type in (2, 9) and payment_status in ('preauth', 'failed'))
or (response.transaction_type = 3 and payment_status = 'completed')
)
returning payment_status
into next_status;
insert into payment_redsys_response (
payment_id
, response_code
@ -61,21 +79,9 @@ begin
, response.error_code
from currency
where currency.currency_code = response.currency_code
on conflict (payment_id) do update
set response_code = excluded.response_code
, date_time = excluded.date_time
, secure_payment = excluded.secure_payment
, transaction_type = excluded.transaction_type
, amount = excluded.amount
, currency_code = excluded.currency_code
, order_number = excluded.order_number
, authorization_code = excluded.authorization_code
, merchant_code = excluded.merchant_code
, terminal_number = excluded.terminal_number
, error_code = excluded.error_code
;
return next_status;
return coalesce(next_status, '');
end;
$$
language plpgsql

View File

@ -5,7 +5,7 @@ reset client_min_messages;
begin;
select plan(59);
select plan(63);
set search_path to camper, public;
@ -16,8 +16,13 @@ select table_privs_are('payment_redsys_response', 'employee', array['SELECT', 'I
select table_privs_are('payment_redsys_response', 'admin', array['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('payment_redsys_response', 'authenticator', array[]::text[]);
select has_column('payment_redsys_response', 'payment_redsys_response_id');
select col_is_pk('payment_redsys_response', 'payment_redsys_response_id');
select col_type_is('payment_redsys_response', 'payment_redsys_response_id', 'integer');
select col_not_null('payment_redsys_response', 'payment_redsys_response_id');
select col_hasnt_default('payment_redsys_response', 'payment_redsys_response_id');
select has_column('payment_redsys_response', 'payment_id');
select col_is_pk('payment_redsys_response', 'payment_id');
select col_is_fk('payment_redsys_response', 'payment_id');
select fk_ok('payment_redsys_response', 'payment_id', 'payment', 'payment_id');
select col_type_is('payment_redsys_response', 'payment_id', 'integer');

View File

@ -5,7 +5,7 @@ reset client_min_messages;
begin;
select plan(19);
select plan(24);
set search_path to camper, public;
@ -52,6 +52,9 @@ values (22, '4ef35e2f-ef98-42d6-a724-913bd761ca8c', 2, 12, '2024-08-28', '2024-0
, (30, '31910d73-d343-44b7-8a29-f7e075b64933', 2, 12, '2024-08-29', '2024-09-03', 71000, 1, 0, 2, 0, 3, 0, 0, 0, 1750, 72750, 'EUR', '', 'refunded', '2024-01-05 05:05:05', '2024-01-05 05:05:05')
, (32, 'c9488490-ac09-4402-90cd-f6f0546f04c0', 2, 12, '2024-08-29', '2024-09-03', 71000, 1, 0, 2, 0, 3, 0, 0, 0, 1750, 72750, 'EUR', '', 'pending', '2024-01-05 05:05:05', '2024-01-05 05:05:05')
, (34, '5819823e-c0ac-4baa-a3ae-515fbb70e909', 2, 12, '2024-08-29', '2024-09-03', 71000, 1, 0, 2, 0, 3, 0, 0, 0, 1750, 72750, 'EUR', '', 'pending', '2024-01-05 05:05:05', '2024-01-06 06:06:06')
, (36, 'f2871c2d-e11a-41e8-b264-0a8605c77dc1', 2, 12, '2024-08-29', '2024-09-03', 71000, 1, 0, 2, 0, 3, 0, 0, 0, 1750, 72750, 'EUR', '', 'pending', '2024-01-05 05:05:05', '2024-01-06 06:06:06')
, (38, '01505d14-6f4d-48a2-9a98-3a2099ab7eef', 2, 12, '2024-08-29', '2024-09-03', 71000, 1, 0, 2, 0, 3, 0, 0, 0, 1750, 72750, 'EUR', '', 'preauth', '2024-01-05 05:05:05', '2024-01-06 06:06:06')
, (40, '7cae7d1c-d626-41e0-b1c5-48359e515579', 2, 12, '2024-08-29', '2024-09-03', 71000, 1, 0, 2, 0, 3, 0, 0, 0, 1750, 72750, 'EUR', '', 'preauth', '2024-01-05 05:05:05', '2024-01-06 06:06:06')
;
insert into payment_redsys_response (payment_id, response_code, date_time, secure_payment, transaction_type, amount, currency_code, order_number, authorization_code, merchant_code, terminal_number, error_code)
@ -100,10 +103,41 @@ select is(
'Should NOT change a payment twice'
);
select is(
process_payment_response('f2871c2d-e11a-41e8-b264-0a8605c77dc1', row('3322450', 5, 0, '2024-02-07 12:23:34', true, 1, '12.40', 'EUR', '00000032c948', '130', '')::redsys_response),
'preauth',
'Should preauth a pending payment if response code < 100'
);
select is(
process_payment_response('f2871c2d-e11a-41e8-b264-0a8605c77dc1', row('3322450', 5, 900, '2024-02-07 12:23:34', true, 2, '12.40', 'EUR', '00000032c948', '131', '')::redsys_response),
'completed',
'Should confirm a preauth payment if response code = 900'
);
select is(
process_payment_response('01505d14-6f4d-48a2-9a98-3a2099ab7eef', row('3322450', 5, 101, '2024-02-07 12:23:34', true, 2, '12.40', 'EUR', '00000032c948', '132', '')::redsys_response),
'preauth',
'Should leave a preauth payment as is if response code <> 900'
);
select is(
process_payment_response('7cae7d1c-d626-41e0-b1c5-48359e515579', row('3322450', 5, 400, '2024-02-07 12:23:34', true, 9, '12.40', 'EUR', '00000032c948', '133', '')::redsys_response),
'voided',
'Should void a preauth payment if response code = 400'
);
select is(
process_payment_response('01505d14-6f4d-48a2-9a98-3a2099ab7eef', row('3322450', 5, 900, '2024-02-07 12:23:34', true, 9, '12.40', 'EUR', '00000032c948', '134', '')::redsys_response),
'preauth',
'Should leave a preauth payment as is if response code <> 400'
);
select throws_ok(
$$ select process_payment_response('5819823e-c0ac-4baa-a3ae-515fbb70e909', row('3322445', 2, 0, '2024-02-02 12:23:34', false, 3, '12.41', 'USD', '000000345819', '130', '')::redsys_response) $$,
'22023', '3 is not a processable transaction type',
'Only transaction type = 0 are allowed for now'
$$ select process_payment_response('5819823e-c0ac-4baa-a3ae-515fbb70e909', row('3322445', 2, 0, '2024-02-02 12:23:34', false, 13, '12.41', 'USD', '000000345819', '135', '')::redsys_response) $$,
'22023', '13 is not a processable transaction type',
'Only transaction types 0, 1, 2, 3, and 9 are allowed.'
);
select bag_eq(
@ -115,15 +149,28 @@ select bag_eq(
, (30, 'refunded', '2024-01-05 05:05:05')
, (32, 'completed', current_timestamp)
, (34, 'pending', '2024-01-06 06:06:06')
, (36, 'completed', current_timestamp)
, (38, 'preauth', current_timestamp)
, (40, 'voided', current_timestamp)
$$,
'Should have updated payments'
);
select bag_eq(
$$ select payment_id, merchant_code, terminal_number, response_code, date_time::text, secure_payment, transaction_type, amount, currency_code, order_number, authorization_code, error_code from payment_redsys_response $$,
$$ values (24, '3322446', 2, 100, '2024-02-03 12:23:34', false, 0, 1236, 'USD', '000000246d1b', '125', 'ERR')
$$ values (22, '3322445', 2, 0, '2024-02-02 12:23:34', true, 0, 1235, 'EUR', '000000224ef3', '124', '')
, (24, '3322446', 2, 100, '2024-02-03 12:23:34', false, 0, 1236, 'USD', '000000246d1b', '125', 'ERR')
, (26, '3322447', 3, 0, '2024-02-04 12:23:34', true, 0, 1237, 'EUR', '000000268d3a', '126', '')
, (28, '1234567', 5, 0, '2023-01-01 01:01:01', false, 1, 1000, 'EUR', 'huh?', '123', '123')
, (28, '3322448', 4, 99, '2024-02-05 12:23:34', true, 0, 1238, 'EUR', '00000028b770', '127', '')
, (30, '3322449', 5, 0, '2024-02-06 12:23:34', false, 0, 1239, 'EUR', '000000303190', '128', '')
, (32, '3322450', 6, 0, '2024-02-07 12:23:34', true, 0, 1240, 'EUR', '00000032c948', '129', 'NOPE')
, (32, '3322450', 6, 0, '2024-02-07 12:23:34', true, 0, 1240, 'EUR', '00000032c948', '129', '')
, (36, '3322450', 5, 0, '2024-02-07 12:23:34', true, 1, 1240, 'EUR', '00000032c948', '130', '')
, (36, '3322450', 5, 900, '2024-02-07 12:23:34', true, 2, 1240, 'EUR', '00000032c948', '131', '')
, (38, '3322450', 5, 101, '2024-02-07 12:23:34', true, 2, 1240, 'EUR', '00000032c948', '132', '')
, (38, '3322450', 5, 900, '2024-02-07 12:23:34', true, 9, 1240, 'EUR', '00000032c948', '134', '')
, (40, '3322450', 5, 400, '2024-02-07 12:23:34', true, 9, 1240, 'EUR', '00000032c948', '133', '')
$$,
'Should have added responses'
);

View File

@ -6,25 +6,34 @@ set search_path to camper;
select 1 / count(*) from payment_status where payment_status = 'draft' and name = 'Draft';
select 1 / count(*) from payment_status where payment_status = 'pending' and name = 'Pending';
select 1 / count(*) from payment_status where payment_status = 'preauth' and name = 'Authorization held';
select 1 / count(*) from payment_status where payment_status = 'failed' and name = 'Failed';
select 1 / count(*) from payment_status where payment_status = 'completed' and name = 'Completed';
select 1 / count(*) from payment_status where payment_status = 'refunded' and name = 'Refunded';
select 1 / count(*) from payment_status where payment_status = 'voided' and name = 'Voided';
select 1 / count(*) from payment_status_i18n where payment_status = 'draft' and lang_tag = 'ca' and name = 'Esborrany';
select 1 / count(*) from payment_status_i18n where payment_status = 'pending' and lang_tag = 'ca' and name = 'Pendent';
select 1 / count(*) from payment_status_i18n where payment_status = 'preauth' and lang_tag = 'ca' and name = 'Autorització retinguda';
select 1 / count(*) from payment_status_i18n where payment_status = 'failed' and lang_tag = 'ca' and name = 'No realitzat';
select 1 / count(*) from payment_status_i18n where payment_status = 'completed' and lang_tag = 'ca' and name = 'Completat';
select 1 / count(*) from payment_status_i18n where payment_status = 'refunded' and lang_tag = 'ca' and name = 'Reemborsat';
select 1 / count(*) from payment_status_i18n where payment_status = 'voided' and lang_tag = 'ca' and name = 'Anul·lat';
select 1 / count(*) from payment_status_i18n where payment_status = 'draft' and lang_tag = 'es' and name = 'Borrador';
select 1 / count(*) from payment_status_i18n where payment_status = 'pending' and lang_tag = 'es' and name = 'Pendiente';
select 1 / count(*) from payment_status_i18n where payment_status = 'preauth' and lang_tag = 'es' and name = 'Autorización retenida';
select 1 / count(*) from payment_status_i18n where payment_status = 'failed' and lang_tag = 'es' and name = 'Fallido';
select 1 / count(*) from payment_status_i18n where payment_status = 'completed' and lang_tag = 'es' and name = 'Completado';
select 1 / count(*) from payment_status_i18n where payment_status = 'refunded' and lang_tag = 'es' and name = 'Reembolsado';
select 1 / count(*) from payment_status_i18n where payment_status = 'voided' and lang_tag = 'es' and name = 'Anulado';
select 1 / count(*) from payment_status_i18n where payment_status = 'draft' and lang_tag = 'fr' and name = 'Brouillon';
select 1 / count(*) from payment_status_i18n where payment_status = 'pending' and lang_tag = 'fr' and name = 'En attente';
select 1 / count(*) from payment_status_i18n where payment_status = 'preauth' and lang_tag = 'fr' and name = 'Autorisation détenue';
select 1 / count(*) from payment_status_i18n where payment_status = 'failed' and lang_tag = 'fr' and name = 'Échouée';
select 1 / count(*) from payment_status_i18n where payment_status = 'completed' and lang_tag = 'fr' and name = 'Terminée';
select 1 / count(*) from payment_status_i18n where payment_status = 'refunded' and lang_tag = 'fr' and name = 'Remboursée';
select 1 / count(*) from payment_status_i18n where payment_status = 'voided' and lang_tag = 'fr' and name = 'Annulé';
rollback;

View File

@ -2,7 +2,8 @@
begin;
select payment_id
select payment_redsys_response_id
, payment_id
, response_code
, date_time
, secure_payment

View File

@ -729,7 +729,7 @@ label[x-show] > span, label[x-show] > br {
/*<editor-fold desc="statuses">*/
.booking-created .booking-status,
.payment-draft .payment-status {
.payment-pending .payment-status {
background-color: var(--camper--color--light-blue);
}
@ -739,17 +739,19 @@ label[x-show] > span, label[x-show] > br {
}
.booking-confirmed .booking-status,
.payment-pending .payment-status {
.payment-preauth .payment-status {
background-color: var(--camper--color--hay);
}
.booking-checked-in .booking-status,
.payment-complete .payment-status {
.payment-completed .payment-status {
background-color: var(--camper--color--light-green);
}
.booking-invoiced .booking-status,
.payment-refunded .payment-status {
.payment-refunded .payment-status,
.payment-draft .payment-status,
.payment-voided .payment-status {
background-color: var(--camper--color--light-gray);
}