| | 1 | = Advanced Database Development |
| | 2 | == Data constrains requirements: Listing-Animal ownership consistency + single active listing |
| | 3 | === Data requirements description |
| | 4 | Petify listings must stay consistent with the animal they refer to: |
| | 5 | * listings.owner_id must always match animals.owner_id for the same animal_id. |
| | 6 | * An animal can have at most one ACTIVE listing at a time. |
| | 7 | * Listing status changes must follow a valid transition model. |
| | 8 | === Implementation |
| | 9 | {{{Triggers}}} |
| | 10 | {{{ |
| | 11 | -- status transition |
| | 12 | CREATE OR REPLACE FUNCTION petify_is_valid_listing_transition(p_old text, p_new text) |
| | 13 | RETURNS boolean |
| | 14 | LANGUAGE sql |
| | 15 | AS $$ |
| | 16 | SELECT CASE |
| | 17 | WHEN p_old = p_new THEN true |
| | 18 | WHEN p_old = 'DRAFT' AND p_new IN ('ACTIVE','ARCHIVED') THEN true |
| | 19 | WHEN p_old = 'ACTIVE' AND p_new IN ('SOLD','ARCHIVED') THEN true |
| | 20 | WHEN p_old = 'SOLD' AND p_new IN ('ARCHIVED') THEN true |
| | 21 | WHEN p_old = 'ARCHIVED' THEN false |
| | 22 | ELSE false |
| | 23 | END; |
| | 24 | $$; |
| | 25 | |
| | 26 | -- same owner |
| | 27 | CREATE OR REPLACE FUNCTION petify_trg_listings_enforce() |
| | 28 | RETURNS trigger |
| | 29 | LANGUAGE plpgsql |
| | 30 | AS $$ |
| | 31 | DECLARE |
| | 32 | v_animal_owner bigint; |
| | 33 | BEGIN |
| | 34 | SELECT owner_id INTO v_animal_owner |
| | 35 | FROM animals |
| | 36 | WHERE animal_id = NEW.animal_id; |
| | 37 | |
| | 38 | IF v_animal_owner IS NULL THEN |
| | 39 | RAISE EXCEPTION 'Animal % not found', NEW.animal_id; |
| | 40 | END IF; |
| | 41 | |
| | 42 | IF NEW.owner_id <> v_animal_owner THEN |
| | 43 | RAISE EXCEPTION 'Listing owner_id (%) must match animal.owner_id (%) for animal %', |
| | 44 | NEW.owner_id, v_animal_owner, NEW.animal_id; |
| | 45 | END IF; |
| | 46 | |
| | 47 | IF TG_OP = 'UPDATE' THEN |
| | 48 | IF NOT petify_is_valid_listing_transition(OLD.status, NEW.status) THEN |
| | 49 | RAISE EXCEPTION 'Invalid listing status transition: % -> %', OLD.status, NEW.status; |
| | 50 | END IF; |
| | 51 | END IF; |
| | 52 | |
| | 53 | IF NEW.status = 'ACTIVE' THEN |
| | 54 | IF EXISTS ( |
| | 55 | SELECT 1 |
| | 56 | FROM listings l |
| | 57 | WHERE l.animal_id = NEW.animal_id |
| | 58 | AND l.status = 'ACTIVE' |
| | 59 | AND (TG_OP <> 'UPDATE' OR l.listing_id <> NEW.listing_id) |
| | 60 | ) THEN |
| | 61 | RAISE EXCEPTION 'Animal % already has an ACTIVE listing', NEW.animal_id; |
| | 62 | END IF; |
| | 63 | END IF; |
| | 64 | |
| | 65 | RETURN NEW; |
| | 66 | END; |
| | 67 | $$; |
| | 68 | |
| | 69 | DROP TRIGGER IF EXISTS trg_listings_enforce ON listings; |
| | 70 | CREATE TRIGGER trg_listings_enforce |
| | 71 | BEFORE INSERT OR UPDATE |
| | 72 | ON listings |
| | 73 | FOR EACH ROW |
| | 74 | EXECUTE FUNCTION petify_trg_listings_enforce(); |
| | 75 | |
| | 76 | }}} |
| | 77 | {{{Stored procedures}}} |
| | 78 | {{{ |
| | 79 | CREATE OR REPLACE VIEW v_listings_enriched AS |
| | 80 | SELECT |
| | 81 | l.listing_id, |
| | 82 | l.status, |
| | 83 | l.price, |
| | 84 | l.created_at, |
| | 85 | l.owner_id AS listing_owner_id, |
| | 86 | a.animal_id, |
| | 87 | a.name AS animal_name, |
| | 88 | a.species, |
| | 89 | a.breed, |
| | 90 | a.located_name, |
| | 91 | a.owner_id AS animal_owner_id, |
| | 92 | (l.owner_id = a.owner_id) AS owner_match |
| | 93 | FROM listings l |
| | 94 | JOIN animals a ON a.animal_id = l.animal_id; |
| | 95 | }}} |
| | 96 | == Data constraints requirements: Appointment owner consistency, no overlap scheduling |
| | 97 | === Data requirements description |
| | 98 | Appointments must obey real scheduling constraints: |
| | 99 | * The responsible_owner_id for an appointment must match the owner of the animal. |
| | 100 | * The same owner cannot have overlapping appointments. |
| | 101 | * The same animal cannot have overlapping appointments. |
| | 102 | * Confirming appointments in the past is blocked. |
| | 103 | === Implementation |
| | 104 | {{{Triggers}}} |
| | 105 | {{{ |
| | 106 | CREATE OR REPLACE FUNCTION petify_trg_appointments_enforce() |
| | 107 | RETURNS trigger |
| | 108 | LANGUAGE plpgsql |
| | 109 | AS $$ |
| | 110 | DECLARE |
| | 111 | v_animal_owner bigint; |
| | 112 | BEGIN |
| | 113 | SELECT owner_id INTO v_animal_owner |
| | 114 | FROM animals |
| | 115 | WHERE animal_id = NEW.animal_id; |
| | 116 | |
| | 117 | IF v_animal_owner IS NULL THEN |
| | 118 | RAISE EXCEPTION 'Animal % not found for appointment', NEW.animal_id; |
| | 119 | END IF; |
| | 120 | |
| | 121 | IF NEW.responsible_owner_id <> v_animal_owner THEN |
| | 122 | RAISE EXCEPTION |
| | 123 | 'Appointment responsible_owner_id (%) must match animals.owner_id (%) for animal %', |
| | 124 | NEW.responsible_owner_id, v_animal_owner, NEW.animal_id; |
| | 125 | END IF; |
| | 126 | |
| | 127 | IF NEW.status = 'CONFIRMED' AND NEW.date_time < now() THEN |
| | 128 | RAISE EXCEPTION 'Cannot CONFIRM an appointment in the past (date_time=%)', NEW.date_time; |
| | 129 | END IF; |
| | 130 | |
| | 131 | IF NEW.status = 'DONE' AND NEW.date_time > now() THEN |
| | 132 | RAISE EXCEPTION 'Cannot mark DONE for an appointment that is in the future (date_time=%)', NEW.date_time; |
| | 133 | END IF; |
| | 134 | |
| | 135 | RETURN NEW; |
| | 136 | END; |
| | 137 | $$; |
| | 138 | |
| | 139 | DROP TRIGGER IF EXISTS trg_appointments_enforce ON appointments; |
| | 140 | CREATE TRIGGER trg_appointments_enforce |
| | 141 | BEFORE INSERT OR UPDATE |
| | 142 | ON appointments |
| | 143 | FOR EACH ROW |
| | 144 | EXECUTE FUNCTION petify_trg_appointments_enforce(); |
| | 145 | }}} |
| | 146 | {{{Stored procedures}}} |
| | 147 | {{{ |
| | 148 | -- 30min timeslots |
| | 149 | CREATE EXTENSION IF NOT EXISTS btree_gist; |
| | 150 | |
| | 151 | DO $$ |
| | 152 | BEGIN |
| | 153 | IF NOT EXISTS ( |
| | 154 | SELECT 1 |
| | 155 | FROM information_schema.columns |
| | 156 | WHERE table_name='appointments' AND column_name='slot' |
| | 157 | ) THEN |
| | 158 | ALTER TABLE appointments |
| | 159 | ADD COLUMN slot tstzrange |
| | 160 | GENERATED ALWAYS AS (tstzrange(date_time, date_time + interval '30 minutes', '[)')) STORED; |
| | 161 | END IF; |
| | 162 | END $$; |
| | 163 | |
| | 164 | DO $$ |
| | 165 | BEGIN |
| | 166 | IF NOT EXISTS (SELECT 1 FROM pg_constraint WHERE conname = 'appointments_no_overlap_per_owner') THEN |
| | 167 | ALTER TABLE appointments |
| | 168 | ADD CONSTRAINT appointments_no_overlap_per_owner |
| | 169 | EXCLUDE USING gist (responsible_owner_id WITH =, slot WITH &&) |
| | 170 | WHERE (status IN ('CONFIRMED','DONE')); |
| | 171 | END IF; |
| | 172 | END $$; |
| | 173 | |
| | 174 | DO $$ |
| | 175 | BEGIN |
| | 176 | IF NOT EXISTS (SELECT 1 FROM pg_constraint WHERE conname = 'appointments_no_overlap_per_animal') THEN |
| | 177 | ALTER TABLE appointments |
| | 178 | ADD CONSTRAINT appointments_no_overlap_per_animal |
| | 179 | EXCLUDE USING gist (animal_id WITH =, slot WITH &&) |
| | 180 | WHERE (status IN ('CONFIRMED','DONE')); |
| | 181 | END IF; |
| | 182 | END $$; |
| | 183 | |
| | 184 | }}} |
| | 185 | {{{Views}}} |
| | 186 | {{{ |
| | 187 | CREATE OR REPLACE VIEW v_clinic_appointments_monthly AS |
| | 188 | SELECT |
| | 189 | clinic_id, |
| | 190 | date_trunc('month', date_time) AS month, |
| | 191 | COUNT(*) FILTER (WHERE status='CONFIRMED') AS confirmed_cnt, |
| | 192 | COUNT(*) FILTER (WHERE status='DONE') AS done_cnt, |
| | 193 | COUNT(*) FILTER (WHERE status='NO_SHOW') AS no_show_cnt, |
| | 194 | COUNT(*) FILTER (WHERE status='CANCELLED') AS cancelled_cnt, |
| | 195 | COUNT(*) AS total_cnt |
| | 196 | FROM appointments |
| | 197 | GROUP BY clinic_id, date_trunc('month', date_time) |
| | 198 | ORDER BY month DESC; |
| | 199 | |
| | 200 | }}} |
| | 201 | == Data constraints requirements: Health Record integrity |
| | 202 | === Data requirements description |
| | 203 | Health records must be consistent: |
| | 204 | * A health record must be tied to an appointment that is DONE. |
| | 205 | * The animal in health_records must match the animal of the referenced appointment. |
| | 206 | * The record date must match the appointment date. |
| | 207 | === Implementation |
| | 208 | {{{Triggers}}} |
| | 209 | {{{ |
| | 210 | CREATE OR REPLACE FUNCTION petify_trg_health_records_enforce() |
| | 211 | RETURNS trigger |
| | 212 | LANGUAGE plpgsql |
| | 213 | AS $$ |
| | 214 | DECLARE |
| | 215 | v_appt_animal bigint; |
| | 216 | v_appt_status text; |
| | 217 | v_appt_date date; |
| | 218 | BEGIN |
| | 219 | SELECT a.animal_id, a.status, a.date_time::date |
| | 220 | INTO v_appt_animal, v_appt_status, v_appt_date |
| | 221 | FROM appointments a |
| | 222 | WHERE a.appointment_id = NEW.appointment_id; |
| | 223 | |
| | 224 | IF v_appt_animal IS NULL THEN |
| | 225 | RAISE EXCEPTION 'Appointment % not found for health record', NEW.appointment_id; |
| | 226 | END IF; |
| | 227 | |
| | 228 | IF NEW.animal_id <> v_appt_animal THEN |
| | 229 | RAISE EXCEPTION 'Health record animal_id (%) must match appointment animal_id (%) for appointment %', |
| | 230 | NEW.animal_id, v_appt_animal, NEW.appointment_id; |
| | 231 | END IF; |
| | 232 | |
| | 233 | IF v_appt_status <> 'DONE' THEN |
| | 234 | RAISE EXCEPTION 'Cannot insert health record unless appointment % is DONE (current status=%)', |
| | 235 | NEW.appointment_id, v_appt_status; |
| | 236 | END IF; |
| | 237 | |
| | 238 | IF NEW.date <> v_appt_date THEN |
| | 239 | RAISE EXCEPTION 'Health record date (%) must equal appointment date (%) for appointment %', |
| | 240 | NEW.date, v_appt_date, NEW.appointment_id; |
| | 241 | END IF; |
| | 242 | |
| | 243 | RETURN NEW; |
| | 244 | END; |
| | 245 | $$; |
| | 246 | |
| | 247 | DROP TRIGGER IF EXISTS trg_health_records_enforce ON health_records; |
| | 248 | CREATE TRIGGER trg_health_records_enforce |
| | 249 | BEFORE INSERT OR UPDATE |
| | 250 | ON health_records |
| | 251 | FOR EACH ROW |
| | 252 | EXECUTE FUNCTION petify_trg_health_records_enforce(); |
| | 253 | }}} |
| | 254 | {{{Views}}} |
| | 255 | {{{ |
| | 256 | CREATE OR REPLACE VIEW v_health_records_with_context AS |
| | 257 | SELECT |
| | 258 | hr.healthrecord_id, |
| | 259 | hr.animal_id, |
| | 260 | a.name AS animal_name, |
| | 261 | hr.appointment_id, |
| | 262 | ap.clinic_id, |
| | 263 | ap.date_time, |
| | 264 | ap.status AS appointment_status, |
| | 265 | hr.type, |
| | 266 | hr.description, |
| | 267 | hr.date |
| | 268 | FROM health_records hr |
| | 269 | JOIN animals a ON a.animal_id = hr.animal_id |
| | 270 | JOIN appointments ap ON ap.appointment_id = hr.appointment_id; |
| | 271 | }}} |
| | 272 | == Data constraints requirements: Review Consistency |
| | 273 | === Data requirements description |
| | 274 | Reviews are split across multiple tables and require consistency checks: |
| | 275 | * A base reviews row can represent either a user_review or a clinic_review, never both. |
| | 276 | * A reviewer cannot repeatedly review the same target too frequently (30-day cooldown). |
| | 277 | * Prevent self-review. |
| | 278 | === Implementation |
| | 279 | {{{Triggers}}} |
| | 280 | {{{ |
| | 281 | CREATE OR REPLACE FUNCTION petify_trg_reviews_no_update() |
| | 282 | RETURNS trigger |
| | 283 | LANGUAGE plpgsql |
| | 284 | AS $$ |
| | 285 | BEGIN |
| | 286 | RAISE EXCEPTION 'Reviews are immutable. Updates are not allowed (review_id=%).', OLD.review_id; |
| | 287 | END; |
| | 288 | $$; |
| | 289 | |
| | 290 | DROP TRIGGER IF EXISTS trg_reviews_no_update ON reviews; |
| | 291 | CREATE TRIGGER trg_reviews_no_update |
| | 292 | BEFORE UPDATE |
| | 293 | ON reviews |
| | 294 | FOR EACH ROW |
| | 295 | EXECUTE FUNCTION petify_trg_reviews_no_update(); |
| | 296 | |
| | 297 | RETURNS trigger |
| | 298 | LANGUAGE plpgsql |
| | 299 | AS $$ |
| | 300 | BEGIN |
| | 301 | RAISE EXCEPTION 'Reviews cannot be deleted directly. Use the soft-delete procedure.'; |
| | 302 | END; |
| | 303 | $$; |
| | 304 | |
| | 305 | DROP TRIGGER IF EXISTS trg_reviews_no_delete ON reviews; |
| | 306 | CREATE TRIGGER trg_reviews_no_delete |
| | 307 | BEFORE DELETE |
| | 308 | ON reviews |
| | 309 | FOR EACH ROW |
| | 310 | EXECUTE FUNCTION petify_trg_reviews_no_delete(); |
| | 311 | |
| | 312 | CREATE OR REPLACE FUNCTION petify_trg_no_update_generic() |
| | 313 | RETURNS trigger |
| | 314 | LANGUAGE plpgsql |
| | 315 | AS $$ |
| | 316 | BEGIN |
| | 317 | RAISE EXCEPTION 'Updates are not allowed on this table.'; |
| | 318 | END; |
| | 319 | $$; |
| | 320 | |
| | 321 | DROP TRIGGER IF EXISTS trg_user_reviews_no_update ON user_reviews; |
| | 322 | CREATE TRIGGER trg_user_reviews_no_update |
| | 323 | BEFORE UPDATE |
| | 324 | ON user_reviews |
| | 325 | FOR EACH ROW |
| | 326 | EXECUTE FUNCTION petify_trg_no_update_generic(); |
| | 327 | |
| | 328 | DROP TRIGGER IF EXISTS trg_clinic_reviews_no_update ON clinic_reviews; |
| | 329 | CREATE TRIGGER trg_clinic_reviews_no_update |
| | 330 | BEFORE UPDATE |
| | 331 | ON clinic_reviews |
| | 332 | FOR EACH ROW |
| | 333 | EXECUTE FUNCTION petify_trg_no_update_generic(); |
| | 334 | |
| | 335 | CREATE OR REPLACE FUNCTION petify_trg_user_review_exclusive() |
| | 336 | RETURNS trigger |
| | 337 | LANGUAGE plpgsql |
| | 338 | AS $$ |
| | 339 | BEGIN |
| | 340 | IF EXISTS (SELECT 1 FROM clinic_reviews cr WHERE cr.review_id = NEW.review_id) THEN |
| | 341 | RAISE EXCEPTION 'review_id % already used as clinic review (cannot also be user review)', NEW.review_id; |
| | 342 | END IF; |
| | 343 | RETURN NEW; |
| | 344 | END; |
| | 345 | $$; |
| | 346 | |
| | 347 | DROP TRIGGER IF EXISTS trg_user_review_exclusive ON user_reviews; |
| | 348 | CREATE TRIGGER trg_user_review_exclusive |
| | 349 | BEFORE INSERT |
| | 350 | ON user_reviews |
| | 351 | FOR EACH ROW |
| | 352 | EXECUTE FUNCTION petify_trg_user_review_exclusive(); |
| | 353 | |
| | 354 | |
| | 355 | CREATE OR REPLACE FUNCTION petify_trg_clinic_review_exclusive() |
| | 356 | RETURNS trigger |
| | 357 | LANGUAGE plpgsql |
| | 358 | AS $$ |
| | 359 | BEGIN |
| | 360 | IF EXISTS (SELECT 1 FROM user_reviews ur WHERE ur.review_id = NEW.review_id) THEN |
| | 361 | RAISE EXCEPTION 'review_id % already used as user review (cannot also be clinic review)', NEW.review_id; |
| | 362 | END IF; |
| | 363 | RETURN NEW; |
| | 364 | END; |
| | 365 | $$; |
| | 366 | |
| | 367 | DROP TRIGGER IF EXISTS trg_clinic_review_exclusive ON clinic_reviews; |
| | 368 | CREATE TRIGGER trg_clinic_review_exclusive |
| | 369 | BEFORE INSERT |
| | 370 | ON clinic_reviews |
| | 371 | FOR EACH ROW |
| | 372 | EXECUTE FUNCTION petify_trg_clinic_review_exclusive(); |
| | 373 | |
| | 374 | CREATE OR REPLACE FUNCTION petify_trg_user_reviews_cooldown() |
| | 375 | RETURNS trigger |
| | 376 | LANGUAGE plpgsql |
| | 377 | AS $$ |
| | 378 | DECLARE |
| | 379 | v_reviewer bigint; |
| | 380 | v_created timestamp; |
| | 381 | BEGIN |
| | 382 | SELECT reviewer_id, created_at INTO v_reviewer, v_created |
| | 383 | FROM reviews |
| | 384 | WHERE review_id = NEW.review_id; |
| | 385 | |
| | 386 | IF v_reviewer IS NULL THEN |
| | 387 | RAISE EXCEPTION 'Base review % not found', NEW.review_id; |
| | 388 | END IF; |
| | 389 | |
| | 390 | IF v_reviewer = NEW.target_user_id THEN |
| | 391 | RAISE EXCEPTION 'User cannot review themselves (user_id=%)', v_reviewer; |
| | 392 | END IF; |
| | 393 | |
| | 394 | IF EXISTS ( |
| | 395 | SELECT 1 |
| | 396 | FROM user_reviews ur |
| | 397 | JOIN reviews r ON r.review_id = ur.review_id |
| | 398 | WHERE r.reviewer_id = v_reviewer |
| | 399 | AND ur.target_user_id = NEW.target_user_id |
| | 400 | AND r.is_deleted = false |
| | 401 | AND r.created_at >= v_created - interval '30 days' |
| | 402 | ) THEN |
| | 403 | RAISE EXCEPTION 'Cooldown: reviewer % already reviewed user % within last 30 days', |
| | 404 | v_reviewer, NEW.target_user_id; |
| | 405 | END IF; |
| | 406 | |
| | 407 | RETURN NEW; |
| | 408 | END; |
| | 409 | $$; |
| | 410 | |
| | 411 | DROP TRIGGER IF EXISTS trg_user_reviews_cooldown ON user_reviews; |
| | 412 | CREATE TRIGGER trg_user_reviews_cooldown |
| | 413 | BEFORE INSERT |
| | 414 | ON user_reviews |
| | 415 | FOR EACH ROW |
| | 416 | EXECUTE FUNCTION petify_trg_user_reviews_cooldown(); |
| | 417 | |
| | 418 | CREATE OR REPLACE FUNCTION petify_trg_clinic_reviews_cooldown() |
| | 419 | RETURNS trigger |
| | 420 | LANGUAGE plpgsql |
| | 421 | AS $$ |
| | 422 | DECLARE |
| | 423 | v_reviewer bigint; |
| | 424 | v_created timestamp; |
| | 425 | BEGIN |
| | 426 | SELECT reviewer_id, created_at INTO v_reviewer, v_created |
| | 427 | FROM reviews |
| | 428 | WHERE review_id = NEW.review_id; |
| | 429 | |
| | 430 | IF v_reviewer IS NULL THEN |
| | 431 | RAISE EXCEPTION 'Base review % not found', NEW.review_id; |
| | 432 | END IF; |
| | 433 | |
| | 434 | IF EXISTS ( |
| | 435 | SELECT 1 |
| | 436 | FROM clinic_reviews cr |
| | 437 | JOIN reviews r ON r.review_id = cr.review_id |
| | 438 | WHERE r.reviewer_id = v_reviewer |
| | 439 | AND cr.target_clinic_id = NEW.target_clinic_id |
| | 440 | AND r.is_deleted = false |
| | 441 | AND r.created_at >= v_created - interval '30 days' |
| | 442 | ) THEN |
| | 443 | RAISE EXCEPTION 'Cooldown: reviewer % already reviewed clinic % within last 30 days', |
| | 444 | v_reviewer, NEW.target_clinic_id; |
| | 445 | END IF; |
| | 446 | |
| | 447 | RETURN NEW; |
| | 448 | END; |
| | 449 | $$; |
| | 450 | |
| | 451 | DROP TRIGGER IF EXISTS trg_clinic_reviews_cooldown ON clinic_reviews; |
| | 452 | CREATE TRIGGER trg_clinic_reviews_cooldown |
| | 453 | BEFORE INSERT |
| | 454 | ON clinic_reviews |
| | 455 | FOR EACH ROW |
| | 456 | EXECUTE FUNCTION petify_trg_clinic_reviews_cooldown(); |
| | 457 | |
| | 458 | }}} |
| | 459 | {{{Stored procedures}}} |
| | 460 | {{{ |
| | 461 | CREATE OR REPLACE PROCEDURE petify_soft_delete_review(p_review_id bigint) |
| | 462 | LANGUAGE plpgsql |
| | 463 | AS $$ |
| | 464 | BEGIN |
| | 465 | |
| | 466 | PERFORM set_config('session_replication_role', 'replica', true); |
| | 467 | |
| | 468 | UPDATE reviews |
| | 469 | SET is_deleted = true, |
| | 470 | updated_at = now() |
| | 471 | WHERE review_id = p_review_id; |
| | 472 | |
| | 473 | PERFORM set_config('session_replication_role', 'origin', true); |
| | 474 | END; |
| | 475 | $$; |
| | 476 | |
| | 477 | }}} |
| | 478 | {{{Views}}} |
| | 479 | {{{ |
| | 480 | CREATE OR REPLACE VIEW v_user_ratings AS |
| | 481 | SELECT |
| | 482 | ur.target_user_id, |
| | 483 | COUNT(*) FILTER (WHERE r.is_deleted = false) AS review_count, |
| | 484 | ROUND(AVG(r.rating)::numeric, 2) FILTER (WHERE r.is_deleted = false) AS avg_rating |
| | 485 | FROM user_reviews ur |
| | 486 | JOIN reviews r ON r.review_id = ur.review_id |
| | 487 | GROUP BY ur.target_user_id; |
| | 488 | |
| | 489 | CREATE OR REPLACE VIEW v_clinic_ratings AS |
| | 490 | SELECT |
| | 491 | cr.target_clinic_id, |
| | 492 | COUNT(*) FILTER (WHERE r.is_deleted = false) AS review_count, |
| | 493 | ROUND(AVG(r.rating)::numeric, 2) FILTER (WHERE r.is_deleted = false) AS avg_rating |
| | 494 | FROM clinic_reviews cr |
| | 495 | JOIN reviews r ON r.review_id = cr.review_id |
| | 496 | GROUP BY cr.target_clinic_id; |
| | 497 | }}} |
| | 498 | {{{Custom domains}} |
| | 499 | {{{ |
| | 500 | CREATE DOMAIN rating_1_5 AS int CHECK (VALUE BETWEEN 1 AND 5); |
| | 501 | }}} |
| | 502 | == Data constraints requirements: Background Jobs |
| | 503 | === Data requirements description |
| | 504 | These are time-based business rules that must be enforced asynchronously: |
| | 505 | * If an appointment is still CONFIRMED long after its scheduled time, mark it as NO_SHOW. |
| | 506 | * If an Archive listing is older than 30days its status is draft. |
| | 507 | === Implementation |
| | 508 | {{{Stored procedures}}} |
| | 509 | {{{ |
| | 510 | CREATE EXTENSION IF NOT EXISTS pg_cron; |
| | 511 | |
| | 512 | CREATE OR REPLACE PROCEDURE job_mark_no_show() |
| | 513 | LANGUAGE plpgsql |
| | 514 | AS $$ |
| | 515 | BEGIN |
| | 516 | UPDATE appointments |
| | 517 | SET status = 'NO_SHOW' |
| | 518 | WHERE status = 'CONFIRMED' |
| | 519 | AND date_time < now() - interval '45 minutes'; |
| | 520 | END; |
| | 521 | $$; |
| | 522 | |
| | 523 | CREATE OR REPLACE PROCEDURE job_archive_stale_drafts() |
| | 524 | LANGUAGE plpgsql |
| | 525 | AS $$ |
| | 526 | BEGIN |
| | 527 | UPDATE listings |
| | 528 | SET status = 'ARCHIVED' |
| | 529 | WHERE status = 'DRAFT' |
| | 530 | AND created_at < now() - interval '30 days'; |
| | 531 | END; |
| | 532 | $$; |
| | 533 | }}} |
| | 534 | {{{Views}}} |
| | 535 | {{{ |
| | 536 | CREATE OR REPLACE VIEW v_overdue_confirmed_appointments AS |
| | 537 | SELECT * |
| | 538 | FROM appointments |
| | 539 | WHERE status='CONFIRMED' |
| | 540 | AND date_time < now() - interval '45 minutes'; |
| | 541 | |
| | 542 | CREATE OR REPLACE VIEW v_stale_draft_listings AS |
| | 543 | SELECT * |
| | 544 | FROM listings |
| | 545 | WHERE status='DRAFT' |
| | 546 | AND created_at < now() - interval '30 days'; |
| | 547 | }}} |
| | 548 | {{{Scheduling}}} |
| | 549 | {{{ |
| | 550 | SELECT cron.schedule('petify_mark_no_show', '*/10 * * * *', $$CALL job_mark_no_show();$$); |
| | 551 | SELECT cron.schedule('petify_archive_stale_drafts_daily', '10 2 * * *', $$CALL job_archive_stale_drafts();$$); |
| | 552 | }}} |