Add marshal_payment and unmarshal_booking functions

The idea is that we will marshal the payment, send it to the campsite’s
instance by email, and then unmarshal it as a booking, that way we can
have a one way replication from the internal to the public instance with
a way back to send the payments.

For testing purposes, i just create the booking in the same instance.

Had to change the booking relation’s permissions to allow insert from
a guest, much like for payments, because the notification from Redsys
comes as a guest connection.  I need this even with all the
marshal/unmarshal shenanigans because not everyone will have an internal
instance, thus need to allow bookings from guest connections.
This commit is contained in:
jordi fita mas 2024-04-29 20:59:22 +02:00
parent 7edf3a3ed1
commit b2ee4dfea3
12 changed files with 332 additions and 112 deletions

View File

@ -0,0 +1,67 @@
-- Deploy camper:marshal_payment to pg
-- requires: roles
-- requires: schema_camper
-- requires: payment
-- requires: payment_customer
-- requires: payment_option
-- requires: payment__acsi_card
-- requires: payment_customer__-acsi_card
begin;
set search_path to camper, public;
create or replace function marshal_payment(pid integer) returns jsonb as
$$
select to_jsonb(ctx)
from (
select 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
, acsi_card
, full_name
, address
, postal_code
, city
, country_code
, email
, phone
, lang_tag
, (
select array_agg(to_jsonb(o))
from (
select campsite_type_option_id
, units
, subtotal
from payment_option
where payment_option.payment_id = payment.payment_id
) o
) as options
from payment
join payment_customer using (payment_id)
where payment_id = pid
) as ctx;
$$
language sql
;
revoke execute on function marshal_payment(integer) from public;
grant execute on function marshal_payment(integer) to guest;
grant execute on function marshal_payment(integer) to employee;
grant execute on function marshal_payment(integer) to admin;
commit;

View File

@ -0,0 +1,100 @@
-- Deploy camper:unmarshal_booking to pg
-- requires: roles
-- requires: schema_camper
-- requires: booking
-- requires: booking_option
-- requires: extension_pg_libphonenumber
begin;
set search_path to camper, public;
grant select, insert on table booking to guest;
grant select, insert on table booking_option to guest;
drop policy if exists delete_from_company on booking;
drop policy if exists update_company on booking;
drop policy if exists insert_to_company on booking;
drop policy if exists select_from_company on booking;
alter table booking disable row level security;
create or replace function unmarshal_booking(data jsonb) returns integer as
$$
declare
bid integer;
begin
insert into booking
( company_id
, campsite_type_id
, stay
, 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
, acsi_card
, holder_name
, address
, postal_code
, city
, country_code
, email
, phone
, lang_tag
)
values((data->>'company_id')::integer
, (data->>'campsite_type_id')::integer
, daterange((data->>'arrival_date')::date, (data->>'departure_date')::date)
, (data->>'subtotal_nights')::integer
, (data->>'number_adults')::integer
, (data->>'subtotal_adults')::integer
, (data->>'number_teenagers')::integer
, (data->>'subtotal_teenagers')::integer
, (data->>'number_children')::integer
, (data->>'subtotal_children')::integer
, (data->>'number_dogs')::integer
, (data->>'subtotal_dogs')::integer
, (data->>'subtotal_tourist_tax')::integer
, (data->>'total')::integer
, data->>'currency_code'
, data->>'zone_preferences'
, (data->>'acsi_card')::boolean
, data->>'full_name'
, data->>'address'
, data->>'postal_code'
, data->>'city'
, data->>'country_code'
, data->>'email'
, parse_packed_phone_number(data->>'phone', data->>'country_code')
, data->>'lang_tag'
)
returning booking_id into bid;
if jsonb_typeof(data->'options') = 'array' then
insert into booking_option (booking_id, campsite_type_option_id, units, subtotal)
select bid, campsite_type_option_id, units, subtotal
from jsonb_to_recordset(data->'options') as x(campsite_type_option_id integer, units integer, subtotal integer)
;
end if;
return bid;
end;
$$
language plpgsql
;
revoke execute on function unmarshal_booking(jsonb) from public;
grant execute on function unmarshal_booking(jsonb) to guest;
grant execute on function unmarshal_booking(jsonb) to employee;
grant execute on function unmarshal_booking(jsonb) to admin;
commit;

