Add flush_payments to clean up draft and pending payments

I always intended to delete draft payments after some time. I follow
WooCommerce’s default times: 1 day for draft and 1 hour for pending. No
other reason than we are used to it.

I added a cron job, rather than a systemd timer, because i want email
notifications, and because i do not yet know how to add many service
files in a Debian package.
This commit is contained in:
jordi fita mas 2024-03-13 14:54:30 +01:00
parent 75e0d8e197
commit 5cf45dcd41
6 changed files with 175 additions and 0 deletions

1
debian/camper.cron.d vendored Normal file
View File

@ -0,0 +1 @@
42 * * * * camper /usr/bin/psql --quiet --output=/dev/null --command='set role guest; select * from flush_payments()'

52
deploy/flush_payments.sql Normal file
View File

@ -0,0 +1,52 @@
-- Deploy camper:flush_payments to pg
-- requires: roles
-- requires: schema_camper
-- requires: payment
-- requires: payment_option
-- requires: payment_redsys_response
begin;
set search_path to camper, public;
create or replace function flush_payments() returns void as
$$
delete from payment_redsys_response
where payment_id in (
select payment_id
from payment
where payment_status = 'draft'
and updated_at <= current_timestamp - interval '1 day'
);
delete from payment_option
where payment_id in (
select payment_id
from payment
where payment_status = 'draft'
and updated_at <= current_timestamp - interval '1 day'
);
delete from payment
where payment_status = 'draft'
and updated_at <= current_timestamp - interval '1 day'
;
update payment
set payment_status = 'failed'
, updated_at = current_timestamp
where payment_status = 'pending'
and updated_at <= current_timestamp - interval '1 hour'
;
$$
language sql
security definer
set search_path = camper, pg_temp;
;
revoke execute on function flush_payments() from public;
grant execute on function flush_payments() to guest;
grant execute on function flush_payments() to employee;
grant execute on function flush_payments() to admin;
commit;

View File

@ -0,0 +1,7 @@
-- Revert camper:flush_payments from pg
begin;
drop function if exists camper.flush_payments();
commit;

View File

@ -262,3 +262,4 @@ payment_reference [roles schema_camper payment] 2024-02-14T01:45:37Z jordi fita
company__tourist_tax_max_days [company] 2024-02-27T18:03:51Z jordi fita mas <jordi@tandem.blog> # Add tourist_tax_max_days to company company__tourist_tax_max_days [company] 2024-02-27T18:03:51Z jordi fita mas <jordi@tandem.blog> # Add tourist_tax_max_days to company
draft_payment [draft_payment@v4 company__tourist_tax_max_days] 2024-02-27T17:49:05Z jordi fita mas <jordi@tandem.blog> # Limit the number of nights that have tourist tax in draft_payment draft_payment [draft_payment@v4 company__tourist_tax_max_days] 2024-02-27T17:49:05Z jordi fita mas <jordi@tandem.blog> # Limit the number of nights that have tourist tax in draft_payment
grant_select_on_payment_status_to_guest [roles payment_status payment_status_i18n] 2024-02-29T16:42:13Z jordi fita mas <jordi@tandem.blog> # Grant SELECT on payment_status and payment_status_i18n to guest grant_select_on_payment_status_to_guest [roles payment_status payment_status_i18n] 2024-02-29T16:42:13Z jordi fita mas <jordi@tandem.blog> # Grant SELECT on payment_status and payment_status_i18n to guest
flush_payments [roles schema_camper payment payment_option payment_redsys_response] 2024-03-13T12:58:04Z jordi fita mas <jordi@tandem.blog> # Add function to flush payments

107
test/flush_payments.sql Normal file
View File

