| 37 | \\ |
| 38 | == Popular Items Report Table |
| 39 | CREATE TABLE restaurant_popular_items ( |
| 40 | report_id SERIAL PRIMARY KEY, |
| 41 | restaurant_id INT NOT NULL, |
| 42 | report_week DATE NOT NULL, |
| 43 | item_id INT NOT NULL, |
| 44 | item_name VARCHAR(100), |
| 45 | |
| 46 | times_ordered INTEGER DEFAULT 0, |
| 47 | total_quantity INTEGER DEFAULT 0, |
| 48 | total_revenue DECIMAL(10,2) DEFAULT 0.00, |
| 49 | avg_price DECIMAL(8,2) DEFAULT 0.00, |
| 50 | popularity_rank INTEGER, |
| 51 | |
| 52 | generated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, |
| 53 | |
| 54 | CONSTRAINT fk_popular_items_restaurant FOREIGN KEY (restaurant_id) REFERENCES restaurant(restaurant_id), |
| 55 | CONSTRAINT fk_popular_items_item FOREIGN KEY (item_id) REFERENCES item(item_id) |
| 56 | ); |
| 57 | \\ |
| 58 | == Daily Breakdown Table |
| 59 | CREATE TABLE restaurant_daily_breakdown ( |
| 60 | breakdown_id SERIAL PRIMARY KEY, |
| 61 | restaurant_id INT NOT NULL, |
| 62 | report_date DATE NOT NULL, |
| 63 | day_of_week INTEGER, -- 0=Sunday, 6=Saturday |
| 64 | |
| 65 | daily_orders INTEGER DEFAULT 0, |
| 66 | daily_revenue DECIMAL(10,2) DEFAULT 0.00, |
| 67 | daily_items_sold INTEGER DEFAULT 0, |
| 68 | avg_order_value DECIMAL(8,2) DEFAULT 0.00, |
| 69 | |
| 70 | -- Hourly breakdown (JSON format for flexibility) |
| 71 | hourly_orders JSONB, |
| 72 | |
| 73 | generated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, |
| 74 | |
| 75 | CONSTRAINT fk_daily_breakdown_restaurant FOREIGN KEY (restaurant_id) REFERENCES restaurant(restaurant_id), |
| 76 | CONSTRAINT uq_restaurant_daily UNIQUE (restaurant_id, report_date) |
| 77 | ); |
| 78 | \\ |
| 79 | == Comparative Analysis Table (Week Over Week) |
| 80 | CREATE TABLE restaurant_trend_analysis ( |
| 81 | trend_id SERIAL PRIMARY KEY, |
| 82 | restaurant_id INT NOT NULL, |
| 83 | analysis_date DATE DEFAULT CURRENT_DATE, |
| 84 | |
| 85 | -- 3-week trends |
| 86 | week1_revenue DECIMAL(10,2), -- Most recent week |
| 87 | week2_revenue DECIMAL(10,2), |
| 88 | week3_revenue DECIMAL(10,2), |
| 89 | |
| 90 | week1_orders INTEGER, |
| 91 | week2_orders INTEGER, |
| 92 | week3_orders INTEGER, |
| 93 | |
| 94 | -- Trend indicators |
| 95 | revenue_trend VARCHAR(20), -- 'INCREASING', 'DECREASING', 'STABLE' |
| 96 | order_trend VARCHAR(20), |
| 97 | |
| 98 | -- Growth rates |
| 99 | revenue_growth_rate DECIMAL(8,2), -- Week over week % |
| 100 | order_growth_rate DECIMAL(8,2), |
| 101 | |
| 102 | -- Performance alerts |
| 103 | performance_alerts JSONB, |
| 104 | recommendations JSONB, |
| 105 | |
| 106 | generated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, |
| 107 | |
| 108 | CONSTRAINT fk_trend_analysis_restaurant FOREIGN KEY (restaurant_id) REFERENCES restaurant(restaurant_id) |
| 109 | ); |
| 110 | \\ |
| 111 | == Performance Metrics Table |
| 112 | CREATE TABLE performance_metrics ( |
| 113 | metric_id SERIAL PRIMARY KEY, |
| 114 | restaurant_id INT NOT NULL, |
| 115 | metric_type VARCHAR(50), |
| 116 | metric_value DECIMAL(8,2), |
| 117 | recorded_at TIMESTAMP, |
| 118 | CONSTRAINT fk_performance_metrics_restaurant FOREIGN KEY (restaurant_id) REFERENCES RESTAURANT(restaurant_id) |
| 119 | ); |
| 120 | \\ |
| 121 | == Audit Table for Orders |
| 122 | CREATE TABLE audit_orders ( |
| 123 | audit_id SERIAL PRIMARY KEY, |
| 124 | order_id INT, |
| 125 | operation VARCHAR(50), |
| 126 | new_status VARCHAR(50), |
| 127 | changed_by VARCHAR(50), |
| 128 | change_timestamp TIMESTAMP DEFAULT CURRENT_TIMESTAMP |
| 129 | ); |
| 130 | \\ |
| 131 | = Utility Functions |
| 132 | \\ |
| 133 | == Get Week Start Function |
| 134 | CREATE OR REPLACE FUNCTION get_week_start(input_date DATE) |
| 135 | RETURNS DATE AS $$ |
| 136 | BEGIN |
| 137 | RETURN input_date - INTERVAL '1 day' * EXTRACT(DOW FROM input_date); |
| 138 | END; |
| 139 | $$ LANGUAGE plpgsql; |
| 140 | |
| 141 | == Get Week Number Function |
| 142 | CREATE OR REPLACE FUNCTION get_week_number(input_date DATE) |
| 143 | RETURNS INTEGER AS $$ |
| 144 | DECLARE |
| 145 | week_start DATE; |
| 146 | current_week_start DATE; |
| 147 | BEGIN |
| 148 | week_start := get_week_start(input_date); |
| 149 | current_week_start := get_week_start(CURRENT_DATE); |
| 150 | |
| 151 | RETURN CASE |
| 152 | WHEN week_start = current_week_start THEN 1 |
| 153 | WHEN week_start = current_week_start - INTERVAL '7 days' THEN 2 |
| 154 | WHEN week_start = current_week_start - INTERVAL '14 days' THEN 3 |
| 155 | ELSE 0 -- Outside 3-week window |
| 156 | END; |
| 157 | END; |
| 158 | $$ LANGUAGE plpgsql; |
| 159 | |
| 160 | == Main Report Generation Function |
| 161 | CREATE OR REPLACE FUNCTION generate_restaurant_weekly_report(p_restaurant_id INT, p_target_date DATE DEFAULT CURRENT_DATE) |
| 162 | RETURNS void AS $$ |
| 163 | DECLARE |
| 164 | week_start DATE; |
| 165 | week_end DATE; |
| 166 | week_num INTEGER; |
| 167 | |
| 168 | -- Variables for calculations |
| 169 | v_total_orders INTEGER; |
| 170 | v_completed_orders INTEGER; |
| 171 | v_cancelled_orders INTEGER; |
| 172 | v_gross_revenue DECIMAL(12,2); |
| 173 | v_net_revenue DECIMAL(12,2); |
| 174 | v_avg_order_value DECIMAL(10,2); |
| 175 | v_total_items_sold INTEGER; |
| 176 | v_avg_prep_time DECIMAL(8,2); |
| 177 | v_peak_hour INTEGER; |
| 178 | v_busiest_day INTEGER; |
| 179 | v_completion_rate DECIMAL(5,2); |
| 180 | v_orders_per_hour DECIMAL(8,2); |
| 181 | |
| 182 | commission_rate DECIMAL(5,4) := 0.15; -- 15% platform fee |
| 183 | BEGIN |
| 184 | -- Calculate week boundaries |
| 185 | week_start := get_week_start(p_target_date); |
| 186 | week_end := week_start + INTERVAL '6 days'; |
| 187 | week_num := get_week_number(p_target_date); |
| 188 | |
| 189 | -- Skip if outside 3-week window |
| 190 | IF week_num = 0 THEN |
| 191 | RETURN; |
| 192 | END IF; |
| 193 | |
| 194 | -- Calculate order statistics |
| 195 | SELECT |
| 196 | COUNT(*), |
| 197 | COUNT(*) FILTER (WHERE order_status = 'delivered'), |
| 198 | COUNT(*) FILTER (WHERE order_status = 'cancelled') |
| 199 | INTO v_total_orders, v_completed_orders, v_cancelled_orders |
| 200 | FROM orders |
| 201 | WHERE restaurant_id = p_restaurant_id |
| 202 | AND order_date::date BETWEEN week_start AND week_end; |
| 203 | |
| 204 | -- Calculate financial metrics |
| 205 | SELECT |
| 206 | COALESCE(SUM(total_amount), 0), |
| 207 | COALESCE(SUM(total_amount * (1 - commission_rate)), 0), |
| 208 | COALESCE(AVG(total_amount), 0) |
| 209 | INTO v_gross_revenue, v_net_revenue, v_avg_order_value |
| 210 | FROM orders |
| 211 | WHERE restaurant_id = p_restaurant_id |
| 212 | AND order_date::date BETWEEN week_start AND week_end |
| 213 | AND order_status = 'delivered'; |
| 214 | |
| 215 | -- Calculate total items sold |
| 216 | SELECT COALESCE(SUM(oi.quantity), 0) |
| 217 | INTO v_total_items_sold |
| 218 | FROM order_items oi |
| 219 | JOIN orders o ON oi.order_id = o.order_id |
| 220 | WHERE o.restaurant_id = p_restaurant_id |
| 221 | AND o.order_date::date BETWEEN week_start AND week_end |
| 222 | AND o.order_status = 'delivered'; |
| 223 | |
| 224 | -- Calculate average preparation time (using performance metrics if available) |
| 225 | SELECT COALESCE(AVG(metric_value), 0) |
| 226 | INTO v_avg_prep_time |
| 227 | FROM performance_metrics pm |
| 228 | WHERE pm.restaurant_id = p_restaurant_id |
| 229 | AND pm.metric_type = 'prep_time_minutes' |
| 230 | AND pm.recorded_at::date BETWEEN week_start AND week_end; |
| 231 | |
| 232 | -- Find peak hour |
| 233 | SELECT EXTRACT(hour FROM order_date) |
| 234 | INTO v_peak_hour |
| 235 | FROM orders |
| 236 | WHERE restaurant_id = p_restaurant_id |
| 237 | AND order_date::date BETWEEN week_start AND week_end |
| 238 | GROUP BY EXTRACT(hour FROM order_date) |
| 239 | ORDER BY COUNT(*) DESC |
| 240 | LIMIT 1; |
| 241 | |
| 242 | -- Find busiest day of week |
| 243 | SELECT EXTRACT(dow FROM order_date) |
| 244 | INTO v_busiest_day |
| 245 | FROM orders |
| 246 | WHERE restaurant_id = p_restaurant_id |
| 247 | AND order_date::date BETWEEN week_start AND week_end |
| 248 | GROUP BY EXTRACT(dow FROM order_date) |
| 249 | ORDER BY COUNT(*) DESC |
| 250 | LIMIT 1; |
| 251 | |
| 252 | -- Calculate completion rate |
| 253 | v_completion_rate := CASE |
| 254 | WHEN v_total_orders > 0 THEN |
| 255 | ROUND((v_completed_orders::DECIMAL / v_total_orders::DECIMAL) * 100, 2) |
| 256 | ELSE 0 |
| 257 | END; |
| 258 | |
| 259 | -- Calculate orders per hour (during operating hours) |
| 260 | WITH operating_hours AS ( |
| 261 | SELECT |
| 262 | EXTRACT(EPOCH FROM (closing_time - opening_time))/3600 * 7 as total_hours_week |
| 263 | FROM restaurant |
| 264 | WHERE restaurant_id = p_restaurant_id |
| 265 | ) |
| 266 | SELECT CASE |
| 267 | WHEN oh.total_hours_week > 0 THEN v_total_orders::DECIMAL / oh.total_hours_week |
| 268 | ELSE 0 |
| 269 | END |
| 270 | INTO v_orders_per_hour |
| 271 | FROM operating_hours oh; |
| 272 | |
| 273 | -- Insert or update the weekly report |
| 274 | INSERT INTO restaurant_weekly_report ( |
| 275 | restaurant_id, report_week, week_number, |
| 276 | total_orders, completed_orders, cancelled_orders, |
| 277 | gross_revenue, net_revenue, average_order_value, total_items_sold, |
| 278 | avg_preparation_time_minutes, peak_hour, busiest_day, |
| 279 | completion_rate, orders_per_hour, last_updated |
| 280 | ) VALUES ( |
| 281 | p_restaurant_id, week_start, week_num, |
| 282 | v_total_orders, v_completed_orders, v_cancelled_orders, |
| 283 | v_gross_revenue, v_net_revenue, v_avg_order_value, v_total_items_sold, |
| 284 | v_avg_prep_time, v_peak_hour, v_busiest_day, |
| 285 | v_completion_rate, v_orders_per_hour, CURRENT_TIMESTAMP |
| 286 | ) |
| 287 | ON CONFLICT (restaurant_id, report_week) |
| 288 | DO UPDATE SET |
| 289 | total_orders = EXCLUDED.total_orders, |
| 290 | completed_orders = EXCLUDED.completed_orders, |
| 291 | cancelled_orders = EXCLUDED.cancelled_orders, |
| 292 | gross_revenue = EXCLUDED.gross_revenue, |
| 293 | net_revenue = EXCLUDED.net_revenue, |
| 294 | average_order_value = EXCLUDED.average_order_value, |
| 295 | total_items_sold = EXCLUDED.total_items_sold, |
| 296 | avg_preparation_time_minutes = EXCLUDED.avg_preparation_time_minutes, |
| 297 | peak_hour = EXCLUDED.peak_hour, |
| 298 | busiest_day = EXCLUDED.busiest_day, |
| 299 | completion_rate = EXCLUDED.completion_rate, |
| 300 | orders_per_hour = EXCLUDED.orders_per_hour, |
| 301 | last_updated = CURRENT_TIMESTAMP; |
| 302 | |
| 303 | -- Generate popular items report |
| 304 | PERFORM generate_popular_items_report(p_restaurant_id, week_start); |
| 305 | |
| 306 | -- Generate daily breakdown |
| 307 | PERFORM generate_daily_breakdown_report(p_restaurant_id, week_start, week_end); |
| 308 | |
| 309 | END; |
| 310 | $$ LANGUAGE plpgsql; |
| 311 | |
| 312 | == Popular Items Report Function |
| 313 | CREATE OR REPLACE FUNCTION generate_popular_items_report(p_restaurant_id INT, p_week_start DATE) |
| 314 | RETURNS void AS $$ |
| 315 | BEGIN |
| 316 | -- Clear existing data for this week |
| 317 | DELETE FROM restaurant_popular_items |
| 318 | WHERE restaurant_id = p_restaurant_id AND report_week = p_week_start; |
| 319 | |
| 320 | -- Insert top 10 popular items for the week |
| 321 | INSERT INTO restaurant_popular_items ( |
| 322 | restaurant_id, report_week, item_id, item_name, |
| 323 | times_ordered, total_quantity, total_revenue, avg_price, popularity_rank |
| 324 | ) |
| 325 | WITH popular_items AS ( |
| 326 | SELECT |
| 327 | i.item_id, |
| 328 | i.name as item_name, |
| 329 | COUNT(DISTINCT o.order_id) as times_ordered, |
| 330 | SUM(oi.quantity) as total_quantity, |
| 331 | SUM(oi.total_price) as total_revenue, |
| 332 | AVG(oi.total_price / oi.quantity) as avg_price, |
| 333 | ROW_NUMBER() OVER (ORDER BY COUNT(DISTINCT o.order_id) DESC) as popularity_rank |
| 334 | FROM orders o |
| 335 | JOIN order_items oi ON o.order_id = oi.order_id |
| 336 | JOIN item i ON oi.item_id = i.item_id |
| 337 | WHERE o.restaurant_id = p_restaurant_id |
| 338 | AND o.order_date::date BETWEEN p_week_start AND p_week_start + INTERVAL '6 days' |
| 339 | AND o.order_status = 'delivered' |
| 340 | GROUP BY i.item_id, i.name |
| 341 | ORDER BY times_ordered DESC |
| 342 | LIMIT 10 |
| 343 | ) |
| 344 | SELECT |
| 345 | p_restaurant_id, p_week_start, item_id, item_name, |
| 346 | times_ordered, total_quantity, total_revenue, avg_price, popularity_rank |
| 347 | FROM popular_items; |
| 348 | END; |
| 349 | $$ LANGUAGE plpgsql; |
| 350 | |
| 351 | == Trend Analysis Function |
| 352 | CREATE OR REPLACE FUNCTION generate_trend_analysis(p_restaurant_id INT) |
| 353 | RETURNS void AS $$ |
| 354 | DECLARE |
| 355 | week1_start DATE := get_week_start(CURRENT_DATE); |
| 356 | week2_start DATE := week1_start - INTERVAL '7 days'; |
| 357 | week3_start DATE := week1_start - INTERVAL '14 days'; |
| 358 | |
| 359 | w1_revenue DECIMAL(10,2); |
| 360 | w2_revenue DECIMAL(10,2); |
| 361 | w3_revenue DECIMAL(10,2); |
| 362 | w1_orders INTEGER; |
| 363 | w2_orders INTEGER; |
| 364 | w3_orders INTEGER; |
| 365 | |
| 366 | revenue_trend_val VARCHAR(20); |
| 367 | order_trend_val VARCHAR(20); |
| 368 | revenue_growth DECIMAL(8,2); |
| 369 | order_growth DECIMAL(8,2); |
| 370 | |
| 371 | alerts JSONB := '[]'::jsonb; |
| 372 | recommendations JSONB := '[]'::jsonb; |
| 373 | BEGIN |
| 374 | -- Get weekly data |
| 375 | SELECT gross_revenue, total_orders INTO w1_revenue, w1_orders |
| 376 | FROM restaurant_weekly_report |
| 377 | WHERE restaurant_id = p_restaurant_id AND report_week = week1_start; |
| 378 | |
| 379 | SELECT gross_revenue, total_orders INTO w2_revenue, w2_orders |
| 380 | FROM restaurant_weekly_report |
| 381 | WHERE restaurant_id = p_restaurant_id AND report_week = week2_start; |
| 382 | |
| 383 | SELECT gross_revenue, total_orders INTO w3_revenue, w3_orders |
| 384 | FROM restaurant_weekly_report |
| 385 | WHERE restaurant_id = p_restaurant_id AND report_week = week3_start; |
| 386 | |
| 387 | -- Calculate trends |
| 388 | IF w2_revenue > 0 THEN |
| 389 | revenue_growth := ROUND(((w1_revenue - w2_revenue) / w2_revenue) * 100, 2); |
| 390 | ELSE |
| 391 | revenue_growth := 0; |
| 392 | END IF; |
| 393 | |
| 394 | IF w2_orders > 0 THEN |
| 395 | order_growth := ROUND(((w1_orders - w2_orders)::DECIMAL / w2_orders::DECIMAL) * 100, 2); |
| 396 | ELSE |
| 397 | order_growth := 0; |
| 398 | END IF; |
| 399 | |
| 400 | -- Determine trend direction |
| 401 | revenue_trend_val := CASE |
| 402 | WHEN revenue_growth > 5 THEN 'INCREASING' |
| 403 | WHEN revenue_growth < -5 THEN 'DECREASING' |
| 404 | ELSE 'STABLE' |
| 405 | END; |
| 406 | |
| 407 | order_trend_val := CASE |
| 408 | WHEN order_growth > 5 THEN 'INCREASING' |
| 409 | WHEN order_growth < -5 THEN 'DECREASING' |
| 410 | ELSE 'STABLE' |
| 411 | END; |
| 412 | |
| 413 | -- Generate alerts |
| 414 | IF revenue_growth < -20 THEN |
| 415 | alerts := alerts || '{"type": "revenue_decline", "severity": "high", "message": "Revenue declined by more than 20% this week"}'::jsonb; |
| 416 | END IF; |
| 417 | |
| 418 | IF order_growth < -15 THEN |
| 419 | alerts := alerts || '{"type": "order_decline", "severity": "medium", "message": "Order volume declined by more than 15% this week"}'::jsonb; |
| 420 | END IF; |
| 421 | |
| 422 | -- Generate recommendations |
| 423 | IF revenue_trend_val = 'DECREASING' THEN |
| 424 | recommendations := recommendations || '{"type": "marketing", "action": "Consider promotional campaigns or menu updates"}'::jsonb; |
| 425 | END IF; |
| 426 | |
| 427 | IF order_trend_val = 'DECREASING' THEN |
| 428 | recommendations := recommendations || '{"type": "operations", "action": "Review menu pricing and delivery times"}'::jsonb; |
| 429 | END IF; |
| 430 | |
| 431 | -- Insert trend analysis |
| 432 | INSERT INTO restaurant_trend_analysis ( |
| 433 | restaurant_id, week1_revenue, week2_revenue, week3_revenue, |
| 434 | week1_orders, week2_orders, week3_orders, |
| 435 | revenue_trend, order_trend, revenue_growth_rate, order_growth_rate, |
| 436 | performance_alerts, recommendations |
| 437 | ) VALUES ( |
| 438 | p_restaurant_id, w1_revenue, w2_revenue, w3_revenue, |
| 439 | w1_orders, w2_orders, w3_orders, |
| 440 | revenue_trend_val, order_trend_val, revenue_growth, order_growth, |
| 441 | alerts, recommendations |
| 442 | ) |
| 443 | ON CONFLICT (restaurant_id) |
| 444 | DO UPDATE SET |
| 445 | week1_revenue = EXCLUDED.week1_revenue, |
| 446 | week2_revenue = EXCLUDED.week2_revenue, |
| 447 | week3_revenue = EXCLUDED.week3_revenue, |
| 448 | week1_orders = EXCLUDED.week1_orders, |
| 449 | week2_orders = EXCLUDED.week2_orders, |
| 450 | week3_orders = EXCLUDED.week3_orders, |
| 451 | revenue_trend = EXCLUDED.revenue_trend, |
| 452 | order_trend = EXCLUDED.order_trend, |
| 453 | revenue_growth_rate = EXCLUDED.revenue_growth_rate, |
| 454 | order_growth_rate = EXCLUDED.order_growth_rate, |
| 455 | performance_alerts = EXCLUDED.performance_alerts, |
| 456 | recommendations = EXCLUDED.recommendations, |
| 457 | generated_at = CURRENT_TIMESTAMP; |
| 458 | END; |
| 459 | $$ LANGUAGE plpgsql; |
| 460 | |
| 461 | = Trigger Functions |
| 462 | == Update Restaurant Reports Trigger Function |
| 463 | CREATE OR REPLACE FUNCTION update_restaurant_reports() |
| 464 | RETURNS TRIGGER AS $$ |
| 465 | DECLARE |
| 466 | affected_restaurant_id INT; |
| 467 | order_date_to_check DATE; |
| 468 | BEGIN |
| 469 | -- Determine which restaurant and date to update |
| 470 | affected_restaurant_id := COALESCE(NEW.restaurant_id, OLD.restaurant_id); |
| 471 | order_date_to_check := COALESCE(NEW.order_date::date, OLD.order_date::date); |
| 472 | |
| 473 | -- Only update if the order is within the last 3 weeks |
| 474 | IF order_date_to_check >= CURRENT_DATE - INTERVAL '21 days' THEN |
| 475 | -- Update reports for the affected week |
| 476 | PERFORM generate_restaurant_weekly_report(affected_restaurant_id, order_date_to_check); |
| 477 | |
| 478 | -- Update trend analysis |
| 479 | PERFORM generate_trend_analysis(affected_restaurant_id); |
| 480 | |
| 481 | -- Log the report update |
| 482 | INSERT INTO audit_orders (order_id, operation, new_status, changed_by) |
| 483 | VALUES ( |
| 484 | COALESCE(NEW.order_id, OLD.order_id), |
| 485 | 'REPORT_UPDATE', |
| 486 | 'Restaurant report updated', |
| 487 | 'system' |
| 488 | ); |
| 489 | END IF; |
| 490 | |
| 491 | RETURN COALESCE(NEW, OLD); |
| 492 | END; |
| 493 | $$ LANGUAGE plpgsql; |
| 494 | |
| 495 | == Update Reports on Items Change Trigger Function |
| 496 | CREATE OR REPLACE FUNCTION update_reports_on_items_change() |
| 497 | RETURNS TRIGGER AS $$ |
| 498 | DECLARE |
| 499 | affected_restaurant_id INT; |
| 500 | order_date_to_check DATE; |
| 501 | BEGIN |
| 502 | -- Get restaurant and date from the order |
| 503 | SELECT restaurant_id, order_date::date INTO affected_restaurant_id, order_date_to_check |
| 504 | FROM orders WHERE order_id = COALESCE(NEW.order_id, OLD.order_id); |
| 505 | |
| 506 | -- Only update if within the last 3 weeks |
| 507 | IF order_date_to_check >= CURRENT_DATE - INTERVAL '21 days' THEN |
| 508 | PERFORM generate_restaurant_weekly_report(affected_restaurant_id, order_date_to_check); |
| 509 | PERFORM generate_trend_analysis(affected_restaurant_id); |
| 510 | END IF; |
| 511 | |
| 512 | RETURN COALESCE(NEW, OLD); |
| 513 | END; |
| 514 | $$ LANGUAGE plpgsql; |
| 515 | |
| 516 | == Create Triggers |
| 517 | -- Trigger on orders table |
| 518 | CREATE TRIGGER trg_update_restaurant_reports |
| 519 | AFTER INSERT OR UPDATE OR DELETE ON orders |
| 520 | FOR EACH ROW |
| 521 | EXECUTE FUNCTION update_restaurant_reports(); |
| 522 | |
| 523 | -- Trigger on order_items table |
| 524 | CREATE TRIGGER trg_update_reports_items |
| 525 | AFTER INSERT OR UPDATE OR DELETE ON order_items |
| 526 | FOR EACH ROW |
| 527 | EXECUTE FUNCTION update_reports_on_items_change(); |
| 528 | |
| 529 | == Report Views for Easy Access |
| 530 | Comprehensive 3-Week Restaurant Report View |
| 531 | CREATE VIEW restaurant_3week_summary AS |
| 532 | SELECT |
| 533 | r.name as restaurant_name, |
| 534 | rwr.restaurant_id, |
| 535 | |
| 536 | -- Current week (Week 1) |
| 537 | MAX(CASE WHEN rwr.week_number = 1 THEN rwr.total_orders END) as current_week_orders, |
| 538 | MAX(CASE WHEN rwr.week_number = 1 THEN rwr.gross_revenue END) as current_week_revenue, |
| 539 | MAX(CASE WHEN rwr.week_number = 1 THEN rwr.completion_rate END) as current_week_completion_rate, |
| 540 | |
| 541 | -- Previous week (Week 2) |
| 542 | MAX(CASE WHEN rwr.week_number = 2 THEN rwr.total_orders END) as prev_week_orders, |
| 543 | MAX(CASE WHEN rwr.week_number = 2 THEN rwr.gross_revenue END) as prev_week_revenue, |
| 544 | |
| 545 | -- 3 weeks ago (Week 3) |
| 546 | MAX(CASE WHEN rwr.week_number = 3 THEN rwr.total_orders END) as week3_orders, |
| 547 | MAX(CASE WHEN rwr.week_number = 3 THEN rwr.gross_revenue END) as week3_revenue, |
| 548 | |
| 549 | -- Totals |
| 550 | SUM(rwr.total_orders) as total_orders_3weeks, |
| 551 | SUM(rwr.gross_revenue) as total_revenue_3weeks, |
| 552 | AVG(rwr.average_order_value) as avg_order_value_3weeks, |
| 553 | AVG(rwr.completion_rate) as avg_completion_rate, |
| 554 | |
| 555 | -- Operational insights |
| 556 | MAX(CASE WHEN rwr.week_number = 1 THEN rwr.peak_hour END) as current_peak_hour, |
| 557 | MAX(CASE WHEN rwr.week_number = 1 THEN rwr.busiest_day END) as current_busiest_day, |
| 558 | AVG(rwr.avg_preparation_time_minutes) as avg_prep_time, |
| 559 | |
| 560 | MAX(rwr.last_updated) as last_updated |
| 561 | FROM restaurant_weekly_report rwr |
| 562 | JOIN restaurant r ON rwr.restaurant_id = r.restaurant_id |
| 563 | WHERE rwr.report_week >= CURRENT_DATE - INTERVAL '21 days' |
| 564 | GROUP BY r.name, rwr.restaurant_id; |
| 565 | |
| 566 | == Top Performing Restaurants View |
| 567 | CREATE VIEW top_restaurants_3weeks AS |
| 568 | SELECT |
| 569 | r.name as restaurant_name, |
| 570 | SUM(rwr.gross_revenue) as total_revenue, |
| 571 | SUM(rwr.total_orders) as total_orders, |
| 572 | AVG(rwr.completion_rate) as avg_completion_rate, |
| 573 | AVG(rwr.average_order_value) as avg_order_value, |
| 574 | rta.revenue_trend, |
| 575 | rta.revenue_growth_rate |
| 576 | FROM restaurant_weekly_report rwr |
| 577 | JOIN restaurant r ON rwr.restaurant_id = r.restaurant_id |
| 578 | LEFT JOIN restaurant_trend_analysis rta ON rwr.restaurant_id = rta.restaurant_id |
| 579 | WHERE rwr.report_week >= CURRENT_DATE - INTERVAL '21 days' |
| 580 | GROUP BY r.name, rta.revenue_trend, rta.revenue_growth_rate |
| 581 | ORDER BY total_revenue DESC; |
| 582 | |
| 583 | == Daily Reports Function |
| 584 | CREATE OR REPLACE FUNCTION generate_daily_breakdown_report( |
| 585 | p_restaurant_id INT, |
| 586 | p_week_start DATE, |
| 587 | p_week_end DATE |
| 588 | ) RETURNS void |
| 589 | LANGUAGE plpgsql |
| 590 | AS $$ |
| 591 | DECLARE |
| 592 | v_day DATE := p_week_start; |
| 593 | v_daily_orders INTEGER := 0; |
| 594 | v_daily_revenue NUMERIC(12,2) := 0; |
| 595 | v_daily_items_sold INTEGER := 0; |
| 596 | v_avg_order_value NUMERIC(12,2) := 0; |
| 597 | v_hourly_orders JSONB := '{}'::jsonb; |
| 598 | BEGIN |
| 599 | IF p_week_end < p_week_start THEN |
| 600 | RAISE EXCEPTION 'p_week_end (%) must be >= p_week_start (%)', p_week_end, p_week_start; |
| 601 | END IF; |
| 602 | |
| 603 | DELETE FROM restaurant_daily_breakdown |
| 604 | WHERE restaurant_id = p_restaurant_id |
| 605 | AND report_date BETWEEN p_week_start AND p_week_end; |
| 606 | |
| 607 | WHILE v_day <= p_week_end LOOP |
| 608 | -- Daily metrics |
| 609 | SELECT |
| 610 | COUNT(*), |
| 611 | COALESCE(SUM(total_amount), 0)::NUMERIC(12,2), |
| 612 | COALESCE(AVG(total_amount), 0)::NUMERIC(12,2) |
| 613 | INTO v_daily_orders, v_daily_revenue, v_avg_order_value |
| 614 | FROM orders |
| 615 | WHERE restaurant_id = p_restaurant_id |
| 616 | AND order_date::date = v_day |
| 617 | AND order_status = 'delivered'; |
| 618 | |
| 619 | -- Daily items sold |
| 620 | SELECT COALESCE(SUM(oi.quantity), 0) |
| 621 | INTO v_daily_items_sold |
| 622 | FROM order_items oi |
| 623 | JOIN orders o ON oi.order_id = o.order_id |
| 624 | WHERE o.restaurant_id = p_restaurant_id |
| 625 | AND o.order_date::date = v_day |
| 626 | AND o.order_status = 'delivered'; |
| 627 | |
| 628 | -- Hourly order breakdown (as JSONB) |
| 629 | SELECT COALESCE(jsonb_object_agg(order_hour::text, order_count), '{}'::jsonb) |
| 630 | INTO v_hourly_orders |
| 631 | FROM ( |
| 632 | SELECT |
| 633 | EXTRACT(hour FROM order_date) AS order_hour, |
| 634 | COUNT(*) AS order_count |
| 635 | FROM orders |
| 636 | WHERE restaurant_id = p_restaurant_id |
| 637 | AND order_date::date = v_day |
| 638 | AND order_status = 'delivered' |
| 639 | GROUP BY 1 |
| 640 | ) AS hourly_counts; |
| 641 | |
| 642 | -- Insert daily breakdown |
| 643 | INSERT INTO restaurant_daily_breakdown ( |
| 644 | restaurant_id, |
| 645 | report_date, |
| 646 | day_of_week, |
| 647 | daily_orders, |
| 648 | daily_revenue, |
| 649 | daily_items_sold, |
| 650 | avg_order_value, |
| 651 | hourly_orders |
| 652 | ) VALUES ( |
| 653 | p_restaurant_id, |
| 654 | v_day, |
| 655 | EXTRACT(DOW FROM v_day), |
| 656 | v_daily_orders, |
| 657 | v_daily_revenue, |
| 658 | v_daily_items_sold, |
| 659 | v_avg_order_value, |
| 660 | v_hourly_orders |
| 661 | ); |
| 662 | |
| 663 | -- Next day |
| 664 | v_day := v_day + 1; -- date + integer yields date |
| 665 | END LOOP; |
| 666 | END; |
| 667 | $$; |
| 668 | |
| 669 | == Constraint Addition |
| 670 | ALTER TABLE restaurant_trend_analysis |
| 671 | ADD CONSTRAINT uq_restaurant_id UNIQUE (restaurant_id); |