Skip to content

Commit

Permalink
refactor views to avoid problems in case of rolling deployment
Browse files Browse the repository at this point in the history
  • Loading branch information
Celestino Bellone committed Feb 7, 2024
1 parent ecd23b0 commit afc488b
Show file tree
Hide file tree
Showing 17 changed files with 70 additions and 99 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -15,20 +15,4 @@
-- along with alf.io. If not, see <http://www.gnu.org/licenses/>.
--

drop view if exists admin_reservation_request_stats;
drop view if exists auditing_user;
drop view if exists events_statistics;
drop view if exists ticket_category_statistics;
drop view if exists ticket_and_reservation_and_tx;
drop view if exists latest_ticket_update;
drop view if exists reservation_and_ticket_and_tx;
drop view if exists ticket_category_with_currency;
drop view if exists additional_service_with_currency;
drop view if exists checkin_ticket_event_and_category_info;
drop view if exists subscription_descriptor_statistics;
drop view if exists basic_event_with_optional_subscription;
drop view if exists reservation_and_subscription_and_tx;
drop view if exists extension_capabilities;
drop view if exists reservation_with_purchase_context;
drop view if exists available_subscriptions_by_event;
drop view if exists promocode_usage_details;
drop view if exists ticket_and_reservation_and_tx;
Original file line number Diff line number Diff line change
Expand Up @@ -15,7 +15,7 @@
-- along with alf.io. If not, see <http://www.gnu.org/licenses/>.
--