@ -0,0 +1,107 @@
-- Test flush_payments
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(13);
set search_path to camper, public;
select has_function('camper', 'flush_payments', array[]::text[]);
select function_lang_is('camper', 'flush_payments', array[]::text[], 'sql');
select function_returns('camper', 'flush_payments', array[]::text[], 'void');
select is_definer('camper', 'flush_payments', array[]::text[]);
select volatility_is('camper', 'flush_payments', array[]::text[], 'volatile');
select function_privs_are('camper', 'flush_payments', array []::text[], 'guest', array['EXECUTE']);
select function_privs_are('camper', 'flush_payments', array []::text[], 'employee', array['EXECUTE']);
select function_privs_are('camper', 'flush_payments', array []::text[], 'admin', array['EXECUTE']);
select function_privs_are('camper', 'flush_payments', array []::text[], 'authenticator', array[]::text[]);
set client_min_messages to warning;
truncate payment_redsys_response cascade;
truncate payment_option cascade;
truncate payment cascade;
truncate campsite_type_option cascade;
truncate campsite_type cascade;
truncate media cascade;
truncate media_content cascade;
truncate company cascade;
reset client_min_messages;
insert into company (company_id, business_name, vatin, trade_name, phone, email, web, address, city, province, postal_code, rtc_number, tourist_tax, tourist_tax_max_days, country_code, currency_code, default_lang_tag)
values (2, 'Company 2', 'XX123', '', '555-555-555', 'a@a', '', '', '', '', '', '', 350, 7, 'ES', 'EUR', 'ca')
;
insert into media_content (media_type, bytes)
values ('image/x-xpixmap', 'static char *s[]={"1 1 1 1","a c #ffffff","a"};')
;
insert into media (media_id, company_id, original_filename, content_hash)
values (10, 2, 'cover2.xpm', sha256('static char *s[]={"1 1 1 1","a c #ffffff","a"};'))
;
insert into campsite_type (campsite_type_id, slug, company_id, name, media_id, max_campers, bookable_nights, overflow_allowed)
values (12, 'c1b6f4fc-32c1-4cd5-b796-0c5059152a52', 2, 'Plots', 10, 6, '[1, 7]', true)
;
insert into campsite_type_option (campsite_type_option_id, campsite_type_id, name, range, per_night)
values (16, 12, 'Big tent', '[0, 4)', true)
;
insert into payment (payment_id, company_id, campsite_type_id, arrival_date, departure_date, subtotal_nights, number_adults, subtotal_adults, number_teenagers, subtotal_teenagers, number_children, subtotal_children, number_dogs, subtotal_dogs, subtotal_tourist_tax, total, currency_code, zone_preferences, payment_status, created_at, updated_at)
values (22, 2, 12, '2024-08-29', '2024-09-03', 71000, 1, 0, 2, 0, 3, 0, 0, 0, 1750, 72750, 'EUR', '', 'draft', '2024-01-01 01:01:01', current_timestamp - interval '1 day, -1 second')
, (24, 2, 12, '2024-08-29', '2024-09-03', 71000, 1, 0, 2, 0, 3, 0, 0, 0, 1750, 72750, 'EUR', '', 'draft', '2024-01-01 01:01:01', current_timestamp - interval '1 day, 1 second')
, (26, 2, 12, '2024-08-29', '2024-09-03', 71000, 1, 0, 2, 0, 3, 0, 0, 0, 1750, 72750, 'EUR', '', 'pending', '2024-01-02 02:02:02', current_timestamp - interval '1 hour, -1 second')
, (28, 2, 12, '2024-08-29', '2024-09-03', 71000, 1, 0, 2, 0, 3, 0, 0, 0, 1750, 72750, 'EUR', '', 'pending', '2024-01-03 03:03:03', current_timestamp - interval '1 hour, 1 second')
, (30, 2, 12, '2024-08-29', '2024-09-03', 71000, 1, 0, 2, 0, 3, 0, 0, 0, 1750, 72750, 'EUR', '', 'preauth', '2024-01-04 04:04:04', current_timestamp - interval '2 days')
, (32, 2, 12, '2024-08-29', '2024-09-03', 71000, 1, 0, 2, 0, 3, 0, 0, 0, 1750, 72750, 'EUR', '', 'failed', '2024-01-05 05:05:05', current_timestamp - interval '2 days')
, (34, 2, 12, '2024-08-29', '2024-09-03', 71000, 1, 0, 2, 0, 3, 0, 0, 0, 1750, 72750, 'EUR', '', 'completed', '2024-01-05 05:05:05', current_timestamp - interval '2 days')
, (36, 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', current_timestamp - interval '2 days')
, (38, 2, 12, '2024-08-29', '2024-09-03', 71000, 1, 0, 2, 0, 3, 0, 0, 0, 1750, 72750, 'EUR', '', 'voided', '2024-01-05 05:05:05', current_timestamp - interval '2 days')
;
insert into payment_option (payment_id, campsite_type_option_id, units, subtotal)
select payment_id, 16, 1, 12 from payment;
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)
select payment_id, 0, current_timestamp, true, 0, 123, 'EUR', '12#2', '123', '123', 1, '' from payment;
set role guest;
select lives_ok($$ select * from flush_payments() $$, 'Should be able to run the function as guest');
reset role;
select bag_eq(
$$ select payment_id, payment_status, updated_at from payment $$,
$$ values (22, 'draft', current_timestamp - interval '1 day, -1 second')
, (26, 'pending', current_timestamp - interval '1 hour, -1 second')
, (28, 'failed', current_timestamp)
, (30, 'preauth', current_timestamp - interval '2 days')
, (32, 'failed', current_timestamp - interval '2 days')
, (34, 'completed', current_timestamp - interval '2 days')
, (36, 'refunded', current_timestamp - interval '2 days')
, (38, 'voided', current_timestamp - interval '2 days')
$$,
'Should have removed expired drafts, and cancelled overdue pending orders'
);
select set_eq (
$$ select payment_id from payment_option $$,
$$ select payment_id from payment $$,
'Should have deleted only draft options'
);
select set_eq (
$$ select payment_id from payment_redsys_response $$,
$$ select payment_id from payment $$,
'Should have deleted only draft responses'
);
select *
from finish();
rollback;

View File

@ -0,0 +1,7 @@
-- Verify camper:flush_payments on pg
begin;
select has_function_privilege('camper.flush_payments()', 'execute');
rollback;