|
| 1 | +-- Create the denormalized table |
| 2 | +CREATE TABLE "BookingTimeStatusDenormalized" ( |
| 3 | + id INTEGER, |
| 4 | + uid TEXT, |
| 5 | + "eventTypeId" INTEGER, |
| 6 | + title TEXT, |
| 7 | + description TEXT, |
| 8 | + "startTime" TIMESTAMP(3), |
| 9 | + "endTime" TIMESTAMP(3), |
| 10 | + "createdAt" TIMESTAMP(3), |
| 11 | + location TEXT, |
| 12 | + paid BOOLEAN, |
| 13 | + status TEXT, |
| 14 | + rescheduled BOOLEAN, |
| 15 | + "userId" INTEGER, |
| 16 | + "teamId" INTEGER, |
| 17 | + "eventLength" INTEGER, |
| 18 | + "timeStatus" TEXT, |
| 19 | + "eventParentId" INTEGER, |
| 20 | + "userEmail" TEXT, |
| 21 | + "username" TEXT, |
| 22 | + "ratingFeedback" TEXT, |
| 23 | + "rating" INTEGER, |
| 24 | + "noShowHost" BOOLEAN, |
| 25 | + "isTeamBooking" BOOLEAN |
| 26 | +); |
| 27 | + |
| 28 | +-- Create indexes to match likely query patterns |
| 29 | +CREATE INDEX ON "BookingTimeStatusDenormalized" (id); |
| 30 | +CREATE INDEX ON "BookingTimeStatusDenormalized" ("userId"); |
| 31 | +CREATE INDEX ON "BookingTimeStatusDenormalized" ("createdAt"); |
| 32 | +CREATE INDEX "idx_event_type_hierarchy" ON "BookingTimeStatusDenormalized" ("eventTypeId", "eventParentId"); |
| 33 | + |
| 34 | +-- Function to calculate timeStatus |
| 35 | +CREATE OR REPLACE FUNCTION calculate_time_status( |
| 36 | + rescheduled BOOLEAN, |
| 37 | + status TEXT, |
| 38 | + end_time TIMESTAMP |
| 39 | +) RETURNS TEXT AS $$ |
| 40 | +BEGIN |
| 41 | + RETURN CASE |
| 42 | + WHEN rescheduled IS TRUE THEN 'rescheduled' |
| 43 | + WHEN status = 'cancelled' AND rescheduled IS NULL THEN 'cancelled' |
| 44 | + WHEN end_time < now() THEN 'completed' |
| 45 | + WHEN end_time > now() THEN 'uncompleted' |
| 46 | + ELSE NULL |
| 47 | + END; |
| 48 | +END; |
| 49 | +$$ LANGUAGE plpgsql; |
| 50 | + |
| 51 | +-- Function to calculate isTeamBooking |
| 52 | +CREATE OR REPLACE FUNCTION calculate_is_team_booking(team_id INTEGER) |
| 53 | +RETURNS BOOLEAN AS $$ |
| 54 | +BEGIN |
| 55 | + RETURN CASE WHEN team_id IS NULL THEN false ELSE true END; |
| 56 | +END; |
| 57 | +$$ LANGUAGE plpgsql; |
| 58 | + |
| 59 | +-- Function to refresh a single booking's data |
| 60 | +CREATE OR REPLACE FUNCTION refresh_booking_time_status_denormalized(booking_id INTEGER) |
| 61 | +RETURNS VOID AS $$ |
| 62 | +BEGIN |
| 63 | + -- Delete existing entry if any |
| 64 | + DELETE FROM "BookingTimeStatusDenormalized" WHERE id = booking_id; |
| 65 | + |
| 66 | + -- Insert non-team booking |
| 67 | + INSERT INTO "BookingTimeStatusDenormalized" |
| 68 | + SELECT |
| 69 | + "Booking".id, |
| 70 | + "Booking".uid, |
| 71 | + "Booking"."eventTypeId", |
| 72 | + "Booking".title, |
| 73 | + "Booking".description, |
| 74 | + "Booking"."startTime", |
| 75 | + "Booking"."endTime", |
| 76 | + "Booking"."createdAt", |
| 77 | + "Booking".location, |
| 78 | + "Booking".paid, |
| 79 | + "Booking".status, |
| 80 | + "Booking".rescheduled, |
| 81 | + "Booking"."userId", |
| 82 | + et."teamId", |
| 83 | + et.length AS "eventLength", |
| 84 | + calculate_time_status("Booking".rescheduled, "Booking".status::text, "Booking"."endTime") AS "timeStatus", |
| 85 | + et."parentId" AS "eventParentId", |
| 86 | + "u"."email" AS "userEmail", |
| 87 | + "u"."username" AS "username", |
| 88 | + "Booking"."ratingFeedback", |
| 89 | + "Booking"."rating", |
| 90 | + "Booking"."noShowHost", |
| 91 | + calculate_is_team_booking(et."teamId") as "isTeamBooking" |
| 92 | + FROM "Booking" |
| 93 | + LEFT JOIN "EventType" et ON "Booking"."eventTypeId" = et.id |
| 94 | + LEFT JOIN users u ON u.id = "Booking"."userId" |
| 95 | + WHERE "Booking".id = booking_id; |
| 96 | +END; |
| 97 | +$$ LANGUAGE plpgsql; |
| 98 | + |
| 99 | +-- Trigger function for booking changes (insert/update) |
| 100 | +CREATE OR REPLACE FUNCTION trigger_refresh_booking_time_status_denormalized() |
| 101 | +RETURNS TRIGGER AS $$ |
| 102 | +BEGIN |
| 103 | + PERFORM refresh_booking_time_status_denormalized(NEW.id); |
| 104 | + RETURN NEW; |
| 105 | +END; |
| 106 | +$$ LANGUAGE plpgsql; |
| 107 | + |
| 108 | +-- Trigger function for booking deletions |
| 109 | +CREATE OR REPLACE FUNCTION trigger_delete_booking_time_status_denormalized() |
| 110 | +RETURNS TRIGGER AS $$ |
| 111 | +BEGIN |
| 112 | + DELETE FROM "BookingTimeStatusDenormalized" WHERE id = OLD.id; |
| 113 | + RETURN OLD; |
| 114 | +END; |
| 115 | +$$ LANGUAGE plpgsql; |
| 116 | + |
| 117 | +-- Create triggers for Booking table |
| 118 | +CREATE TRIGGER booking_insert_update_trigger |
| 119 | + AFTER INSERT OR UPDATE ON "Booking" |
| 120 | + FOR EACH ROW |
| 121 | + EXECUTE FUNCTION trigger_refresh_booking_time_status_denormalized(); |
| 122 | + |
| 123 | +CREATE TRIGGER booking_delete_trigger |
| 124 | + AFTER DELETE ON "Booking" |
| 125 | + FOR EACH ROW |
| 126 | + EXECUTE FUNCTION trigger_delete_booking_time_status_denormalized(); |
| 127 | + |
| 128 | +-- Trigger function for EventType changes |
| 129 | +CREATE OR REPLACE FUNCTION trigger_refresh_booking_time_status_denormalized_event_type() |
| 130 | +RETURNS TRIGGER AS $$ |
| 131 | +BEGIN |
| 132 | + -- Refresh all bookings associated with this event type |
| 133 | + UPDATE "BookingTimeStatusDenormalized" btsd |
| 134 | + SET |
| 135 | + "teamId" = NEW."teamId", |
| 136 | + "eventLength" = NEW.length, |
| 137 | + "eventParentId" = NEW."parentId", |
| 138 | + "isTeamBooking" = calculate_is_team_booking(NEW."teamId") |
| 139 | + WHERE btsd."eventTypeId" = NEW.id; |
| 140 | + RETURN NEW; |
| 141 | +END; |
| 142 | +$$ LANGUAGE plpgsql; |
| 143 | + |
| 144 | +-- Trigger function for user changes |
| 145 | +CREATE OR REPLACE FUNCTION trigger_refresh_booking_time_status_denormalized_user() |
| 146 | +RETURNS TRIGGER AS $$ |
| 147 | +BEGIN |
| 148 | + -- Refresh all bookings associated with this user |
| 149 | + UPDATE "BookingTimeStatusDenormalized" btsd |
| 150 | + SET |
| 151 | + "userEmail" = NEW.email, |
| 152 | + "username" = NEW.username |
| 153 | + WHERE btsd."userId" = NEW.id; |
| 154 | + RETURN NEW; |
| 155 | +END; |
| 156 | +$$ LANGUAGE plpgsql; |
| 157 | + |
| 158 | +-- Create triggers for EventType table |
| 159 | +CREATE TRIGGER event_type_update_trigger |
| 160 | + AFTER UPDATE OF "teamId", length, "parentId" ON "EventType" |
| 161 | + FOR EACH ROW |
| 162 | + EXECUTE FUNCTION trigger_refresh_booking_time_status_denormalized_event_type(); |
| 163 | + |
| 164 | +-- Create triggers for users table |
| 165 | +CREATE TRIGGER user_update_trigger |
| 166 | + AFTER UPDATE OF email, username ON users |
| 167 | + FOR EACH ROW |
| 168 | + EXECUTE FUNCTION trigger_refresh_booking_time_status_denormalized_user(); |
| 169 | + |
| 170 | + |
| 171 | +-- Populate the table with initial data |
| 172 | +-- DELETE FROM "BookingTimeStatusDenormalized"; |
| 173 | +-- INSERT INTO "BookingTimeStatusDenormalized" |
| 174 | +-- SELECT * FROM "BookingTimeStatus"; |
0 commit comments