create view admin_reservation_request_stats as (
create or replace view admin_reservation_request_stats as (
select request_id,
user_id,
event_id,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -15,7 +15,7 @@
-- along with alf.io. If not, see <http://www.gnu.org/licenses/>.
--

CREATE VIEW auditing_user AS
CREATE or replace VIEW auditing_user AS
SELECT auditing.reservation_id,
auditing.user_id,
auditing.event_type,
Expand Down

This file was deleted.

Original file line number Diff line number Diff line change
Expand Up @@ -15,6 +15,61 @@
-- along with alf.io. If not, see <http://www.gnu.org/licenses/>.
--

drop view if exists events_statistics;
drop view if exists ticket_category_statistics;

create view ticket_category_statistics as (select
res.*,
is_expired and not_sold_tickets > 0 as is_containing_orphan_tickets,
stuck_count > 0 as is_containing_stuck_tickets
from

(select
id as ticket_category_id,
access_restricted,
max_tickets,
bounded,
is_expired,
event_id,
coalesce(pending_count,0) as pending_count,
coalesce(checked_in_count,0) as checked_in_count,
coalesce(sold_tickets_count,0) as sold_tickets_count,
coalesce(released_count, 0) as released_count,
case(bounded) when false then 0 else max_tickets - coalesce(sold_tickets_count,0 ) - coalesce(checked_in_count, 0) - coalesce(pending_count, 0) end as not_sold_tickets,
coalesce(stuck_count, 0) as stuck_count,
category_configuration
from

(select max_tickets, bounded, id, event_id, expiration < now() as is_expired, access_restricted from ticket_category where tc_status = 'ACTIVE' ) ticket_cat

left join

(select
sum(case(status = 'PENDING') when true then 1 else 0 end) as pending_count,
sum(case(status = 'RELEASED') when true then 1 else 0 end) as released_count,
sum(case(status = 'CHECKED_IN') when true then 1 else 0 end) checked_in_count,
sum(case(status in ('TO_BE_PAID', 'ACQUIRED')) when true then 1 else 0 end) as sold_tickets_count,
category_id
from ticket
inner join ticket_category tc
on category_id = tc.id
group by category_id
) tickets_stats on ticket_cat.id = tickets_stats.category_id

left join

(select count(*) stuck_count, category_id
from ticket
inner join tickets_reservation on tickets_reservation.id = tickets_reservation_id
where tickets_reservation.status = 'STUCK'
group by category_id) stuck_count on ticket_cat.id = stuck_count.category_id

left join
(select ticket_category_id_fk, jsonb_agg(json_build_object('id', id, 'key', c_key, 'value', c_value, 'configurationPathLevel', 'TICKET_CATEGORY')) category_configuration
from configuration_ticket_category group by 1) tc_settings on ticket_cat.id = tc_settings.ticket_category_id_fk

) as res);

create view events_statistics as (
select
event.id,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -15,6 +15,6 @@
-- along with alf.io. If not, see <http://www.gnu.org/licenses/>.
--

CREATE VIEW latest_ticket_update as
CREATE or replace VIEW latest_ticket_update as
select cast(entity_id as int) ticket_id, event_id, max(event_time) last_update from auditing
where entity_type = 'TICKET' group by ticket_id, event_id;
Original file line number Diff line number Diff line change
Expand Up @@ -15,7 +15,7 @@
-- along with alf.io. If not, see <http://www.gnu.org/licenses/>.
--

create view reservation_and_ticket_and_tx as (select
create or replace view reservation_and_ticket_and_tx as (select

tickets_reservation.id tr_id,
tickets_reservation.validity tr_validity,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -15,7 +15,7 @@
-- along with alf.io. If not, see <http://www.gnu.org/licenses/>.
--

create view ticket_category_with_currency as (
create or replace view ticket_category_with_currency as (
select tc.id id,
tc.inception inception,
tc.expiration expiration,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -15,7 +15,7 @@
-- along with alf.io. If not, see <http://www.gnu.org/licenses/>.
--

create view additional_service_with_currency as (
create or replace view additional_service_with_currency as (
select asv.id id,
asv.event_id_fk event_id_fk,
asv.price_cts price_cts,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -33,7 +33,7 @@ select
end;
$$ language sql;

create view checkin_ticket_event_and_category_info as
create or replace view checkin_ticket_event_and_category_info as
(
select
-- ticket
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -15,7 +15,7 @@
-- along with alf.io. If not, see <http://www.gnu.org/licenses/>.
--

create view reservation_and_subscription_and_tx as (select
create or replace view reservation_and_subscription_and_tx as (select

tickets_reservation.id tr_id,
tickets_reservation.validity tr_validity,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -15,7 +15,7 @@
-- along with alf.io. If not, see <http://www.gnu.org/licenses/>.
--

create view basic_event_with_optional_subscription as (
create or replace view basic_event_with_optional_subscription as (
select e.*,
s.id as subscription_id,
o.slug as org_slug
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -15,7 +15,7 @@
-- along with alf.io. If not, see <http://www.gnu.org/licenses/>.
--

create view subscription_descriptor_statistics as (
create or replace view subscription_descriptor_statistics as (
select
sd.id sd_id,
sd.title sd_title,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -15,7 +15,7 @@
-- along with alf.io. If not, see <http://www.gnu.org/licenses/>.
--

create view extension_capabilities as (
create or replace view extension_capabilities as (
select es.es_id,
es.path,
es.name,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -15,7 +15,7 @@
-- along with alf.io. If not, see <http://www.gnu.org/licenses/>.
--

create view reservation_with_purchase_context as (
create or replace view reservation_with_purchase_context as (

with reservations as (
select
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -15,7 +15,7 @@
-- along with alf.io. If not, see <http://www.gnu.org/licenses/>.
--

create view available_subscriptions_by_event as (
create or replace view available_subscriptions_by_event as (
with usage_by_subscription_id as (
select s.id subscription_id,
sum(case when t.subscription_id_fk is not null then 1 else 0 end) usage
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -15,7 +15,7 @@
-- along with alf.io. If not, see <http://www.gnu.org/licenses/>.
--

create view promocode_usage_details as (
create or replace view promocode_usage_details as (
with tickets as (
select t.tickets_reservation_id, json_agg(jsonb_build_object(
'id', t.uuid,
Expand Down

0 comments on commit afc488b

Please sign in to comment.