View File

@ -257,6 +257,10 @@ func handleNotification(w http.ResponseWriter, r *http.Request, user *auth.User,
if err := sendEmail(r, conn, payment, company, user.Locale); err != nil { if err := sendEmail(r, conn, payment, company, user.Locale); err != nil {
log.Println("Could not send email:", err) log.Println("Could not send email:", err)
} }
// TODO: use email to send marshalled payment
if _, err := conn.Exec(r.Context(), "select unmarshal_booking(marshal_payment($1))", payment.ID); err != nil {
log.Println("Could not marshal payment:", err)
}
default: default:
} }
w.WriteHeader(http.StatusOK) w.WriteHeader(http.StatusOK)

View File

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

View File

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

View File

@ -330,3 +330,5 @@ edit_invoice [roles schema_camper invoice currency parse_price edited_invoice_pr
add_contact [roles schema_camper email extension_pg_libphonenumber country_code contact contact_email contact_phone] 2024-04-28T14:21:37Z jordi fita mas <jordi@tandem.blog> # Add function to create new contacts add_contact [roles schema_camper email extension_pg_libphonenumber country_code contact contact_email contact_phone] 2024-04-28T14:21:37Z jordi fita mas <jordi@tandem.blog> # Add function to create new contacts
edit_contact [roles schema_camper email country_code contact extension_pg_libphonenumber contact_email contact_phone] 2024-04-28T14:21:27Z jordi fita mas <jordi@tandem.blog> # Add function to edit contacts edit_contact [roles schema_camper email country_code contact extension_pg_libphonenumber contact_email contact_phone] 2024-04-28T14:21:27Z jordi fita mas <jordi@tandem.blog> # Add function to edit contacts
booking_invoice [roles schema_camper booking invoice] 2024-04-28T19:45:05Z jordi fita mas <jordi@tandem.blog> # Add relation of booking invoices booking_invoice [roles schema_camper booking invoice] 2024-04-28T19:45:05Z jordi fita mas <jordi@tandem.blog> # Add relation of booking invoices
marshal_payment [roles schema_camper payment payment_customer payment_option payment__acsi_card payment_customer__-acsi_card] 2024-04-29T17:11:59Z jordi fita mas <jordi@tandem.blog> # Add function to marshal a payment
unmarshal_booking [roles schema_camper booking booking_option extension_pg_libphonenumber] 2024-04-29T17:20:38Z jordi fita mas <jordi@tandem.blog> # Add function to unmarshal a booking

View File

@ -5,13 +5,13 @@ reset client_min_messages;
begin; begin;
select plan(156); select plan(142);
set search_path to camper, public; set search_path to camper, public;
select has_table('booking'); select has_table('booking');
select has_pk('booking'); select has_pk('booking');
select table_privs_are('booking', 'guest', array[]::text[]); select table_privs_are('booking', 'guest', array['SELECT', 'INSERT']);
select table_privs_are('booking', 'employee', array['SELECT', 'INSERT', 'UPDATE']); select table_privs_are('booking', 'employee', array['SELECT', 'INSERT', 'UPDATE']);
select table_privs_are('booking', 'admin', array['SELECT', 'INSERT', 'UPDATE', 'DELETE']); select table_privs_are('booking', 'admin', array['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('booking', 'authenticator', array[]::text[]); select table_privs_are('booking', 'authenticator', array[]::text[]);
@ -232,115 +232,6 @@ values (2, 10, 'Holder 2', daterange('2024-01-18', '2024-01-19'), 0, false, 'EUR
, (4, 12, 'Holder 4', daterange('2024-01-18', '2024-01-19'), 0, false, 'EUR', '', 0, 1, 0, 0, 0, 0, 0, 0, 0, 0) , (4, 12, 'Holder 4', daterange('2024-01-18', '2024-01-19'), 0, false, 'EUR', '', 0, 1, 0, 0, 0, 0, 0, 0, 0, 0)
; ;
prepare booking_data as
select company_id, holder_name
from booking
order by company_id, holder_name;
select set_cookie('12af4c88b528c2ad4222e3740496ecbc58e76e26f087657524/employee4@tandem.blog', 'co4');
select bag_eq(
'booking_data',
$$ values (4, 'Holder 4')
$$,
'Should only list bookings from second company'
);
reset role;
select set_cookie('44facbb30d8a419dfd4bfbc44a4b5539d4970148dfc84bed0e/employee2@tandem.blog', 'co2');
select bag_eq(
'booking_data',
$$ values (2, 'Holder 2')
$$,
'Should only list bookings from first company'
);
select lives_ok(
$$ insert into booking(company_id, campsite_type_id, holder_name, stay, number_dogs, acsi_card, currency_code, zone_preferences, subtotal_nights, number_adults, subtotal_adults, number_teenagers, subtotal_teenagers, number_children, subtotal_children, subtotal_dogs, subtotal_tourist_tax, total) values (2, 10, 'New Holder', daterange('2024-01-18', '2024-01-19'), 0, false, 'EUR', '', 0, 1, 0, 0, 0, 0, 0, 0, 0, 0) $$,
'Users from company 2 should be able to insert a new booking type to their company.'
);
select bag_eq(
'booking_data',
$$ values (2, 'Holder 2')
, (2, 'New Holder')
$$,
'The new row should have been added'
);
select lives_ok(
$$ update booking set holder_name = 'Another Holder' where company_id = 2 and holder_name = 'New Holder' $$,
'Users from company 2 should be able to update bookins of their company.'
);
select bag_eq(
'booking_data',
$$ values (2, 'Holder 2')
, (2, 'Another Holder')
$$,
'The row should have been updated.'
);
select throws_ok(
$$ insert into booking (company_id, campsite_type_id, holder_name, stay, number_dogs, acsi_card, currency_code, zone_preferences, subtotal_nights, number_adults, subtotal_adults, number_teenagers, subtotal_teenagers, number_children, subtotal_children, subtotal_dogs, subtotal_tourist_tax, total) values (4, 12, 'Another holder', daterange('2024-01-18', '2024-01-19'), 0, false, 'EUR', '', 0, 1, 0, 0, 0, 0, 0, 0, 0, 0) $$,
'42501', 'new row violates row-level security policy for table "booking"',
'Users from company 2 should NOT be able to insert new bookings to company 4.'
);
select lives_ok(
$$ update booking set holder_name = 'Nope' where company_id = 4 $$,
'Users from company 2 should not be able to update new campsite types of company 4, but no error if company_id is not changed.'
);
select bag_eq(
'booking_data',
$$ values (2, 'Holder 2')
, (2, 'Another Holder')
$$,
'No row should have been changed.'
);
select throws_ok(
$$ update booking set company_id = 4 where company_id = 2 $$,
'42501', 'new row violates row-level security policy for table "booking"',
'Users from company 2 should NOT be able to move bookings to company 4'
);
reset role;
select set_cookie('6d8215c4888ffac017c3e4b8438e9a1a5559decd719df9c790/admin2@tandem.blog', 'co2');
select lives_ok(
$$ delete from booking where company_id = 2 and holder_name = 'Another Holder' $$,
'Admins from company 2 should be able to delete campsite type from their company.'
);
select bag_eq(
'booking_data',
$$ values (2, 'Holder 2')
$$,
'The row should have been deleted.'
);
select lives_ok(
$$ delete from booking where company_id = 4 $$,
'Admins from company 2 should NOT be able to delete bookins from company 4, but not error is thrown'
);
reset role;
select bag_eq(
'booking_data',
$$ values (2, 'Holder 2')
, (4, 'Holder 4')
$$,
'No row should have been changed'
);
select throws_ok( select throws_ok(
$$ insert into booking (company_id, campsite_type_id, holder_name, stay, number_dogs, acsi_card, currency_code, zone_preferences, subtotal_nights, number_adults, subtotal_adults, number_teenagers, subtotal_teenagers, number_children, subtotal_children, subtotal_dogs, subtotal_tourist_tax, total) values (2, 10, ' ', daterange('2024-01-18', '2024-01-19'), 0, false, 'EUR', '', 0, 1, 0, 0, 0, 0, 0, 0, 0, 0) $$, $$ insert into booking (company_id, campsite_type_id, holder_name, stay, number_dogs, acsi_card, currency_code, zone_preferences, subtotal_nights, number_adults, subtotal_adults, number_teenagers, subtotal_teenagers, number_children, subtotal_children, subtotal_dogs, subtotal_tourist_tax, total) values (2, 10, ' ', daterange('2024-01-18', '2024-01-19'), 0, false, 'EUR', '', 0, 1, 0, 0, 0, 0, 0, 0, 0, 0) $$,
'23514', 'new row for relation "booking" violates check constraint "holder_name_not_empty"', '23514', 'new row for relation "booking" violates check constraint "holder_name_not_empty"',

View File

@ -12,7 +12,7 @@ set search_path to camper, public;
select has_table('booking_option'); select has_table('booking_option');
select has_pk('booking_option'); select has_pk('booking_option');
select col_is_pk('booking_option', array['booking_id', 'campsite_type_option_id']); select col_is_pk('booking_option', array['booking_id', 'campsite_type_option_id']);
select table_privs_are('booking_option', 'guest', array[]::text[]); select table_privs_are('booking_option', 'guest', array['SELECT', 'INSERT']);
select table_privs_are('booking_option', 'employee', array['SELECT', 'INSERT', 'UPDATE', 'DELETE']); select table_privs_are('booking_option', 'employee', array['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('booking_option', 'admin', array['SELECT', 'INSERT', 'UPDATE', 'DELETE']); select table_privs_are('booking_option', 'admin', array['SELECT', 'INSERT', 'UPDATE', 'DELETE']);
select table_privs_are('booking_option', 'authenticator', array[]::text[]); select table_privs_are('booking_option', 'authenticator', array[]::text[]);

27
test/marshal_payment.sql Normal file
View File

@ -0,0 +1,27 @@
-- Test marshal_payment
set client_min_messages to warning;
create extension if not exists pgtap;
reset client_min_messages;
begin;
select plan(9);
set search_path to camper, public;
select has_function('camper', 'marshal_payment', array['integer']);
select function_lang_is('camper', 'marshal_payment', array['integer'], 'sql');
select function_returns('camper', 'marshal_payment', array['integer'], 'jsonb');
select isnt_definer('camper', 'marshal_payment', array['integer']);
select volatility_is('camper', 'marshal_payment', array['integer'], 'volatile');
select function_privs_are('camper', 'marshal_payment', array ['integer'], 'guest', array['EXECUTE']);
select function_privs_are('camper', 'marshal_payment', array ['integer'], 'employee', array['EXECUTE']);
select function_privs_are('camper', 'marshal_payment', array ['integer'], 'admin', array['EXECUTE']);
select function_privs_are('camper', 'marshal_payment', array ['integer'], 'authenticator', array[]::text[]);
-- The functions output is tested in unmarshal_bookings test suite
select *
from finish();
rollback;

101
test/unmarshal_booking.sql Normal file
View File

@ -0,0 +1,101 @@
-- Test unmarshal_booking
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', 'unmarshal_booking', array['jsonb']);
select function_lang_is('camper', 'unmarshal_booking', array['jsonb'], 'plpgsql');
select function_returns('camper', 'unmarshal_booking', array['jsonb'], 'integer');
select isnt_definer('camper', 'unmarshal_booking', array['jsonb']);
select volatility_is('camper', 'unmarshal_booking', array['jsonb'], 'volatile');
select function_privs_are('camper', 'unmarshal_booking', array['jsonb'], 'guest', array['EXECUTE']);
select function_privs_are('camper', 'unmarshal_booking', array['jsonb'], 'employee', array['EXECUTE']);
select function_privs_are('camper', 'unmarshal_booking', array['jsonb'], 'admin', array['EXECUTE']);
select function_privs_are('camper', 'unmarshal_booking', array['jsonb'], 'authenticator', array[]::text[]);
set client_min_messages to warning;
truncate booking_option cascade;
truncate booking cascade;
truncate payment_customer 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, company_id, name, media_id, max_campers, bookable_nights, overflow_allowed)
values (12, 2, 'Plots', 10, 6, '[1, 7]', true)
, (14, 2, 'Bungalows', 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)
, (18, 12, 'Small 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, acsi_card, payment_status, created_at, updated_at)
values (22, 2, 12, '2024-08-29', '2024-09-03', 71000, 2, 200, 3, 400, 4, 600, 5, 800, 1000, 1200, 'EUR', 'a b c', false, 'completed', '2024-01-01 01:01:01', '2024-02-02 02:02:02')
, (24, 2, 14, '2024-08-30', '2024-09-02', 61000, 1, 100, 2, 200, 3, 400, 4, 600, 800, 600, 'USD', 'c b a', true, 'preauth', '2024-02-02 02:02:02', '2024-03-03 03:03:03')
;
insert into payment_customer (payment_id, full_name, address, postal_code, city, country_code, email, phone, lang_tag)
values (22, 'First Name', 'Fake St., 123', '17500', 'None', 'ES', 'one@example.cat', '+34 977 977 977', 'ca')
, (24, 'Second Guy', 'Bullshit Av., 1', 'ABC123', 'Some', 'FR', 'two@example.fr', '+33 123 123 123', 'fr')
;
insert into payment_option (payment_id, campsite_type_option_id, units, subtotal)
values (22, 16, 1, 12)
, (22, 18, 2, 24)
;
select lives_ok(
$$ select unmarshal_booking(marshal_payment(22)) $$,
'Can unmarshal the first payment marshalled'
);
select lives_ok(
$$ select unmarshal_booking(marshal_payment(24)) $$,
'Can unmarshal the second payment marshalled'
);
select bag_eq(
$$ select company_id, campsite_type_id, stay, holder_name, address, postal_code, city, country_code::text, email::text, phone::text, lang_tag, zone_preferences, subtotal_nights::integer, number_adults::integer, subtotal_adults::integer, number_teenagers::integer, subtotal_teenagers::integer, number_children::integer, subtotal_children::integer, number_dogs::integer, subtotal_dogs::integer, subtotal_tourist_tax::integer, total::integer, acsi_card, currency_code::text, booking_status from booking $$,
$$ values (2, 12, daterange('2024-08-29', '2024-09-03'), 'First Name', 'Fake St., 123', '17500', 'None', 'ES', 'one@example.cat', '+34 977 97 79 77', 'ca', 'a b c', 71000, 2, 200, 3, 400, 4, 600, 5, 800, 1000, 1200, false, 'EUR', 'created')
, (2, 14, daterange('2024-08-30', '2024-09-02'), 'Second Guy', 'Bullshit Av., 1', 'ABC123', 'Some', 'FR', 'two@example.fr', '+33 1 23 12 31 23', 'fr', 'c b a', 61000, 1, 100, 2, 200, 3, 400, 4, 600, 800, 600, true, 'USD', 'created')
$$,
'Should have created the new bookings'
);
select bag_eq (
$$ select campsite_type_id, campsite_type_option_id, units, subtotal from booking_option join booking using (booking_id) $$,
$$ values (12, 16, 1, 12)
, (12, 18, 2, 24)
$$ ,
'Should have added the booking options too'
);
select *
from finish();
rollback;

View File

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

View File

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