├── 8-weeks-SQL-Challenge ├── README.md ├── Week 1 │ ├── 1. SQL_Schema │ └── My_Solution └── Week 2 │ ├── 1. SQL_Schema │ ├── 2. Solution_Pizza_Metrics │ ├── 3. Solution_Runner_and_Customer_Experience │ ├── 4. Ingredient_Optimisation │ └── 5. Pricing_And_Ratings.sql ├── Case Study #1 - Danny's Diner ├── README.md ├── SQL_Output └── SQL_code.sql ├── Case Study #2: Pizza Runner ├── README.md ├── SQL_code │ └── Complete_Solution └── SQL_output │ ├── 1. SQL_Schema │ ├── 2. Solution_Pizza_Metrics │ ├── 3. Solution_Runner_and_Customer_Experience │ ├── 4. Ingredient_Optimisation │ └── 5. Pricing_And_Ratings ├── README.md └── images ├── .gitkeep ├── ER_case_1.png └── ER_case_2.png /8-weeks-SQL-Challenge/README.md: -------------------------------------------------------------------------------- 1 | https://8weeksqlchallenge.com/getting-started/ 2 | 3 | The 8 weeks SQL Challenge was the perfect opportunity to test my skills on diverse mini projects which encompass a wide range of SQL techniques. 4 | My goal is both to display my current mastery of SQL & define improvement goals for the future ! 5 | -------------------------------------------------------------------------------- /8-weeks-SQL-Challenge/Week 1/1. SQL_Schema: -------------------------------------------------------------------------------- 1 | -- **Schema (PostgreSQL v13)** 2 | 3 | CREATE TABLE sales ( 4 | "customer_id" VARCHAR(1), 5 | "order_date" DATE, 6 | "product_id" INTEGER 7 | ); 8 | 9 | INSERT INTO sales 10 | ("customer_id", "order_date", "product_id") 11 | VALUES 12 | ('A', '2021-01-01', '1'), 13 | ('A', '2021-01-01', '2'), 14 | ('A', '2021-01-07', '2'), 15 | ('A', '2021-01-10', '3'), 16 | ('A', '2021-01-11', '3'), 17 | ('A', '2021-01-11', '3'), 18 | ('B', '2021-01-01', '2'), 19 | ('B', '2021-01-02', '2'), 20 | ('B', '2021-01-04', '1'), 21 | ('B', '2021-01-11', '1'), 22 | ('B', '2021-01-16', '3'), 23 | ('B', '2021-02-01', '3'), 24 | ('C', '2021-01-01', '3'), 25 | ('C', '2021-01-01', '3'), 26 | ('C', '2021-01-07', '3'); 27 | 28 | 29 | CREATE TABLE menu ( 30 | "product_id" INTEGER, 31 | "product_name" VARCHAR(5), 32 | "price" INTEGER 33 | ); 34 | 35 | INSERT INTO menu 36 | ("product_id", "product_name", "price") 37 | VALUES 38 | ('1', 'sushi', '10'), 39 | ('2', 'curry', '15'), 40 | ('3', 'ramen', '12'); 41 | 42 | 43 | CREATE TABLE members ( 44 | "customer_id" VARCHAR(1), 45 | "join_date" DATE 46 | ); 47 | 48 | INSERT INTO members 49 | ("customer_id", "join_date") 50 | VALUES 51 | ('A', '2021-01-07'), 52 | ('B', '2021-01-09'); 53 | -------------------------------------------------------------------------------- /8-weeks-SQL-Challenge/Week 1/My_Solution: -------------------------------------------------------------------------------- 1 | -- Data with Danny - 8 Week Challenge (Week 1) 2 | -- https://8weeksqlchallenge.com/case-study-1/ 3 | 4 | -- Done with PostgreSQL 5 | 6 | -- Case Study Questions 7 | -- Each of the following case study questions can be answered using a single SQL statement: 8 | -- 9 | -- 1) What is the total amount each customer spent at the restaurant? 10 | -- 2) How many days has each customer visited the restaurant? 11 | -- 3) What was the first item from the menu purchased by each customer? 12 | -- 4) What is the most purchased item on the menu and how many times was it purchased by all customers? 13 | -- 5)Which item was the most popular for each customer? 14 | -- 6) Which item was purchased first by the customer after they became a member? 15 | -- 7) Which item was purchased just before the customer became a member? 16 | -- 8) What is the total items and amount spent for each member before they became a member? 17 | -- 9) If each $1 spent equates to 10 points and sushi has a 2x points multiplier - how many points would each customer have? 18 | -- 10) In the first week after a customer joins the program (including their join date) they earn 2x points on all items, not just sushi - how many points do customer A and B have at the end of January? 19 | 20 | -- Bonus Questions: recreate 2 tables 21 | -- 1) Join all the things (see case link) 22 | -- 2) Rank all the things (see case link) 23 | 24 | -------------------------------------------------------------------------------------------------------------------------------------------------------- 25 | 26 | -- BONUS QUESTION 1; Join All The Things 27 | 28 | SELECT 29 | S.customer_id, 30 | S.order_date, 31 | S.product_id, 32 | MU.product_name, 33 | MU.price, 34 | CASE WHEN (S.order_date >= MB.join_date) THEN 'Y' else 'N' END AS member 35 | FROM 36 | sales AS S 37 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 38 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 39 | ORDER BY customer_id, order_date; 40 | 41 | | customer_id | order_date | product_id | product_name | price | member | 42 | | ----------- | ------------------------ | ---------- | ------------ | ----- | ------ | 43 | | A | 2021-01-01T00:00:00.000Z | 1 | sushi | 10 | N | 44 | | A | 2021-01-01T00:00:00.000Z | 2 | curry | 15 | N | 45 | | A | 2021-01-07T00:00:00.000Z | 2 | curry | 15 | Y | 46 | | A | 2021-01-10T00:00:00.000Z | 3 | ramen | 12 | Y | 47 | | A | 2021-01-11T00:00:00.000Z | 3 | ramen | 12 | Y | 48 | | A | 2021-01-11T00:00:00.000Z | 3 | ramen | 12 | Y | 49 | | B | 2021-01-01T00:00:00.000Z | 2 | curry | 15 | N | 50 | | B | 2021-01-02T00:00:00.000Z | 2 | curry | 15 | N | 51 | | B | 2021-01-04T00:00:00.000Z | 1 | sushi | 10 | N | 52 | | B | 2021-01-11T00:00:00.000Z | 1 | sushi | 10 | Y | 53 | | B | 2021-01-16T00:00:00.000Z | 3 | ramen | 12 | Y | 54 | | B | 2021-02-01T00:00:00.000Z | 3 | ramen | 12 | Y | 55 | | C | 2021-01-01T00:00:00.000Z | 3 | ramen | 12 | N | 56 | | C | 2021-01-01T00:00:00.000Z | 3 | ramen | 12 | N | 57 | | C | 2021-01-07T00:00:00.000Z | 3 | ramen | 12 | N | 58 | 59 | --- 60 | -- BONUS QUESTION 2: Rank All The Things 61 | 62 | WITH joined_table AS( 63 | SELECT 64 | S.customer_id, 65 | S.order_date, 66 | S.product_id, 67 | MU.product_name, 68 | MU.price, 69 | CASE WHEN (S.order_date >= MB.join_date) THEN 'Y' else 'N' END AS member 70 | FROM 71 | sales AS S 72 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 73 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 74 | ORDER BY customer_id, order_date 75 | ) 76 | SELECT 77 | customer_id, 78 | order_date, 79 | product_id, 80 | product_name, 81 | price, 82 | member, 83 | CASE WHEN member = 'Y' THEN rank() OVER (PARTITION BY customer_id, member ORDER BY order_date) ELSE NULL END as ranking 84 | FROM 85 | joined_table; 86 | 87 | | customer_id | order_date | product_id | product_name | price | member | ranking | 88 | | ----------- | ------------------------ | ---------- | ------------ | ----- | ------ | ------- | 89 | | A | 2021-01-01T00:00:00.000Z | 1 | sushi | 10 | N | | 90 | | A | 2021-01-01T00:00:00.000Z | 2 | curry | 15 | N | | 91 | | A | 2021-01-07T00:00:00.000Z | 2 | curry | 15 | Y | 1 | 92 | | A | 2021-01-10T00:00:00.000Z | 3 | ramen | 12 | Y | 2 | 93 | | A | 2021-01-11T00:00:00.000Z | 3 | ramen | 12 | Y | 3 | 94 | | A | 2021-01-11T00:00:00.000Z | 3 | ramen | 12 | Y | 3 | 95 | | B | 2021-01-01T00:00:00.000Z | 2 | curry | 15 | N | | 96 | | B | 2021-01-02T00:00:00.000Z | 2 | curry | 15 | N | | 97 | | B | 2021-01-04T00:00:00.000Z | 1 | sushi | 10 | N | | 98 | | B | 2021-01-11T00:00:00.000Z | 1 | sushi | 10 | Y | 1 | 99 | | B | 2021-01-16T00:00:00.000Z | 3 | ramen | 12 | Y | 2 | 100 | | B | 2021-02-01T00:00:00.000Z | 3 | ramen | 12 | Y | 3 | 101 | | C | 2021-01-01T00:00:00.000Z | 3 | ramen | 12 | N | | 102 | | C | 2021-01-01T00:00:00.000Z | 3 | ramen | 12 | N | | 103 | | C | 2021-01-07T00:00:00.000Z | 3 | ramen | 12 | N | | 104 | 105 | ------------------------------------------------------ 106 | 107 | -- 1. What is the total amount each customer spent at the restaurant? 108 | 109 | SELECT 110 | customer_id, 111 | SUM(price) as total_spent 112 | FROM 113 | ( 114 | SELECT 115 | S.customer_id, 116 | S.order_date, 117 | S.product_id, 118 | MU.product_name, 119 | MU.price, 120 | CASE 121 | WHEN (S.order_date >= MB.join_date) THEN 'Y' 122 | else 'N' 123 | END AS member 124 | FROM 125 | sales AS S 126 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 127 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 128 | ORDER BY 129 | customer_id, 130 | order_date 131 | ) as bonus_table 132 | GROUP BY 133 | customer_id 134 | ORDER BY 135 | customer_id; 136 | 137 | | customer_id | total_spent | 138 | | ----------- | ----------- | 139 | | A | 76 | 140 | | B | 74 | 141 | | C | 36 | 142 | 143 | 144 | ------------------------------------------------------ 145 | -- 2. How many days has each customer visited the restaurant? 146 | 147 | SELECT 148 | customer_id, 149 | COUNT(DISTINCT order_date) 150 | FROM 151 | sales 152 | GROUP BY 153 | customer_id; 154 | 155 | | customer_id | count | 156 | | ----------- | ----- | 157 | | A | 4 | 158 | | B | 6 | 159 | | C | 2 | 160 | 161 | ------------------------------------------------------ 162 | -- 3. What was the first item from the menu purchased by each customer? 163 | 164 | SELECT 165 | customer_id, 166 | product_name 167 | FROM 168 | ( 169 | WITH table_name AS( 170 | SELECT 171 | S.customer_id, 172 | S.order_date, 173 | M.product_name 174 | FROM 175 | sales as S 176 | LEFT JOIN menu as M ON S.product_id = M.product_id 177 | ORDER BY 178 | order_date 179 | ) 180 | SELECT 181 | customer_id, 182 | product_name, 183 | RANK() OVER (ORDER BY order_date) as rank_order 184 | FROM table_name ) as rank_product 185 | WHERE 186 | rank_order = 1 187 | GROUP BY 188 | customer_id, 189 | product_name 190 | ORDER BY 191 | customer_id; 192 | 193 | | customer_id | product_name | 194 | | ----------- | ------------ | 195 | | A | curry | 196 | | A | sushi | 197 | | B | curry | 198 | | C | ramen | 199 | 200 | ------------------------------------------------------ 201 | -- 4. What is the most purchased item on the menu and how many times was it purchased by all customers? 202 | 203 | SELECT 204 | S.product_id, 205 | M.product_name, 206 | COUNT(S.product_id) as total_order 207 | FROM 208 | sales S 209 | LEFT JOIN menu M 210 | ON S.product_id = M.product_id 211 | GROUP BY 212 | S.product_id, 213 | M.product_name 214 | ORDER BY 215 | total_order DESC 216 | LIMIT 1; 217 | 218 | | product_id | product_name | total_order | 219 | | ---------- | ------------ | ----------- | 220 | | 3 | ramen | 8 | 221 | 222 | -------------------------------------------------------- 223 | -- 5. Which item was the most popular for each customer? 224 | 225 | SELECT 226 | customer_id, 227 | string_agg( CAST(product_id AS CHAR), ', ') AS favorite_product 228 | FROM 229 | ( 230 | 231 | SELECT 232 | customer_id, 233 | product_id, 234 | product_name, 235 | total_order, 236 | rank 237 | FROM 238 | ( 239 | WITH table_name AS ( 240 | SELECT 241 | S.customer_id, 242 | S.product_id, 243 | M.product_name, 244 | COUNT(S.product_id) as total_order 245 | FROM 246 | sales S 247 | LEFT JOIN menu M ON S.product_id = M.product_id 248 | GROUP BY 249 | S.customer_id, 250 | S.product_id, 251 | M.product_name 252 | ) 253 | SELECT 254 | customer_id, 255 | product_id, 256 | product_name, 257 | total_order, 258 | RANK() OVER (PARTITION BY customer_id ORDER BY total_order DESC) as Rank 259 | FROM 260 | table_name ) as rank_order 261 | WHERE 262 | rank = 1) as ranking_table 263 | GROUP BY 264 | customer_id; 265 | 266 | | customer_id | favorite_product | 267 | | ----------- | ---------------- | 268 | | A | 3 | 269 | | B | 3, 1, 2 | 270 | | C | 3 | 271 | 272 | ------------------------------------------------------ 273 | -- 6. Which item was purchased first by the customer after they became a member? 274 | 275 | SELECT 276 | customer_id, 277 | product_id, 278 | product_name, 279 | order_date 280 | FROM 281 | ( 282 | WITH joined_table AS( 283 | SELECT 284 | S.customer_id, 285 | S.order_date, 286 | S.product_id, 287 | MU.product_name, 288 | MU.price, 289 | CASE 290 | WHEN (S.order_date >= MB.join_date) THEN 'Y' 291 | else 'N' 292 | END AS member 293 | FROM 294 | sales AS S 295 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 296 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 297 | ORDER BY 298 | customer_id, 299 | order_date 300 | ) 301 | SELECT 302 | customer_id, 303 | order_date, 304 | product_id, 305 | product_name, 306 | price, 307 | member, 308 | CASE 309 | WHEN member = 'Y' THEN rank() OVER ( 310 | PARTITION BY customer_id, 311 | member 312 | ORDER BY 313 | order_date 314 | ) 315 | ELSE NULL 316 | END as ranking 317 | FROM 318 | joined_table 319 | ) as ranking_table 320 | WHERE ranking = 1; 321 | 322 | | customer_id | product_id | product_name | order_date | 323 | | ----------- | ---------- | ------------ | ------------------------ | 324 | | A | 2 | curry | 2021-01-07T00:00:00.000Z | 325 | | B | 1 | sushi | 2021-01-11T00:00:00.000Z | 326 | 327 | ------------------------------------------------------ 328 | -- 7. Which item was purchased just before the customer became a member? 329 | 330 | SELECT 331 | customer_id, 332 | string_agg(product_name, ', ') AS favorite_product 333 | FROM( 334 | SELECT 335 | customer_id, 336 | join_date, 337 | order_date, 338 | product_id, 339 | product_name, 340 | price 341 | FROM 342 | ( 343 | WITH joined_table AS( 344 | SELECT 345 | S.customer_id, 346 | S.order_date, 347 | S.product_id, 348 | MU.product_name, 349 | MU.price, 350 | MB.join_date, 351 | CASE 352 | WHEN (S.order_date >= MB.join_date) THEN 'Y' 353 | else 'N' 354 | END AS member 355 | FROM 356 | sales AS S 357 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 358 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 359 | ORDER BY 360 | customer_id, 361 | order_date 362 | ) 363 | SELECT 364 | customer_id, 365 | join_date, 366 | order_date, 367 | product_id, 368 | product_name, 369 | price, 370 | member, 371 | CASE 372 | WHEN member = 'Y' THEN rank() OVER ( 373 | PARTITION BY customer_id, 374 | member 375 | ORDER BY 376 | order_date 377 | ) 378 | ELSE NULL 379 | END as ranking, 380 | CASE 381 | WHEN member = 'N' THEN rank() OVER ( 382 | PARTITION BY customer_id, 383 | member 384 | ORDER BY 385 | order_date DESC 386 | ) 387 | ELSE NULL 388 | END as inverse_ranking 389 | FROM 390 | joined_table 391 | ) as ranking_table 392 | WHERE 393 | join_date IS NOT NULL 394 | AND inverse_ranking = 1 395 | ) as ranking_table 396 | GROUP BY 397 | customer_id; 398 | 399 | | customer_id | favorite_product | 400 | | ----------- | ---------------- | 401 | | A | curry, sushi | 402 | | B | sushi | 403 | 404 | ------------------------------------------------------ 405 | -- 8) What is the total items and amount spent for each member before they became a member? 406 | 407 | SELECT 408 | customer_id, 409 | COUNT(order_date) as items, 410 | SUM(price) as price_paid 411 | FROM 412 | ( 413 | WITH joined_table AS( 414 | SELECT 415 | S.customer_id, 416 | S.order_date, 417 | S.product_id, 418 | MU.product_name, 419 | MU.price, 420 | MB.join_date, 421 | CASE 422 | WHEN (S.order_date >= MB.join_date) THEN 'Y' 423 | else 'N' 424 | END AS member 425 | FROM 426 | sales AS S 427 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 428 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 429 | ORDER BY 430 | customer_id, 431 | order_date 432 | ) 433 | SELECT 434 | customer_id, 435 | join_date, 436 | order_date, 437 | product_id, 438 | product_name, 439 | price, 440 | member, 441 | CASE 442 | WHEN member = 'Y' THEN rank() OVER ( 443 | PARTITION BY customer_id, 444 | member 445 | ORDER BY 446 | order_date 447 | ) 448 | ELSE NULL 449 | END as ranking, 450 | CASE 451 | WHEN member = 'N' THEN rank() OVER ( 452 | PARTITION BY customer_id, 453 | member 454 | ORDER BY 455 | order_date DESC 456 | ) 457 | ELSE NULL 458 | END as inverse_ranking 459 | FROM 460 | joined_table 461 | ) as ranking_table 462 | WHERE 463 | join_date IS NOT NULL 464 | AND member = 'N' 465 | GROUP BY 466 | customer_id; 467 | 468 | | customer_id | items | price_paid | 469 | | ----------- | ----- | ---------- | 470 | | B | 3 | 40 | 471 | | A | 2 | 25 | 472 | 473 | 474 | ------------------------------------------------------ 475 | -- 9. If each $1 spent equates to 10 points and sushi has a 2x points multiplier - how many points would each customer have? 476 | 477 | SELECT 478 | customer_id, 479 | SUM(CASE WHEN product_name = 'sushi' THEN price*20 ELSE price*10 END) as customer_points 480 | FROM 481 | ( 482 | WITH joined_table AS( 483 | SELECT 484 | S.customer_id, 485 | S.order_date, 486 | S.product_id, 487 | MU.product_name, 488 | MU.price, 489 | CASE WHEN (S.order_date >= MB.join_date) THEN 'Y' else 'N' END AS member 490 | FROM 491 | sales AS S 492 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 493 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 494 | ORDER BY customer_id, order_date 495 | ) 496 | SELECT 497 | customer_id, 498 | order_date, 499 | product_id, 500 | product_name, 501 | price, 502 | member, 503 | CASE WHEN member = 'Y' THEN rank() OVER (PARTITION BY customer_id, member ORDER BY order_date) ELSE NULL END as ranking 504 | FROM 505 | joined_table) as ranking_table 506 | WHERE 507 | member = 'Y' 508 | GROUP BY 509 | customer_id 510 | ORDER BY 511 | customer_id; 512 | 513 | | customer_id | customer_points | 514 | | ----------- | --------------- | 515 | | A | 510 | 516 | | B | 440 | 517 | 518 | ------------------------------------------------------ 519 | -- 10. In the first week after a customer joins the program (including their join date) they earn 2x points on all items, 520 | -- not just sushi - how many points do customer A and B have at the end of January? 521 | 522 | SELECT 523 | customer_id, 524 | SUM(CASE WHEN first_week ='Y' THEN price*20 525 | ELSE CASE WHEN product_name = 'sushi' THEN price*20 ELSE price*10 END END) AS customer_points 526 | FROM 527 | ( 528 | WITH joined_table AS( 529 | SELECT 530 | S.customer_id, 531 | MB.join_date, 532 | S.order_date, 533 | S.product_id, 534 | MU.product_name, 535 | MU.price, 536 | CASE WHEN (S.order_date >= MB.join_date) THEN 'Y' else 'N' END AS member, 537 | CASE WHEN (S.order_date - MB.join_date) BETWEEN 0 and 6 THEN 'Y' else 'N' END AS first_week 538 | FROM 539 | sales AS S 540 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 541 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 542 | ORDER BY customer_id, order_date 543 | ) 544 | SELECT 545 | customer_id, 546 | join_date, 547 | order_date, 548 | product_id, 549 | product_name, 550 | price, 551 | member, 552 | first_week, 553 | CASE WHEN member = 'Y' THEN rank() OVER (PARTITION BY customer_id, member ORDER BY order_date) ELSE NULL END as ranking 554 | FROM 555 | joined_table) as ranking_table 556 | WHERE 557 | member = 'Y' 558 | GROUP BY 559 | customer_id 560 | ORDER BY 561 | customer_id; 562 | 563 | | customer_id | customer_points | 564 | | ----------- | --------------- | 565 | | A | 1020 | 566 | | B | 440 | 567 | 568 | --- 569 | 570 | [View on DB Fiddle](https://www.db-fiddle.com/f/2rM8RAnq7h5LLDTzZiRWcd/18) 571 | -------------------------------------------------------------------------------- /8-weeks-SQL-Challenge/Week 2/1. SQL_Schema: -------------------------------------------------------------------------------- 1 | -- Data with Danny - 8 Week Challenge (Week 2) 2 | -- Case available at: https://8weeksqlchallenge.com/case-study-2/ 3 | 4 | -- **Schema (PostgreSQL v13)** 5 | 6 | DROP TABLE IF EXISTS runners; 7 | CREATE TABLE runners ( 8 | "runner_id" INTEGER, 9 | "registration_date" DATE 10 | ); 11 | INSERT INTO runners 12 | ("runner_id", "registration_date") 13 | VALUES 14 | (1, '2021-01-01'), 15 | (2, '2021-01-03'), 16 | (3, '2021-01-08'), 17 | (4, '2021-01-15'); 18 | 19 | 20 | DROP TABLE IF EXISTS customer_orders; 21 | CREATE TABLE customer_orders ( 22 | "order_id" INTEGER, 23 | "customer_id" INTEGER, 24 | "pizza_id" INTEGER, 25 | "exclusions" VARCHAR(4), 26 | "extras" VARCHAR(4), 27 | "order_time" TIMESTAMP 28 | ); 29 | 30 | INSERT INTO customer_orders 31 | ("order_id", "customer_id", "pizza_id", "exclusions", "extras", "order_time") 32 | VALUES 33 | ('1', '101', '1', '', '', '2020-01-01 18:05:02'), 34 | ('2', '101', '1', '', '', '2020-01-01 19:00:52'), 35 | ('3', '102', '1', '', '', '2020-01-02 12:51:23'), 36 | ('3', '102', '2', '', NULL, '2020-01-02 12:51:23'), 37 | ('4', '103', '1', '4', '', '2020-01-04 13:23:46'), 38 | ('4', '103', '1', '4', '', '2020-01-04 13:23:46'), 39 | ('4', '103', '2', '4', '', '2020-01-04 13:23:46'), 40 | ('5', '104', '1', 'null', '1', '2020-01-08 21:00:29'), 41 | ('6', '101', '2', 'null', 'null', '2020-01-08 21:03:13'), 42 | ('7', '105', '2', 'null', '1', '2020-01-08 21:20:29'), 43 | ('8', '102', '1', 'null', 'null', '2020-01-09 23:54:33'), 44 | ('9', '103', '1', '4', '1, 5', '2020-01-10 11:22:59'), 45 | ('10', '104', '1', 'null', 'null', '2020-01-11 18:34:49'), 46 | ('10', '104', '1', '2, 6', '1, 4', '2020-01-11 18:34:49'); 47 | 48 | 49 | DROP TABLE IF EXISTS runner_orders; 50 | CREATE TABLE runner_orders ( 51 | "order_id" INTEGER, 52 | "runner_id" INTEGER, 53 | "pickup_time" VARCHAR(19), 54 | "distance" VARCHAR(7), 55 | "duration" VARCHAR(10), 56 | "cancellation" VARCHAR(23) 57 | ); 58 | 59 | INSERT INTO runner_orders 60 | ("order_id", "runner_id", "pickup_time", "distance", "duration", "cancellation") 61 | VALUES 62 | ('1', '1', '2020-01-01 18:15:34', '20km', '32 minutes', ''), 63 | ('2', '1', '2020-01-01 19:10:54', '20km', '27 minutes', ''), 64 | ('3', '1', '2020-01-02 00:12:37', '13.4km', '20 mins', NULL), 65 | ('4', '2', '2020-01-04 13:53:03', '23.4', '40', NULL), 66 | ('5', '3', '2020-01-08 21:10:57', '10', '15', NULL), 67 | ('6', '3', 'null', 'null', 'null', 'Restaurant Cancellation'), 68 | ('7', '2', '2020-01-08 21:30:45', '25km', '25mins', 'null'), 69 | ('8', '2', '2020-01-10 00:15:02', '23.4 km', '15 minute', 'null'), 70 | ('9', '2', 'null', 'null', 'null', 'Customer Cancellation'), 71 | ('10', '1', '2020-01-11 18:50:20', '10km', '10minutes', 'null'); 72 | 73 | 74 | DROP TABLE IF EXISTS pizza_names; 75 | CREATE TABLE pizza_names ( 76 | "pizza_id" INTEGER, 77 | "pizza_name" TEXT 78 | ); 79 | INSERT INTO pizza_names 80 | ("pizza_id", "pizza_name") 81 | VALUES 82 | (1, 'Meatlovers'), 83 | (2, 'Vegetarian'); 84 | 85 | 86 | DROP TABLE IF EXISTS pizza_recipes; 87 | CREATE TABLE pizza_recipes ( 88 | "pizza_id" INTEGER, 89 | "toppings" TEXT 90 | ); 91 | INSERT INTO pizza_recipes 92 | ("pizza_id", "toppings") 93 | VALUES 94 | (1, '1, 2, 3, 4, 5, 6, 8, 10'), 95 | (2, '4, 6, 7, 9, 11, 12'); 96 | 97 | 98 | DROP TABLE IF EXISTS pizza_toppings; 99 | CREATE TABLE pizza_toppings ( 100 | "topping_id" INTEGER, 101 | "topping_name" TEXT 102 | ); 103 | INSERT INTO pizza_toppings 104 | ("topping_id", "topping_name") 105 | VALUES 106 | (1, 'Bacon'), 107 | (2, 'BBQ Sauce'), 108 | (3, 'Beef'), 109 | (4, 'Cheese'), 110 | (5, 'Chicken'), 111 | (6, 'Mushrooms'), 112 | (7, 'Onions'), 113 | (8, 'Pepperoni'), 114 | (9, 'Peppers'), 115 | (10, 'Salami'), 116 | (11, 'Tomatoes'), 117 | (12, 'Tomato Sauce'); 118 | -------------------------------------------------------------------------------- /8-weeks-SQL-Challenge/Week 2/2. Solution_Pizza_Metrics: -------------------------------------------------------------------------------- 1 | -- Data with Danny - 8 Week Challenge (Week 2) 2 | -- https://8weeksqlchallenge.com/case-study-2/ 3 | 4 | -- Done with PostgreSQL 5 | 6 | --PART 1: PIZZA METRICS ! 7 | 8 | --1) How many pizzas were ordered? 9 | --2) How many unique customer orders were made? 10 | --3) How many successful orders were delivered by each runner? 11 | --4) How many of each type of pizza was delivered? 12 | --5) How many Vegetarian and Meatlovers were ordered by each customer? 13 | --6) What was the maximum number of pizzas delivered in a single order? 14 | --7) For each customer, how many delivered pizzas had at least 1 change and how many had no changes? 15 | --8) How many pizzas were delivered that had both exclusions and extras? 16 | --9) What was the total volume of pizzas ordered for each hour of the day? 17 | --10) What was the volume of orders for each day of the week? 18 | 19 | -------------------------------------------------------------------------------------------------------------------------------------------------------- 20 | -- BEFORE ANSWERING THE QUESTIONS, LET'S BEGIN BY FIXING THE TABLES 21 | 22 | 23 | DROP TABLE IF EXISTS customer_orders_cleaned; 24 | CREATE TEMP TABLE customer_orders_cleaned AS WITH first_layer AS ( 25 | SELECT 26 | order_id, 27 | customer_id, 28 | pizza_id, 29 | CASE 30 | WHEN exclusions = '' THEN NULL 31 | WHEN exclusions = 'null' THEN NULL 32 | ELSE exclusions 33 | END as exclusions, 34 | CASE 35 | WHEN extras = '' THEN NULL 36 | WHEN extras = 'null' THEN NULL 37 | ELSE extras 38 | END as extras, 39 | order_time 40 | FROM 41 | customer_orders 42 | ) 43 | SELECT 44 | ROW_NUMBER() OVER ( -- We are adding a row_number rank to deal with orders having multiple times the same pizza in it 45 | ORDER BY 46 | order_id, 47 | pizza_id 48 | ) AS row_number_order, 49 | order_id, 50 | customer_id, 51 | pizza_id, 52 | exclusions, 53 | extras, 54 | order_time 55 | FROM 56 | first_layer; 57 | 58 | --- 59 | 60 | 61 | DROP TABLE IF EXISTS runner_orders_cleaned; 62 | CREATE TEMP TABLE runner_orders_cleaned AS WITH first_layer AS ( 63 | SELECT 64 | order_id, 65 | runner_id, 66 | CAST( 67 | CASE 68 | WHEN pickup_time = 'null' THEN NULL 69 | ELSE pickup_time 70 | END AS timestamp 71 | ) AS pickup_time, 72 | CASE 73 | WHEN distance = '' THEN NULL 74 | WHEN distance = 'null' THEN NULL 75 | ELSE distance 76 | END as distance, 77 | CASE 78 | WHEN duration = '' THEN NULL 79 | WHEN duration = 'null' THEN NULL 80 | ELSE duration 81 | END as duration, 82 | CASE 83 | WHEN cancellation = '' THEN NULL 84 | WHEN cancellation = 'null' THEN NULL 85 | ELSE cancellation 86 | END as cancellation 87 | FROM 88 | runner_orders 89 | ) 90 | SELECT 91 | order_id, 92 | runner_id, 93 | CASE WHEN order_id = '3' THEN (pickup_time + INTERVAL '13 hour') ELSE pickup_time END AS pickup_time, 94 | CAST( regexp_replace(distance, '[a-z]+', '' ) AS DECIMAL(5,2) ) AS distance, 95 | CAST( regexp_replace(duration, '[a-z]+', '' ) AS INT ) AS duration, 96 | cancellation 97 | FROM 98 | first_layer; 99 | 100 | ------------------------------------------------------ 101 | --1) How many pizzas were ordered? 102 | 103 | SELECT 104 | COUNT(pizza_id) AS number_of_pizza_ordered 105 | FROM 106 | customer_orders_cleaned; 107 | 108 | | number_of_pizza_ordered | 109 | | ----------------------- | 110 | | 14 | 111 | 112 | ------------------------------------------------------ 113 | --2) How many unique customer orders were made? 114 | 115 | SELECT 116 | COUNT(DISTINCT order_id) AS distinct_orders 117 | FROM 118 | customer_orders_cleaned; 119 | 120 | | distinct_orders | 121 | | --------------- | 122 | | 10 | 123 | 124 | ------------------------------------------------------ 125 | --3) How many successful orders were delivered by each runner? 126 | 127 | SELECT 128 | COUNT(order_id) AS distinct_orders 129 | FROM 130 | runner_orders_cleaned 131 | WHERE 132 | cancellation IS NULL; 133 | 134 | | distinct_orders | 135 | | --------------- | 136 | | 8 | 137 | 138 | ------------------------------------------------------ 139 | --4) How many of each type of pizza was delivered? 140 | 141 | SELECT 142 | C.pizza_id, 143 | COUNT(C.pizza_id) as pizza_delivered 144 | FROM 145 | customer_orders_cleaned AS C 146 | LEFT JOIN runner_orders_cleaned AS R ON C.order_id = R.order_id 147 | WHERE 148 | R.cancellation IS NULL 149 | GROUP BY 150 | pizza_id; 151 | 152 | | pizza_id | pizza_delivered | 153 | | -------- | --------------- | 154 | | 1 | 9 | 155 | | 2 | 3 | 156 | 157 | ------------------------------------------------------ 158 | --5) How many Vegetarian and Meatlovers were ordered by each customer? 159 | 160 | SELECT 161 | customer_id, 162 | SUM(CASE WHEN pizza_id = 1 THEN 1 ELSE 0 END) as meatlovers, 163 | SUM(CASE WHEN pizza_id = 2 THEN 1 ELSE 0 END) as vegetarians 164 | FROM 165 | customer_orders_cleaned 166 | GROUP BY 167 | customer_id 168 | ORDER BY 169 | customer_id; 170 | 171 | | customer_id | meatlovers | vegetarians | 172 | | ----------- | ---------- | ----------- | 173 | | 101 | 2 | 1 | 174 | | 102 | 2 | 1 | 175 | | 103 | 3 | 1 | 176 | | 104 | 3 | 0 | 177 | | 105 | 0 | 1 | 178 | 179 | ------------------------------------------------------ 180 | --6) What was the maximum number of pizzas delivered in a single order? 181 | 182 | SELECT 183 | order_id, 184 | COUNT(pizza_id) as pizzas_delivered 185 | FROM 186 | customer_orders_cleaned 187 | GROUP BY 188 | order_id 189 | ORDER BY 190 | pizzas_delivered DESC; 191 | 192 | | order_id | pizzas_delivered | 193 | | -------- | ---------------- | 194 | | 4 | 3 | 195 | | 10 | 2 | 196 | | 3 | 2 | 197 | | 2 | 1 | 198 | | 7 | 1 | 199 | | 1 | 1 | 200 | | 9 | 1 | 201 | | 8 | 1 | 202 | | 5 | 1 | 203 | | 6 | 1 | 204 | 205 | ------------------------------------------------------ 206 | --7) For each customer, how many delivered pizzas had at least 1 change and how many had no changes? 207 | 208 | SELECT 209 | customer_id, 210 | SUM(CASE WHEN (exclusions IS NOT NULL OR extras IS NOT NULL) THEN 1 ELSE 0 END) as changes_performed, 211 | SUM(CASE WHEN (exclusions IS NULL AND extras IS NULL) THEN 1 ELSE 0 END) as no_changes 212 | FROM 213 | customer_orders_cleaned 214 | GROUP BY 215 | customer_id 216 | ORDER BY 217 | customer_id; 218 | 219 | | customer_id | changes_performed | no_changes | 220 | | ----------- | ----------------- | ---------- | 221 | | 101 | 0 | 3 | 222 | | 102 | 0 | 3 | 223 | | 103 | 4 | 0 | 224 | | 104 | 2 | 1 | 225 | | 105 | 1 | 0 | 226 | 227 | ------------------------------------------------------ 228 | --8) How many pizzas were delivered that had both exclusions and extras? 229 | 230 | SELECT 231 | SUM(CASE WHEN (exclusions IS NOT NULL AND extras IS NOT NULL) THEN 1 ELSE 0 END) as exclusions_and_extra 232 | FROM 233 | customer_orders_cleaned; 234 | 235 | | exclusions_and_extra | 236 | | -------------------- | 237 | | 2 | 238 | 239 | ------------------------------------------------------ 240 | --9) What was the total volume of pizzas ordered for each hour of the day? 241 | 242 | SELECT 243 | extract(hour from order_time) AS order_hour, 244 | COUNT(extract(hour from order_time)) AS count_pizza_ordered, 245 | ROUND( 100 * COUNT(extract(hour from order_time))/SUM(COUNT(*)) OVER (),2) AS volume_pizza_ordered 246 | FROM 247 | customer_orders_cleaned 248 | GROUP BY 249 | order_hour 250 | ORDER BY 251 | order_hour; 252 | 253 | | order_hour | count_pizza_ordered | volume_pizza_ordered | 254 | | ---------- | ------------------- | -------------------- | 255 | | 11 | 1 | 7.14 | 256 | | 12 | 2 | 14.29 | 257 | | 13 | 3 | 21.43 | 258 | | 18 | 3 | 21.43 | 259 | | 19 | 1 | 7.14 | 260 | | 21 | 3 | 21.43 | 261 | | 23 | 1 | 7.14 | 262 | 263 | ------------------------------------------------------ 264 | --10) What was the volume of orders for each day of the week? 265 | 266 | SELECT 267 | to_char(order_time, 'Day') AS day_ordered, 268 | COUNT(to_char(order_time, 'Day')) AS count_pizza_ordered, 269 | ROUND( 100 * COUNT(to_char(order_time, 'Day'))/SUM(COUNT(*)) OVER (),2) AS volume_pizza_ordered 270 | FROM 271 | customer_orders_cleaned 272 | GROUP BY 273 | day_ordered 274 | ORDER BY 275 | day_ordered; 276 | 277 | | day_ordered | count_pizza_ordered | volume_pizza_ordered | 278 | | ----------- | ------------------- | -------------------- | 279 | | Friday | 1 | 7.14 | 280 | | Saturday | 5 | 35.71 | 281 | | Thursday | 3 | 21.43 | 282 | | Wednesday | 5 | 35.71 | 283 | 284 | ------------------------------------------------------ 285 | 286 | [View on DB Fiddle](https://www.db-fiddle.com/f/7VcQKQwsS3CTkGRFG7vu98/4) 287 | -------------------------------------------------------------------------------- /8-weeks-SQL-Challenge/Week 2/3. Solution_Runner_and_Customer_Experience: -------------------------------------------------------------------------------- 1 | -- Data with Danny - 8 Week Challenge (Week 2) 2 | -- https://8weeksqlchallenge.com/case-study-2/ 3 | 4 | -- Done with PostgreSQL 5 | 6 | --PART 2: Runner and Customer Experience! 7 | 8 | --1) How many runners signed up for each 1 week period? (i.e. week starts 2021-01-01) 9 | --2) What was the average time in minutes it took for each runner to arrive at the Pizza Runner HQ to pickup the order? 10 | --3) Is there any relationship between the number of pizzas and how long the order takes to prepare? 11 | --4) What was the average distance travelled for each customer? 12 | --5) What was the difference between the longest and shortest delivery times for all orders? 13 | --6) What was the average speed for each runner for each delivery and do you notice any trend for these values? 14 | --7) What is the successful delivery percentage for each runner? 15 | 16 | -------------------------------------------------------------------------------------------------------------------------------------------------------- 17 | --Previous tables which we will still use for this part: 18 | 19 | 20 | DROP TABLE IF EXISTS runner_orders_cleaned; 21 | CREATE TEMP TABLE runner_orders_cleaned AS WITH first_layer AS ( 22 | SELECT 23 | order_id, 24 | runner_id, 25 | CAST( 26 | CASE 27 | WHEN pickup_time = 'null' THEN NULL 28 | ELSE pickup_time 29 | END AS timestamp 30 | ) AS pickup_time, 31 | CASE 32 | WHEN distance = '' THEN NULL 33 | WHEN distance = 'null' THEN NULL 34 | ELSE distance 35 | END as distance, 36 | CASE 37 | WHEN duration = '' THEN NULL 38 | WHEN duration = 'null' THEN NULL 39 | ELSE duration 40 | END as duration, 41 | CASE 42 | WHEN cancellation = '' THEN NULL 43 | WHEN cancellation = 'null' THEN NULL 44 | ELSE cancellation 45 | END as cancellation 46 | FROM 47 | runner_orders 48 | ) 49 | SELECT 50 | order_id, 51 | runner_id, 52 | pickup_time, 53 | CAST( regexp_replace(distance, '[a-z]+', '' ) AS DECIMAL(5,2) ) AS distance, 54 | CAST( regexp_replace(duration, '[a-z]+', '' ) AS INT ) AS duration, 55 | cancellation 56 | FROM 57 | first_layer; 58 | 59 | --- 60 | 61 | DROP TABLE IF EXISTS customer_orders_cleaned; 62 | CREATE TEMP TABLE customer_orders_cleaned AS WITH first_layer AS ( 63 | SELECT 64 | order_id, 65 | customer_id, 66 | pizza_id, 67 | CASE 68 | WHEN exclusions = '' THEN NULL 69 | WHEN exclusions = 'null' THEN NULL 70 | ELSE exclusions 71 | END as exclusions, 72 | CASE 73 | WHEN extras = '' THEN NULL 74 | WHEN extras = 'null' THEN NULL 75 | ELSE extras 76 | END as extras, 77 | order_time 78 | FROM 79 | customer_orders 80 | ) 81 | SELECT 82 | ROW_NUMBER() OVER ( -- We are adding a row_number rank to deal with orders having multiple times the same pizza in it 83 | ORDER BY 84 | order_id, 85 | pizza_id 86 | ) AS row_number_order, 87 | order_id, 88 | customer_id, 89 | pizza_id, 90 | exclusions, 91 | extras, 92 | order_time 93 | FROM 94 | first_layer; 95 | 96 | 97 | 98 | --- 99 | -- New temp table for this part 100 | 101 | DROP TABLE IF EXISTS parties_experience; 102 | CREATE TEMP TABLE parties_experience AS 103 | SELECT 104 | C.order_id, 105 | C.customer_id, 106 | C.pizza_id, 107 | R.runner_id, 108 | R.distance, 109 | R.duration, 110 | C.order_time, 111 | R.pickup_time 112 | FROM 113 | customer_orders_cleaned AS C 114 | LEFT JOIN runner_orders_cleaned AS R ON C.order_id = R.order_id 115 | WHERE 116 | R.cancellation IS NULL 117 | ORDER BY 118 | order_id; 119 | 120 | ------------------------------------------------------ 121 | --1) How many runners signed up for each 1 week period? (i.e. week starts 2021-01-01) 122 | 123 | SELECT 124 | week_signed_up, 125 | COUNT(week_signed_up) as runners_signed_up 126 | FROM 127 | ( 128 | SELECT 129 | runner_id, 130 | CAST(to_char(registration_date, 'WW') AS NUMERIC) AS week_signed_up 131 | FROM 132 | runners) AS runner_sign_date 133 | GROUP BY 134 | week_signed_up 135 | ORDER BY 136 | week_signed_up; 137 | 138 | | week_signed_up | runners_signed_up | 139 | | -------------- | ----------------- | 140 | | 1 | 2 | 141 | | 2 | 1 | 142 | | 3 | 1 | 143 | 144 | ------------------------------------------------------ 145 | --2) What was the average time in minutes it took for each runner to arrive at the Pizza Runner HQ to pickup the order? 146 | 147 | SELECT 148 | runner_id, 149 | ROUND( 150 | CAST( 151 | AVG( 152 | ( 153 | DATE_PART('hour', pickup_time - order_time) * 60 + DATE_PART('minute', pickup_time - order_time) 154 | ) * 60 + DATE_PART('second', pickup_time - order_time) 155 | ) AS NUMERIC 156 | ), 157 | 2 158 | ) AS avg_delivery_time 159 | FROM 160 | parties_experience 161 | GROUP BY 162 | runner_id 163 | ORDER BY 164 | runner_id; 165 | 166 | | runner_id | avg_delivery_time | 167 | | --------- | ----------------- | 168 | | 1 | 940.67 | 169 | | 2 | 1423.20 | 170 | | 3 | 628.00 | 171 | 172 | ------------------------------------------------------ 173 | --3) Is there any relationship between the number of pizzas and how long the order takes to prepare? 174 | 175 | SELECT 176 | count_pizza_ordered, 177 | ROUND(AVG(avg_delivery_time),2) AS avg_preparation_time_seconds 178 | FROM 179 | ( 180 | SELECT 181 | order_id, 182 | COUNT(pizza_id) AS count_pizza_ordered, 183 | ROUND(CAST(AVG((DATE_PART('hour', pickup_time - order_time) * 60 184 | + DATE_PART('minute', pickup_time - order_time)) * 60 185 | + DATE_PART('second', pickup_time - order_time)) AS NUMERIC),2) AS avg_delivery_time 186 | FROM 187 | parties_experience 188 | GROUP BY 189 | order_id) AS order_metrics 190 | GROUP BY 191 | count_pizza_ordered 192 | ORDER BY 193 | count_pizza_ordered; 194 | 195 | | count_pizza_ordered | avg_preparation_time_seconds | 196 | | ------------------- | ---------------------------- | 197 | | 1 | 741.40 | 198 | | 2 | 1102.50 | 199 | | 3 | 1757.00 | 200 | 201 | 202 | -- The number of pizzas ordered seems to be correlated to the preparation time 203 | 204 | 205 | ------------------------------------------------------ 206 | --4) What was the average distance travelled for each customer? 207 | 208 | SELECT 209 | customer_id, 210 | ROUND(AVG(distance),2) 211 | FROM 212 | parties_experience 213 | GROUP BY 214 | customer_id 215 | ORDER BY 216 | customer_id; 217 | 218 | | customer_id | round | 219 | | ----------- | ----- | 220 | | 101 | 20.00 | 221 | | 102 | 16.73 | 222 | | 103 | 23.40 | 223 | | 104 | 10.00 | 224 | | 105 | 25.00 | 225 | 226 | ------------------------------------------------------ 227 | --5) What was the difference between the longest and shortest delivery times for all orders? 228 | 229 | SELECT 230 | max_duration - min_duration AS difference_delivery_time_seconds 231 | FROM 232 | ( 233 | SELECT 234 | MAX(duration) AS max_duration, 235 | MIN(duration) AS min_duration 236 | FROM 237 | parties_experience) as first_layer; 238 | 239 | | difference_delivery_time_seconds | 240 | | -------------------------------- | 241 | | 30 | 242 | 243 | ------------------------------------------------------ 244 | --6) What was the average speed for each runner for each delivery and do you notice any trend for these values? 245 | 246 | SELECT 247 | runner_id, 248 | order_id, 249 | ROUND( 250 | (distance::NUMERIC/(duration::NUMERIC/60)),2) AS speed, 251 | distance 252 | FROM 253 | parties_experience 254 | GROUP BY 255 | runner_id, 256 | order_id, 257 | speed, 258 | distance 259 | ORDER BY 260 | runner_id, order_id; 261 | 262 | | runner_id | order_id | speed | distance | 263 | | --------- | -------- | ----- | -------- | 264 | | 1 | 1 | 37.50 | 20.00 | 265 | | 1 | 2 | 44.44 | 20.00 | 266 | | 1 | 3 | 40.20 | 13.40 | 267 | | 1 | 10 | 60.00 | 10.00 | 268 | | 2 | 4 | 35.10 | 23.40 | 269 | | 2 | 7 | 60.00 | 25.00 | 270 | | 2 | 8 | 93.60 | 23.40 | 271 | | 3 | 5 | 40.00 | 10.00 | 272 | 273 | ------------------------------------------------------ 274 | --7) What is the successful delivery percentage for each runner? 275 | 276 | --UPDATE TEMP TABLE, this time taking in account the NULL values: 277 | DROP TABLE IF EXISTS parties_experience; 278 | CREATE TEMP TABLE parties_experience AS 279 | SELECT 280 | C.order_id, 281 | C.customer_id, 282 | C.pizza_id, 283 | R.runner_id, 284 | R.distance, 285 | R.duration, 286 | C.order_time, 287 | R.pickup_time, 288 | R.cancellation 289 | FROM 290 | customer_orders_cleaned AS C 291 | LEFT JOIN runner_orders_cleaned AS R ON C.order_id = R.order_id 292 | ORDER BY 293 | order_id; 294 | --- 295 | 296 | SELECT 297 | runner_id, 298 | ROUND( 299 | 100 * SUM(successful_orders::numeric) / COUNT(successful_orders::numeric),2) AS percentage_successful_delivery 300 | FROM 301 | (SELECT 302 | runner_id, 303 | order_id, 304 | CASE WHEN cancellation IS NOT NULL then 0 ELSE 1 END AS successful_orders 305 | FROM 306 | parties_experience 307 | GROUP BY 308 | runner_id, 309 | order_id, 310 | cancellation 311 | ORDER BY 312 | runner_id, order_id) as first_layer 313 | GROUP BY 314 | runner_id; 315 | 316 | | runner_id | percentage_successful_delivery | 317 | | --------- | ------------------------------ | 318 | | 1 | 100.00 | 319 | | 2 | 75.00 | 320 | | 3 | 50.00 | 321 | 322 | ------------------------------------------------------ 323 | 324 | [View on DB Fiddle](https://www.db-fiddle.com/f/7VcQKQwsS3CTkGRFG7vu98/4) 325 | -------------------------------------------------------------------------------- /8-weeks-SQL-Challenge/Week 2/4. Ingredient_Optimisation: -------------------------------------------------------------------------------- 1 | -- Data with Danny - 8 Week Challenge (Week 2) 2 | -- https://8weeksqlchallenge.com/case-study-2/ 3 | 4 | -- Done with PostgreSQL 5 | 6 | --PART 3: Ingredient Optimisation! 7 | 8 | --Questions: 9 | -- 1) What are the standard ingredients for each pizza? 10 | -- 2) What was the most commonly added extra? 11 | -- 3) What was the most common exclusion? 12 | -- 4) Generate an order item for each record in the customers_orders table in the format of one of the following: 13 | -- Meat Lovers 14 | -- Meat Lovers - Exclude Beef 15 | -- Meat Lovers - Extra Bacon 16 | -- Meat Lovers - Exclude Cheese, Bacon - Extra Mushroom, Peppers 17 | -- 5) Generate an alphabetically ordered comma separated ingredient list for each pizza order from the customer_orders table and add a 2x in front of any relevant ingredients 18 | -- For example: "Meat Lovers: 2xBacon, Beef, ... , Salami" 19 | -- 6) What is the total quantity of each ingredient used in all delivered pizzas sorted by most frequent first? 20 | 21 | -------------------------------------------------------------------------------------------------------------------------------------------------------- 22 | 23 | --Previous tables which we will still use for this part: 24 | 25 | DROP TABLE IF EXISTS customer_orders_cleaned; 26 | CREATE TEMP TABLE customer_orders_cleaned AS WITH first_layer AS ( 27 | SELECT 28 | order_id, 29 | customer_id, 30 | pizza_id, 31 | CASE 32 | WHEN exclusions = '' THEN NULL 33 | WHEN exclusions = 'null' THEN NULL 34 | ELSE exclusions 35 | END as exclusions, 36 | CASE 37 | WHEN extras = '' THEN NULL 38 | WHEN extras = 'null' THEN NULL 39 | ELSE extras 40 | END as extras, 41 | order_time 42 | FROM 43 | customer_orders 44 | ) 45 | SELECT 46 | ROW_NUMBER() OVER ( 47 | ORDER BY 48 | order_id, 49 | pizza_id 50 | ) AS row_number_order, 51 | order_id, 52 | customer_id, 53 | pizza_id, 54 | exclusions, 55 | extras, 56 | order_time 57 | FROM 58 | first_layer; 59 | 60 | --- 61 | 62 | 63 | DROP TABLE IF EXISTS runner_orders_cleaned; 64 | CREATE TEMP TABLE runner_orders_cleaned AS WITH first_layer AS ( 65 | SELECT 66 | order_id, 67 | runner_id, 68 | CAST( 69 | CASE 70 | WHEN pickup_time = 'null' THEN NULL 71 | ELSE pickup_time 72 | END AS timestamp 73 | ) AS pickup_time, 74 | CASE 75 | WHEN distance = '' THEN NULL 76 | WHEN distance = 'null' THEN NULL 77 | ELSE distance 78 | END as distance, 79 | CASE 80 | WHEN duration = '' THEN NULL 81 | WHEN duration = 'null' THEN NULL 82 | ELSE duration 83 | END as duration, 84 | CASE 85 | WHEN cancellation = '' THEN NULL 86 | WHEN cancellation = 'null' THEN NULL 87 | ELSE cancellation 88 | END as cancellation 89 | FROM 90 | runner_orders 91 | ) 92 | SELECT 93 | order_id, 94 | runner_id, 95 | CASE WHEN order_id = '3' THEN (pickup_time + INTERVAL '13 hour') ELSE pickup_time END AS pickup_time, 96 | CAST( regexp_replace(distance, '[a-z]+', '' ) AS DECIMAL(5,2) ) AS distance, 97 | CAST( regexp_replace(duration, '[a-z]+', '' ) AS INT ) AS duration, 98 | cancellation 99 | FROM 100 | first_layer; 101 | 102 | 103 | 104 | ------------------------------------------------------ 105 | -- 1) What are the standard ingredients for each pizza? 106 | 107 | WITH pizza_recipes_unstacked AS ( 108 | SELECT 109 | pizza_id, 110 | CAST( 111 | UNNEST( 112 | string_to_array(toppings, ', ') 113 | ) AS INT 114 | ) AS topping_id 115 | FROM 116 | pizza_recipes 117 | ) 118 | SELECT 119 | t1.pizza_id, 120 | t1.pizza_name, 121 | t2.topping_id, 122 | t3.topping_name 123 | FROM 124 | pizza_names t1 125 | JOIN pizza_recipes_unstacked t2 ON t1.pizza_id = t2.pizza_id 126 | JOIN pizza_toppings t3 ON t2.topping_id = t3.topping_id 127 | ORDER BY 128 | t1.pizza_id, 129 | t2.topping_id; 130 | 131 | | pizza_id | pizza_name | topping_id | topping_name | 132 | | -------- | ---------- | ---------- | ------------ | 133 | | 1 | Meatlovers | 1 | Bacon | 134 | | 1 | Meatlovers | 2 | BBQ Sauce | 135 | | 1 | Meatlovers | 3 | Beef | 136 | | 1 | Meatlovers | 4 | Cheese | 137 | | 1 | Meatlovers | 5 | Chicken | 138 | | 1 | Meatlovers | 6 | Mushrooms | 139 | | 1 | Meatlovers | 8 | Pepperoni | 140 | | 1 | Meatlovers | 10 | Salami | 141 | | 2 | Vegetarian | 4 | Cheese | 142 | | 2 | Vegetarian | 6 | Mushrooms | 143 | | 2 | Vegetarian | 7 | Onions | 144 | | 2 | Vegetarian | 9 | Peppers | 145 | 146 | ------------------------------------------------------ 147 | --2) What was the most commonly added extra? 148 | 149 | SELECT 150 | extras, 151 | topping_name, 152 | COUNT(extras) AS times_ordered 153 | FROM 154 | ( 155 | SELECT 156 | order_id, 157 | CAST( 158 | UNNEST(string_to_array(extras, ', ')) AS INT 159 | ) AS extras 160 | FROM 161 | customer_orders_cleaned 162 | ) AS extras_information 163 | JOIN pizza_toppings ON pizza_toppings.topping_id = extras_information.extras 164 | GROUP BY 165 | extras, 166 | topping_name 167 | ORDER BY 168 | times_ordered DESC; 169 | 170 | | extras | topping_name | times_ordered | 171 | | ------ | ------------ | ------------- | 172 | | 1 | Bacon | 4 | 173 | | 4 | Cheese | 1 | 174 | | 5 | Chicken | 1 | 175 | 176 | ------------------------------------------------------ 177 | -- 3) What was the most common exclusion? 178 | 179 | SELECT 180 | exclusions, 181 | topping_name, 182 | COUNT(exclusions) AS times_ordered 183 | FROM 184 | ( 185 | SELECT 186 | order_id, 187 | CAST( 188 | UNNEST(string_to_array(exclusions, ', ')) AS INT 189 | ) AS exclusions 190 | FROM 191 | customer_orders_cleaned 192 | ) AS exclusions_information 193 | JOIN pizza_toppings ON pizza_toppings.topping_id = exclusions_information.exclusions 194 | GROUP BY 195 | exclusions, 196 | topping_name 197 | ORDER BY 198 | times_ordered DESC; 199 | 200 | | exclusions | topping_name | times_ordered | 201 | | ---------- | ------------ | ------------- | 202 | | 4 | Cheese | 4 | 203 | | 2 | BBQ Sauce | 1 | 204 | | 6 | Mushrooms | 1 | 205 | 206 | ------------------------------------------------------ 207 | -- 4) Generate an order item for each record in the customers_orders table in the format of one of the following: 208 | -- Meat Lovers 209 | -- Meat Lovers - Exclude Beef 210 | -- Meat Lovers - Extra Bacon 211 | -- Meat Lovers - Exclude Cheese, Bacon - Extra Mushroom, Peppers 212 | 213 | DROP VIEW IF EXISTS extras_exclusions; 214 | CREATE VIEW extras_exclusions AS 215 | SELECT 216 | order_id, 217 | customers_info.pizza_id, 218 | pizza_names.pizza_name, 219 | exclusion_col1, 220 | top1.topping_name AS topping_name1, 221 | CASE 222 | WHEN exclusion_col2 = '' THEN NULL 223 | ELSE TRIM(exclusion_col2) :: INTEGER 224 | END as exclusion_col2, 225 | extras_col1, 226 | top2.topping_name AS topping_name3, 227 | CASE 228 | WHEN extras_col2 = '' THEN NULL 229 | ELSE TRIM(extras_col2) :: INTEGER 230 | END as extras_col2 231 | FROM 232 | ( 233 | SELECT 234 | order_id, 235 | pizza_id, 236 | split_part(exclusions, ',', 1) AS exclusion_col1, 237 | split_part(exclusions, ',', 2) AS exclusion_col2, 238 | split_part(extras, ',', 1) AS extras_col1, 239 | split_part(extras, ',', 2) AS extras_col2 240 | FROM 241 | customer_orders_cleaned 242 | ORDER BY 243 | order_id 244 | ) AS customers_info 245 | JOIN pizza_names ON customers_info.pizza_id = pizza_names.pizza_id 246 | LEFT JOIN pizza_toppings top1 ON customers_info.exclusion_col1 :: INT = top1.topping_id 247 | LEFT JOIN pizza_toppings top2 ON customers_info.extras_col1 :: INT = top2.topping_id; 248 | 249 | --- 250 | 251 | SELECT 252 | order_id, 253 | CONCAT(pizza_name, ' ', exclusions, ' ', extras) AS pizza_details 254 | FROM 255 | ( 256 | WITH tabular_modifications AS( 257 | SELECT 258 | order_id, 259 | pizza_id, 260 | pizza_name, 261 | exclusion_col1, 262 | topping_name1, 263 | exclusion_col2 :: INT, 264 | t2.topping_name AS topping_name2, 265 | extras_col1, 266 | topping_name3, 267 | extras_col2 :: INT, 268 | t3.topping_name AS topping_name4 269 | FROM 270 | extras_exclusions t1 271 | LEFT JOIN pizza_toppings t2 ON t1.exclusion_col2 = t2.topping_id 272 | LEFT JOIN pizza_toppings t3 ON t1.extras_col2 = t3.topping_id 273 | ) 274 | SELECT 275 | order_id, 276 | pizza_id, 277 | pizza_name, 278 | CASE 279 | WHEN exclusion_col1 IS NULL THEN CONCAT(topping_name1, ' ', topping_name2) 280 | WHEN exclusion_col2 IS NULL THEN CONCAT('- Exclude', ' ', topping_name1) 281 | ELSE CONCAT('- Exclude', ' ', topping_name1, ', ', topping_name2) 282 | END AS exclusions, 283 | CASE 284 | WHEN extras_col1 IS NULL THEN CONCAT(topping_name3, ' ', topping_name4) 285 | WHEN extras_col2 IS NULL THEN CONCAT('- Extra', ' ', topping_name3) 286 | ELSE CONCAT('- Extra', ' ', topping_name3, ', ', topping_name4) 287 | END AS extras 288 | FROM 289 | tabular_modifications 290 | ) AS Modified_concat 291 | ORDER BY 292 | order_id; 293 | 294 | | order_id | pizza_details | 295 | | -------- | --------------------------------------------------------------- | 296 | | 1 | Meatlovers | 297 | | 2 | Meatlovers | 298 | | 3 | Vegetarian | 299 | | 3 | Meatlovers | 300 | | 4 | Meatlovers - Exclude Cheese | 301 | | 4 | Meatlovers - Exclude Cheese | 302 | | 4 | Vegetarian - Exclude Cheese | 303 | | 5 | Meatlovers - Extra Bacon | 304 | | 6 | Vegetarian | 305 | | 7 | Vegetarian - Extra Bacon | 306 | | 8 | Meatlovers | 307 | | 9 | Meatlovers - Exclude Cheese - Extra Bacon, Chicken | 308 | | 10 | Meatlovers - Exclude BBQ Sauce, Mushrooms - Extra Bacon, Cheese | 309 | | 10 | Meatlovers | 310 | 311 | ------------------------------------------------------ 312 | -- 5) Generate an alphabetically ordered comma separated ingredient list for each pizza order from the customer_orders table and add a 2x in front of any relevant ingredients 313 | -- For example: "Meat Lovers: 2xBacon, Beef, ... , Salami" 314 | 315 | -- Step 1: create basic recipe table (recycling question 1) 316 | DROP TABLE IF EXISTS classical_recipe; 317 | CREATE TEMP TABLE classical_recipe AS 318 | WITH pizza_recipes_unstacked AS ( 319 | SELECT 320 | pizza_id, 321 | CAST( 322 | UNNEST( 323 | string_to_array(toppings, ', ') 324 | ) AS INT 325 | ) AS topping_id 326 | FROM 327 | pizza_recipes 328 | ) 329 | SELECT 330 | t4.row_number_order, 331 | t4.order_id, 332 | t4.customer_id, 333 | t1.pizza_id, 334 | t1.pizza_name, 335 | t2.topping_id, 336 | t3.topping_name 337 | FROM 338 | pizza_names t1 339 | JOIN pizza_recipes_unstacked t2 ON t1.pizza_id = t2.pizza_id 340 | JOIN pizza_toppings t3 ON t2.topping_id = t3.topping_id 341 | RIGHT JOIN customer_orders_cleaned t4 ON t1.pizza_id = t4.pizza_id; 342 | 343 | 344 | 345 | -- Step 2: unpivot extras and exclusions table into 2 separated table: 346 | 347 | DROP TABLE IF EXISTS orders_exclusions; 348 | CREATE TEMP TABLE orders_exclusions AS 349 | SELECT 350 | row_number_order, 351 | order_id, 352 | customer_id, 353 | customer_orders_cleaned.pizza_id, 354 | pizza_name, 355 | CAST(UNNEST(string_to_array(COALESCE(exclusions, '0'), ',')) AS INT) AS exclusions 356 | FROM 357 | customer_orders_cleaned 358 | JOIN pizza_names ON customer_orders_cleaned.pizza_id = pizza_names.pizza_id 359 | ORDER BY 360 | order_id; 361 | 362 | --- 363 | 364 | DROP TABLE IF EXISTS orders_extras; 365 | CREATE TEMP TABLE orders_extras AS 366 | SELECT 367 | row_number_order, 368 | order_id, 369 | customer_id, 370 | customer_orders_cleaned.pizza_id, 371 | pizza_name, 372 | CAST(UNNEST(string_to_array(COALESCE(extras, '0'), ',')) AS INT) AS extras 373 | FROM 374 | customer_orders_cleaned 375 | JOIN pizza_names ON customer_orders_cleaned.pizza_id = pizza_names.pizza_id 376 | ORDER BY 377 | order_id; 378 | 379 | 380 | --step 3: Join all the tables (Union extras, Except exclusions): 381 | 382 | DROP TABLE IF EXISTS pizzas_details; 383 | CREATE TEMP TABLE pizzas_details AS 384 | WITH first_layer AS (SELECT 385 | row_number_order, 386 | order_id, 387 | customer_id, 388 | pizza_id, 389 | pizza_name, 390 | topping_id 391 | FROM 392 | classical_recipe 393 | EXCEPT 394 | SELECT 395 | * 396 | FROM 397 | orders_exclusions 398 | UNION ALL 399 | SELECT 400 | * 401 | FROM 402 | orders_extras 403 | WHERE 404 | extras != 0) 405 | SELECT 406 | row_number_order, 407 | order_id, 408 | customer_id, 409 | pizza_id, 410 | pizza_name, 411 | first_layer.topping_id, 412 | topping_name 413 | FROM 414 | first_layer 415 | LEFT JOIN pizza_toppings ON first_layer.topping_id = pizza_toppings.topping_id 416 | ORDER BY 417 | row_number_order, 418 | order_id, 419 | pizza_id, 420 | topping_id; 421 | 422 | 423 | -- Step 4: let's now reshape the data to answer the question 424 | 425 | WITH counting_table AS( 426 | SELECT 427 | row_number_order, 428 | order_id, 429 | customer_id 430 | pizza_id, 431 | pizza_name, 432 | topping_id, 433 | topping_name, 434 | COUNT(topping_id) AS count_ingredient 435 | FROM 436 | pizzas_details 437 | GROUP BY 438 | row_number_order, 439 | order_id, 440 | customer_id, 441 | pizza_id, 442 | pizza_name, 443 | topping_id, 444 | topping_name) 445 | , text_table AS( 446 | SELECT 447 | row_number_order, 448 | order_id, 449 | pizza_id, 450 | pizza_name, 451 | topping_id, 452 | CASE WHEN count_ingredient = 1 THEN topping_name 453 | ELSE CONCAT(count_ingredient, 'x ',topping_name) END AS ingredient_count 454 | FROM 455 | counting_table) 456 | , group_text AS( 457 | SELECT 458 | row_number_order, 459 | order_id, 460 | pizza_id, 461 | pizza_name, 462 | STRING_AGG(ingredient_count, ', ') AS recipe 463 | FROM 464 | text_table 465 | GROUP BY 466 | row_number_order, 467 | order_id, 468 | pizza_id, 469 | pizza_name) 470 | SELECT 471 | row_number_order, 472 | order_id, 473 | CONCAT(pizza_name, ': ', recipe) 474 | FROM 475 | group_text 476 | ORDER BY 477 | row_number_order, order_id; 478 | 479 | | row_number_order | order_id | concat | 480 | | ---------------- | -------- | ------------------------------------------------------------------------------------ | 481 | | 1 | 1 | Meatlovers: Cheese, Chicken, Salami, Bacon, Beef, Pepperoni, Mushrooms, BBQ Sauce | 482 | | 2 | 2 | Meatlovers: Chicken, BBQ Sauce, Pepperoni, Salami, Cheese, Beef, Bacon, Mushrooms | 483 | | 3 | 3 | Meatlovers: Salami, Chicken, BBQ Sauce, Beef, Bacon, Mushrooms, Pepperoni, Cheese | 484 | | 4 | 3 | Vegetarian: Onions, Tomato Sauce, Mushrooms, Tomatoes, Peppers, Cheese | 485 | | 5 | 4 | Meatlovers: BBQ Sauce, Mushrooms, Beef, Salami, Pepperoni, Bacon, Chicken | 486 | | 6 | 4 | Meatlovers: Chicken, Mushrooms, Beef, Pepperoni, Bacon, BBQ Sauce, Salami | 487 | | 7 | 4 | Vegetarian: Tomato Sauce, Onions, Tomatoes, Peppers, Mushrooms | 488 | | 8 | 5 | Meatlovers: Cheese, Pepperoni, BBQ Sauce, 2x Bacon, Chicken, Salami, Mushrooms, Beef | 489 | | 9 | 6 | Vegetarian: Tomato Sauce, Onions, Mushrooms, Cheese, Tomatoes, Peppers | 490 | | 10 | 7 | Vegetarian: Mushrooms, Bacon, Tomato Sauce, Peppers, Onions, Tomatoes, Cheese | 491 | | 11 | 8 | Meatlovers: Pepperoni, Beef, Salami, Cheese, Bacon, Mushrooms, Chicken, BBQ Sauce | 492 | | 12 | 9 | Meatlovers: Beef, Pepperoni, Mushrooms, 2x Chicken, 2x Bacon, BBQ Sauce, Salami | 493 | | 13 | 10 | Meatlovers: Mushrooms, Chicken, Bacon, Salami, Cheese, BBQ Sauce, Beef, Pepperoni | 494 | | 14 | 10 | Meatlovers: 2x Bacon, Chicken, Beef, 2x Cheese, Salami, Pepperoni | 495 | 496 | ------------------------------------------------------ 497 | -- 6) What is the total quantity of each ingredient used in all delivered pizzas sorted by most frequent first? 498 | 499 | SELECT 500 | topping_id, 501 | topping_name, 502 | COUNT(topping_id) as time_used 503 | FROM 504 | pizzas_details 505 | GROUP BY 506 | topping_id, 507 | topping_name 508 | ORDER BY 509 | time_used DESC; 510 | 511 | | topping_id | topping_name | time_used | 512 | | ---------- | ------------ | --------- | 513 | | 1 | Bacon | 14 | 514 | | 6 | Mushrooms | 13 | 515 | | 5 | Chicken | 11 | 516 | | 4 | Cheese | 11 | 517 | | 8 | Pepperoni | 10 | 518 | | 10 | Salami | 10 | 519 | | 3 | Beef | 10 | 520 | | 2 | BBQ Sauce | 9 | 521 | | 9 | Peppers | 4 | 522 | | 7 | Onions | 4 | 523 | | 11 | Tomatoes | 4 | 524 | | 12 | Tomato Sauce | 4 | 525 | 526 | --- 527 | 528 | [View on DB Fiddle](https://www.db-fiddle.com/f/7VcQKQwsS3CTkGRFG7vu98/4) 529 | -------------------------------------------------------------------------------- /8-weeks-SQL-Challenge/Week 2/5. Pricing_And_Ratings.sql: -------------------------------------------------------------------------------- 1 | -- Data with Danny - 8 Week Challenge (Week 2) 2 | -- https://8weeksqlchallenge.com/case-study-2/ 3 | 4 | -- Done with PostgreSQL 5 | 6 | PART 4: Pricing and Ratings! 7 | 8 | 9 | --Questions: 10 | -- 1) If a Meat Lovers pizza costs $12 and Vegetarian costs $10 and there were no charges for changes - how much money has Pizza Runner 11 | -- made so far if there are no delivery fees? 12 | -- 2) What if there was an additional $1 charge for any pizza extras? 13 | -- - Add cheese is $1 extra 14 | -- 3) What if substitutes were allowed at no additional cost but any additional extras were charged at $1? 15 | -- - Exclude Cheese and add Bacon is free 16 | -- - Exclude Cheese but add bacon and beef costs $1 extra 17 | -- 4) What if meat substitutes and vegetable substitutes were allowed but any change outside were charged at $2 and $1 respectively? 18 | -- - Exclude Cheese and add Bacon is $2 extra 19 | -- - Exclude Beef and add mushroom is $1 extra 20 | -- - Exclude Beef and add Bacon is free 21 | -- - Exclude Beef and Mushroom, and add Bacon and Cheese is free 22 | -- 5)The Pizza Runner team now wants to add an additional ratings system that allows customers to rate their runner, 23 | -- how would you design an additional table for this new dataset - generate a schema for this new table and insert 24 | -- your own data for ratings for each successful customer order between 1 to 5. 25 | -- 6)Using your newly generated table - can you join all of the information together to form a table which has the following information for successful deliveries? 26 | -- - customer_id 27 | -- - order_id 28 | -- - runner_id 29 | -- - rating 30 | -- - order_time 31 | -- - pickup_time 32 | -- - Time between order and pickup 33 | -- - Delivery duration 34 | -- - Average speed 35 | -- - Total number of pizzas 36 | -- 7) If a Meat Lovers pizza was $12 and Vegetarian $10 fixed prices with no cost for extras and each runner is paid $0.30 per kilometre 37 | -- traveled - how much money does Pizza Runner have left over after these deliveries? 38 | -- 8) If 1 unit of each ingredient costs $0.50 - how much net revenue will Pizza Runner make if the costs from question 30 are used? 39 | 40 | 41 | -------------------------------------------------------------------------------------------------------------------------------------------------------- 42 | 43 | --Previous tables which we will still use for this part: 44 | 45 | 46 | DROP TABLE IF EXISTS customer_orders_cleaned; 47 | CREATE TEMP TABLE customer_orders_cleaned AS WITH first_layer AS ( 48 | SELECT 49 | order_id, 50 | customer_id, 51 | pizza_id, 52 | CASE 53 | WHEN exclusions = '' THEN NULL 54 | WHEN exclusions = 'null' THEN NULL 55 | ELSE exclusions 56 | END as exclusions, 57 | CASE 58 | WHEN extras = '' THEN NULL 59 | WHEN extras = 'null' THEN NULL 60 | ELSE extras 61 | END as extras, 62 | order_time 63 | FROM 64 | customer_orders 65 | ) 66 | SELECT 67 | ROW_NUMBER() OVER ( 68 | ORDER BY 69 | order_id, 70 | pizza_id 71 | ) AS row_number_order, 72 | order_id, 73 | customer_id, 74 | pizza_id, 75 | exclusions, 76 | extras, 77 | order_time 78 | FROM 79 | first_layer; 80 | 81 | --- 82 | 83 | 84 | DROP TABLE IF EXISTS runner_orders_cleaned; 85 | CREATE TEMP TABLE runner_orders_cleaned AS WITH first_layer AS ( 86 | SELECT 87 | order_id, 88 | runner_id, 89 | CAST( 90 | CASE 91 | WHEN pickup_time = 'null' THEN NULL 92 | ELSE pickup_time 93 | END AS timestamp 94 | ) AS pickup_time, 95 | CASE 96 | WHEN distance = '' THEN NULL 97 | WHEN distance = 'null' THEN NULL 98 | ELSE distance 99 | END as distance, 100 | CASE 101 | WHEN duration = '' THEN NULL 102 | WHEN duration = 'null' THEN NULL 103 | ELSE duration 104 | END as duration, 105 | CASE 106 | WHEN cancellation = '' THEN NULL 107 | WHEN cancellation = 'null' THEN NULL 108 | ELSE cancellation 109 | END as cancellation 110 | FROM 111 | runner_orders 112 | ) 113 | SELECT 114 | order_id, 115 | runner_id, 116 | CASE 117 | WHEN order_id = '3' THEN (pickup_time + INTERVAL '13 hour') 118 | ELSE pickup_time 119 | END AS pickup_time, 120 | CAST( 121 | regexp_replace(distance, '[a-z]+', '') AS DECIMAL(5, 2) 122 | ) AS distance, 123 | CAST(regexp_replace(duration, '[a-z]+', '') AS INT) AS duration, 124 | cancellation 125 | FROM 126 | first_layer; 127 | 128 | 129 | ------------------------------------------------------ 130 | -- 1) If a Meat Lovers pizza costs $12 and Vegetarian costs $10 and there were no charges for changes - how much money has Pizza Runner 131 | -- made so far if there are no delivery fees? 132 | 133 | 134 | --Let's create a temp table to make this more organized and get used to the syntax. I do not append those information to existing tables as it would require discussion 135 | -- with the person managing the database (in a real situation). I'll use another method. 136 | 137 | 138 | DROP TABLE IF EXISTS pizza_prices; 139 | CREATE TEMP TABLE pizza_prices ( 140 | "pizza_id" INTEGER, 141 | "price" INTEGER 142 | ); 143 | INSERT INTO 144 | pizza_prices ("pizza_id", "price") 145 | VALUES 146 | (1, 12), 147 | (2, 10); 148 | 149 | --- 150 | 151 | WITH profit_table AS ( 152 | SELECT 153 | C.pizza_id, 154 | COUNT(C.pizza_id) * price as pizza_revenues 155 | FROM 156 | customer_orders_cleaned AS C 157 | LEFT JOIN runner_orders_cleaned AS R ON C.order_id = R.order_id 158 | LEFT JOIN pizza_prices AS P ON C.pizza_id = P.pizza_id 159 | WHERE 160 | R.cancellation IS NULL 161 | GROUP BY 162 | C.pizza_id, 163 | price 164 | ) 165 | SELECT 166 | SUM(pizza_revenues) AS total_revenue 167 | FROM 168 | profit_table; 169 | 170 | | total_revenue | 171 | | ------------- | 172 | | 138 | 173 | 174 | 175 | 176 | ------------------------------------------------------ 177 | -- 2) What if there was an additional $1 charge for any pizza extras? 178 | -- - Add cheese is $1 extra 179 | 180 | -- let's recycle last part queries: 181 | 182 | DROP TABLE IF EXISTS orders_extras; 183 | CREATE TEMP TABLE orders_extras AS 184 | SELECT 185 | row_number_order, 186 | order_id, 187 | customer_id, 188 | customer_orders_cleaned.pizza_id, 189 | pizza_name, 190 | CAST( 191 | UNNEST(string_to_array(COALESCE(extras, '0'), ',')) AS INT 192 | ) AS extras 193 | FROM 194 | customer_orders_cleaned 195 | JOIN pizza_names ON customer_orders_cleaned.pizza_id = pizza_names.pizza_id 196 | ORDER BY 197 | order_id; 198 | 199 | 200 | WITH segmented_revenues AS ( 201 | SELECT 202 | table1.pizza_id, 203 | table1.pizza_revenues, 204 | table2.extras_revenues, 205 | (table1.pizza_revenues + table2.extras_revenues) AS total_revenues 206 | FROM 207 | ( 208 | SELECT 209 | C.pizza_id, 210 | COUNT(C.pizza_id) * price as pizza_revenues 211 | FROM 212 | customer_orders_cleaned AS C 213 | LEFT JOIN runner_orders_cleaned AS R ON C.order_id = R.order_id 214 | LEFT JOIN pizza_prices AS P ON C.pizza_id = P.pizza_id 215 | WHERE 216 | R.cancellation IS NULL 217 | GROUP BY 218 | C.pizza_id, 219 | price 220 | ) AS table1 221 | LEFT JOIN ( 222 | SELECT 223 | t1.pizza_id, 224 | SUM( 225 | CASE 226 | WHEN t1.extras > 0 THEN 1 227 | ELSE 0 228 | END 229 | ) AS extras_revenues 230 | FROM 231 | orders_extras t1 232 | LEFT JOIN pizza_prices t2 ON t1.pizza_id = t2.pizza_id 233 | LEFT JOIN runner_orders_cleaned t3 ON t1.order_id = t3.order_id 234 | WHERE 235 | t3.cancellation IS NULL 236 | GROUP BY 237 | t1.pizza_id 238 | ) AS table2 ON table1.pizza_id = table2.pizza_id 239 | ) 240 | SELECT 241 | SUM(total_revenues) AS total_revenues 242 | FROM 243 | segmented_revenues; 244 | 245 | | total_revenues | 246 | | -------------- | 247 | | 142 | 248 | 249 | 250 | 251 | 252 | ------------------------------------------------------ 253 | -- 3) What if substitutes were allowed at no additional cost but any additional extras were charged at $1? 254 | -- - Exclude Cheese and add Bacon is free 255 | -- - Exclude Cheese but add bacon and beef costs $1 extra 256 | 257 | 258 | -- Step 1: create an unstacked table with the extras and exceptions 259 | DROP TABLE IF EXISTS exclusions_extras_unstacked; 260 | CREATE TEMP TABLE exclusions_extras_unstacked AS 261 | SELECT 262 | row_number_order, 263 | order_id, 264 | customer_id, 265 | customer_orders_cleaned.pizza_id, 266 | pizza_name, 267 | CAST( 268 | UNNEST(string_to_array(COALESCE(exclusions, '0'), ',')) AS INT 269 | ) AS exclusions, 270 | CAST( 271 | UNNEST(string_to_array(COALESCE(extras, '0'), ',')) AS INT 272 | ) AS extras 273 | FROM 274 | customer_orders_cleaned 275 | JOIN pizza_names ON customer_orders_cleaned.pizza_id = pizza_names.pizza_id 276 | ORDER BY 277 | order_id; 278 | 279 | --Step 2: create a balance to see if we had more extras than exclusions 280 | WITH order_layer AS ( 281 | SELECT 282 | row_number_order, 283 | order_id, 284 | pizza_id, 285 | SUM( 286 | CASE 287 | WHEN extras > 0 THEN 1 288 | ELSE 0 289 | END 290 | ) - SUM( 291 | CASE 292 | WHEN exclusions > 0 THEN 1 293 | ELSE 0 294 | END 295 | ) AS substitutes_cost 296 | FROM 297 | exclusions_extras_unstacked 298 | GROUP BY 299 | row_number_order, 300 | order_id, 301 | pizza_id 302 | ), 303 | pizza_layer AS( 304 | SELECT 305 | row_number_order, 306 | order_id, 307 | pizza_id, 308 | CASE 309 | WHEN substitutes_cost < 0 THEN 0 310 | ELSE substitutes_cost 311 | END AS substitutes_cost 312 | FROM 313 | order_layer 314 | ) 315 | SELECT 316 | pizza_id, 317 | SUM(substitutes_cost) AS substitutes_cost 318 | FROM 319 | pizza_layer 320 | GROUP BY 321 | pizza_id; 322 | 323 | | pizza_id | substitutes_cost | 324 | | -------- | ---------------- | 325 | | 2 | 1 | 326 | | 1 | 2 | 327 | 328 | --Step 3: Change the LEFT JOIN in our last question query with the one created in step 2. 329 | WITH segmented_revenues AS ( 330 | SELECT 331 | table1.pizza_id, 332 | table1.pizza_revenues, 333 | table2.substitutes_cost, 334 | (table1.pizza_revenues + table2.substitutes_cost) AS total_revenues 335 | FROM 336 | ( 337 | SELECT 338 | C.pizza_id, 339 | COUNT(C.pizza_id) * price as pizza_revenues 340 | FROM 341 | customer_orders_cleaned AS C 342 | LEFT JOIN runner_orders_cleaned AS R ON C.order_id = R.order_id 343 | LEFT JOIN pizza_prices AS P ON C.pizza_id = P.pizza_id 344 | WHERE 345 | R.cancellation IS NULL 346 | GROUP BY 347 | C.pizza_id, 348 | price 349 | ) AS table1 350 | LEFT JOIN ( 351 | WITH order_layer AS ( 352 | SELECT 353 | row_number_order, 354 | order_id, 355 | pizza_id, 356 | SUM( 357 | CASE 358 | WHEN extras > 0 THEN 1 359 | ELSE 0 360 | END 361 | ) - SUM( 362 | CASE 363 | WHEN exclusions > 0 THEN 1 364 | ELSE 0 365 | END 366 | ) AS substitutes_cost 367 | FROM 368 | exclusions_extras_unstacked 369 | GROUP BY 370 | row_number_order, 371 | order_id, 372 | pizza_id 373 | ), 374 | pizza_layer AS( 375 | SELECT 376 | row_number_order, 377 | order_id, 378 | pizza_id, 379 | CASE 380 | WHEN substitutes_cost < 0 THEN 0 381 | ELSE substitutes_cost 382 | END AS substitutes_cost 383 | FROM 384 | order_layer 385 | ) 386 | SELECT 387 | pizza_id, 388 | SUM(substitutes_cost) AS substitutes_cost 389 | FROM 390 | pizza_layer 391 | GROUP BY 392 | pizza_id 393 | ) AS table2 ON table1.pizza_id = table2.pizza_id 394 | ) 395 | SELECT 396 | SUM(total_revenues) AS total_revenues 397 | FROM 398 | segmented_revenues; 399 | 400 | | total_revenues | 401 | | -------------- | 402 | | 141 | 403 | 404 | 405 | 406 | ------------------------------------------------------ 407 | -- 4) What if meat substitutes and vegetable substitutes were allowed but any change outside were charged at $2 and $1 respectively? 408 | -- - Exclude Cheese and add Bacon is $2 extra 409 | -- - Exclude Beef and add mushroom is $1 extra 410 | -- - Exclude Beef and add Bacon is free 411 | -- - Exclude Beef and Mushroom, and add Bacon and Cheese is free 412 | 413 | -- Table 2: Just as before, we will not modify existing tables. 414 | 415 | DROP TABLE IF EXISTS modification_prices; 416 | CREATE TEMP TABLE modification_prices ( 417 | "topping_id" INTEGER, 418 | "topping_name" TEXT, 419 | "type" INTEGER, 420 | "type_name" TEXT, 421 | "modification_price" INTEGER 422 | ); 423 | INSERT INTO 424 | modification_prices ( 425 | "topping_id", 426 | "topping_name", 427 | "type", 428 | "type_name", 429 | "modification_price" 430 | ) 431 | VALUES 432 | ('1', 'Bacon', '1', 'Vegetable', '2'), 433 | ('2', 'BBQ Sauce', '0', 'Sauce', '0'), 434 | ('3', 'Beef', '1', 'Meat', '2'), 435 | ('4', 'Cheese', '2', 'Vegetable', '1'), 436 | ('5', 'Chicken', '1', 'Meat', '2'), 437 | ('6', 'Mushrooms', '2', 'Vegetable', '1'), 438 | ('7', 'Onions', '2', 'Vegetable', '1'), 439 | ('8', 'Pepperoni', '1', 'Meat', '2'), 440 | ('9', 'Peppers', '2', 'Vegetable', '1'), 441 | ('10', 'Salami', '1', 'Meat', '2'), 442 | ('11', 'Tomatoes', '2', 'Vegetable', '1'), 443 | ('12', 'Tomato Sauce', '0', 'Sauce', '0'); 444 | 445 | 446 | --Step 2: compute the fees using the table previously created 447 | WITH unstacking AS( 448 | SELECT 449 | t1.row_number_order, 450 | t1.order_id, 451 | t1.pizza_id, 452 | t1.exclusions, 453 | t1.extras, 454 | t2.type AS exclusion_type, 455 | t3.type AS extras_type, 456 | t3.modification_price AS extras_price 457 | FROM 458 | exclusions_extras_unstacked t1 459 | LEFT JOIN modification_prices t2 ON t1.exclusions = t2.topping_id 460 | LEFT JOIN modification_prices t3 ON t1.extras = t3.topping_id 461 | ORDER BY 462 | order_id 463 | ), 464 | condition_type AS( 465 | SELECT 466 | row_number_order, 467 | order_id, 468 | pizza_id, 469 | extras_price, 470 | CASE 471 | WHEN exclusion_type = 1 THEN 1 472 | ELSE 0 473 | END AS exclusion_type1, 474 | CASE 475 | WHEN exclusion_type = 2 THEN 1 476 | ELSE 0 477 | END AS exclusion_type2, 478 | CASE 479 | WHEN extras_type = 1 THEN 1 480 | ELSE 0 481 | END AS extras_type1, 482 | CASE 483 | WHEN extras_type = 2 THEN 1 484 | ELSE 0 485 | END AS extras_type2 486 | FROM 487 | unstacking 488 | ), 489 | count_type AS( 490 | SELECT 491 | row_number_order, 492 | order_id, 493 | pizza_id, 494 | extras_price, 495 | SUM(exclusion_type1) AS exclusion_type1, 496 | SUM(exclusion_type2) AS exclusion_type2, 497 | SUM(extras_type1) AS extras_type1, 498 | SUM(extras_type2) AS extras_type2 499 | FROM 500 | condition_type 501 | GROUP BY 502 | row_number_order, 503 | order_id, 504 | pizza_id, 505 | extras_price 506 | ORDER BY 507 | row_number_order 508 | ), 509 | fees_type AS( 510 | SELECT 511 | row_number_order, 512 | order_id, 513 | pizza_id, 514 | CASE 515 | WHEN (extras_type1 - exclusion_type1) * extras_price < 0 THEN 0 516 | ELSE (extras_type1 - exclusion_type1) * extras_price 517 | END AS fees_type1, 518 | CASE 519 | WHEN (extras_type2 - exclusion_type2) * extras_price < 0 THEN 0 520 | ELSE (extras_type2 - exclusion_type2) * extras_price 521 | END AS fees_type2 522 | FROM 523 | count_type 524 | ) 525 | SELECT 526 | pizza_id, 527 | SUM(fees_type1) + SUM(fees_type2) AS substitutes_cost 528 | FROM 529 | fees_type 530 | GROUP BY 531 | pizza_id; 532 | 533 | | pizza_id | substitutes_cost | 534 | | -------- | ---------------- | 535 | | 2 | 2 | 536 | | 1 | 8 | 537 | 538 | 539 | --Step 3: Compute the total revenues with the previously used queries: 540 | WITH segmented_revenues AS ( 541 | SELECT 542 | table1.pizza_id, 543 | table1.pizza_revenues, 544 | table2.substitutes_cost, 545 | (table1.pizza_revenues + table2.substitutes_cost) AS total_revenues 546 | FROM 547 | ( 548 | SELECT 549 | C.pizza_id, 550 | COUNT(C.pizza_id) * price as pizza_revenues 551 | FROM 552 | customer_orders_cleaned AS C 553 | LEFT JOIN runner_orders_cleaned AS R ON C.order_id = R.order_id 554 | LEFT JOIN pizza_prices AS P ON C.pizza_id = P.pizza_id 555 | WHERE 556 | R.cancellation IS NULL 557 | GROUP BY 558 | C.pizza_id, 559 | price 560 | ) AS table1 561 | LEFT JOIN ( 562 | WITH unstacking AS( 563 | SELECT 564 | t1.row_number_order, 565 | t1.order_id, 566 | t1.pizza_id, 567 | t1.exclusions, 568 | t1.extras, 569 | t2.type AS exclusion_type, 570 | t3.type AS extras_type, 571 | t3.modification_price AS extras_price 572 | FROM 573 | exclusions_extras_unstacked t1 574 | LEFT JOIN modification_prices t2 ON t1.exclusions = t2.topping_id 575 | LEFT JOIN modification_prices t3 ON t1.extras = t3.topping_id 576 | ORDER BY 577 | order_id 578 | ), 579 | condition_type AS( 580 | SELECT 581 | row_number_order, 582 | order_id, 583 | pizza_id, 584 | extras_price, 585 | CASE 586 | WHEN exclusion_type = 1 THEN 1 587 | ELSE 0 588 | END AS exclusion_type1, 589 | CASE 590 | WHEN exclusion_type = 2 THEN 1 591 | ELSE 0 592 | END AS exclusion_type2, 593 | CASE 594 | WHEN extras_type = 1 THEN 1 595 | ELSE 0 596 | END AS extras_type1, 597 | CASE 598 | WHEN extras_type = 2 THEN 1 599 | ELSE 0 600 | END AS extras_type2 601 | FROM 602 | unstacking 603 | ), 604 | count_type AS( 605 | SELECT 606 | row_number_order, 607 | order_id, 608 | pizza_id, 609 | extras_price, 610 | SUM(exclusion_type1) AS exclusion_type1, 611 | SUM(exclusion_type2) AS exclusion_type2, 612 | SUM(extras_type1) AS extras_type1, 613 | SUM(extras_type2) AS extras_type2 614 | FROM 615 | condition_type 616 | GROUP BY 617 | row_number_order, 618 | order_id, 619 | pizza_id, 620 | extras_price 621 | ORDER BY 622 | row_number_order 623 | ), 624 | fees_type AS( 625 | SELECT 626 | row_number_order, 627 | order_id, 628 | pizza_id, 629 | CASE 630 | WHEN (extras_type1 - exclusion_type1) * extras_price < 0 THEN 0 631 | ELSE (extras_type1 - exclusion_type1) * extras_price 632 | END AS fees_type1, 633 | CASE 634 | WHEN (extras_type2 - exclusion_type2) * extras_price < 0 THEN 0 635 | ELSE (extras_type2 - exclusion_type2) * extras_price 636 | END AS fees_type2 637 | FROM 638 | count_type 639 | ) 640 | SELECT 641 | pizza_id, 642 | SUM(fees_type1) + SUM(fees_type2) AS substitutes_cost 643 | FROM 644 | fees_type 645 | GROUP BY 646 | pizza_id 647 | ) AS table2 ON table1.pizza_id = table2.pizza_id 648 | ) 649 | SELECT 650 | SUM(total_revenues) AS total_revenues 651 | FROM 652 | segmented_revenues; 653 | 654 | | total_revenues | 655 | | -------------- | 656 | | 148 | 657 | 658 | 659 | 660 | ------------------------------------------------------ 661 | -- 5)The Pizza Runner team now wants to add an additional ratings system that allows customers to rate their runner, 662 | -- how would you design an additional table for this new dataset - generate a schema for this new table and insert 663 | -- your own data for ratings for each successful customer order between 1 to 5. 664 | 665 | DROP TABLE IF EXISTS runner_ratings; 666 | CREATE TABLE runner_ratings ( 667 | "order_id" INTEGER, 668 | "rating" INTEGER CONSTRAINT check1to5_rating CHECK ( 669 | "rating" between 1 670 | and 5 671 | ), 672 | "comment" VARCHAR(150) 673 | ); 674 | INSERT INTO 675 | runner_ratings ("order_id", "rating", "comment") 676 | VALUES 677 | ('1', '2', 'Tasty'), 678 | ('2', '4', ''), 679 | ('3', '4', ''), 680 | ('4', '5', 'The pizza arrived cold, really bad service'), 681 | ('5', '2', ''), 682 | ('6', NULL, ''), 683 | ('7', '5', ''), 684 | ('8', '4', 'Great service'), 685 | ('9', NULL, ''), 686 | ('10', '1', 'The pizza arrived upside down, really disappointed'); 687 | 688 | SELECT 689 | * 690 | FROM 691 | runner_ratings; 692 | 693 | | order_id | rating | comment | 694 | | -------- | ------ | -------------------------------------------------- | 695 | | 1 | 2 | Tasty | 696 | | 2 | 4 | | 697 | | 3 | 4 | | 698 | | 4 | 5 | The pizza arrived cold, really bad service | 699 | | 5 | 2 | | 700 | | 6 | | | 701 | | 7 | 5 | | 702 | | 8 | 4 | Great service | 703 | | 9 | | | 704 | | 10 | 1 | The pizza arrived upside down, really disappointed | 705 | 706 | 707 | ------------------------------------------------------ 708 | -- 6)Using your newly generated table - can you join all of the information together to form a table which has the following information for successful deliveries? 709 | -- - customer_id 710 | -- - order_id 711 | -- - runner_id 712 | -- - rating 713 | -- - order_time 714 | -- - pickup_time 715 | -- - Time between order and pickup 716 | -- - Delivery duration 717 | -- - Average speed 718 | -- - Total number of pizzas 719 | 720 | DROP TABLE IF EXISTS Global_table; 721 | CREATE TEMP TABLE Global_table AS WITH runner_layer1 AS ( 722 | SELECT 723 | order_id, 724 | runner_id, 725 | CAST( 726 | CASE 727 | WHEN pickup_time = 'null' THEN NULL 728 | ELSE pickup_time 729 | END AS timestamp 730 | ) AS pickup_time, 731 | CASE 732 | WHEN distance = '' THEN NULL 733 | WHEN distance = 'null' THEN NULL 734 | ELSE distance 735 | END as distance, 736 | CASE 737 | WHEN duration = '' THEN NULL 738 | WHEN duration = 'null' THEN NULL 739 | ELSE duration 740 | END as duration, 741 | CASE 742 | WHEN cancellation = '' THEN NULL 743 | WHEN cancellation = 'null' THEN NULL 744 | ELSE cancellation 745 | END as cancellation 746 | FROM 747 | runner_orders 748 | ), 749 | runner_layer2 AS( 750 | SELECT 751 | order_id, 752 | runner_id, 753 | CASE 754 | WHEN order_id = '3' THEN (pickup_time + INTERVAL '13 hour') 755 | ELSE pickup_time 756 | END AS pickup_time, 757 | CAST( 758 | regexp_replace(distance, '[a-z]+', '') AS DECIMAL(5, 2) 759 | ) AS distance, 760 | CAST(regexp_replace(duration, '[a-z]+', '') AS INT) AS duration, 761 | cancellation 762 | FROM 763 | runner_layer1 764 | ) 765 | SELECT 766 | t1.order_id, 767 | t2.customer_id, 768 | t1.runner_id, 769 | t3.rating, 770 | t2.order_time, 771 | t1.pickup_time, 772 | ( 773 | DATE_PART('hour', t1.pickup_time - t2.order_time) * 60 + DATE_PART('minute', t1.pickup_time - t2.order_time) 774 | ) * 60 + DATE_PART('second', t1.pickup_time - t2.order_time) AS time_between_order_and_pickup, 775 | t1.distance, 776 | t1.duration, 777 | ROUND( 778 | ( 779 | t1.distance :: NUMERIC /(t1.duration :: NUMERIC / 60) 780 | ), 781 | 2 782 | ) AS average_speed, 783 | COUNT(t2.pizza_id) AS count_pizza 784 | FROM 785 | runner_layer2 t1 786 | LEFT JOIN customer_orders t2 ON t1.order_id = t2.order_id 787 | LEFT JOIN runner_ratings t3 ON t1.order_id = t3.order_id 788 | WHERE 789 | cancellation IS NULL 790 | GROUP BY 791 | t1.order_id, 792 | t1.runner_id, 793 | t1.pickup_time, 794 | t1.distance, 795 | t1.duration, 796 | ROUND( 797 | ( 798 | t1.distance :: NUMERIC /(t1.duration :: NUMERIC / 60) 799 | ), 800 | 2 801 | ), 802 | t2.customer_id, 803 | t2.order_time, 804 | t3.rating; 805 | 806 | 807 | ------------------------------------------------------ 808 | -- 7) If a Meat Lovers pizza was $12 and Vegetarian $10 fixed prices with no cost for extras and each runner is paid $0.30 per kilometre 809 | -- traveled - how much money does Pizza Runner have left over after these deliveries? 810 | 811 | WITH pizza_revenues AS( 812 | SELECT 813 | t1.order_id, 814 | pizza_id, 815 | CASE 816 | WHEN pizza_id = 1 THEN COUNT(pizza_id) * 12 817 | ELSE COUNT(pizza_id) * 10 818 | END AS pizza_revenues 819 | FROM 820 | customer_orders_cleaned t1 821 | LEFT JOIN runner_orders_cleaned t2 ON t1.order_id = t2.order_id 822 | WHERE 823 | cancellation IS NULL 824 | GROUP BY 825 | t1.order_id, 826 | pizza_id 827 | ), 828 | revenues_delivery AS( 829 | SELECT 830 | t1.order_id, 831 | t2.distance * 0.3 AS delivery_cost, 832 | SUM(t1.pizza_revenues) AS order_revenues 833 | FROM 834 | pizza_revenues t1 835 | LEFT JOIN Global_table t2 ON t1.order_id = t2.order_id 836 | GROUP BY 837 | t1.order_id, 838 | distance 839 | ) 840 | SELECT 841 | ROUND(SUM(order_revenues) - SUM(delivery_COST), 2) AS revenues_afterdelivery 842 | FROM 843 | revenues_delivery; 844 | 845 | | revenues_afterdelivery | 846 | | ---------------------- | 847 | | 94.44 | 848 | 849 | 850 | 851 | ------------------------------------------------------ 852 | -- 8) If 1 unit of each ingredient costs $0.50 - how much net revenue will Pizza Runner make if the costs from question 30 are used? 853 | 854 | --Step 1: Let's go back to previous queries where we obtained how many times each ingredients were used (question 5 & 6 of part Ingredient Optimization) 855 | -- Note that those lines are added to make the SQL works as I divided this assignment in multiple parts for readability ! 856 | DROP TABLE IF EXISTS classical_recipe; 857 | CREATE TEMP TABLE classical_recipe AS WITH pizza_recipes_unstacked AS ( 858 | SELECT 859 | pizza_id, 860 | CAST( 861 | UNNEST( 862 | string_to_array(toppings, ', ') 863 | ) AS INT 864 | ) AS topping_id 865 | FROM 866 | pizza_recipes 867 | ) 868 | SELECT 869 | t4.row_number_order, 870 | t4.order_id, 871 | t4.customer_id, 872 | t1.pizza_id, 873 | t1.pizza_name, 874 | t2.topping_id, 875 | t3.topping_name 876 | FROM 877 | pizza_names t1 878 | JOIN pizza_recipes_unstacked t2 ON t1.pizza_id = t2.pizza_id 879 | JOIN pizza_toppings t3 ON t2.topping_id = t3.topping_id 880 | RIGHT JOIN customer_orders_cleaned t4 ON t1.pizza_id = t4.pizza_id; 881 | 882 | 883 | DROP TABLE IF EXISTS orders_exclusions; 884 | CREATE TEMP TABLE orders_exclusions AS 885 | SELECT 886 | row_number_order, 887 | order_id, 888 | customer_id, 889 | customer_orders_cleaned.pizza_id, 890 | pizza_name, 891 | CAST( 892 | UNNEST(string_to_array(COALESCE(exclusions, '0'), ',')) AS INT 893 | ) AS exclusions 894 | FROM 895 | customer_orders_cleaned 896 | JOIN pizza_names ON customer_orders_cleaned.pizza_id = pizza_names.pizza_id 897 | ORDER BY 898 | order_id; 899 | 900 | 901 | DROP TABLE IF EXISTS orders_extras; 902 | CREATE TEMP TABLE orders_extras AS 903 | SELECT 904 | row_number_order, 905 | order_id, 906 | customer_id, 907 | customer_orders_cleaned.pizza_id, 908 | pizza_name, 909 | CAST( 910 | UNNEST(string_to_array(COALESCE(extras, '0'), ',')) AS INT 911 | ) AS extras 912 | FROM 913 | customer_orders_cleaned 914 | JOIN pizza_names ON customer_orders_cleaned.pizza_id = pizza_names.pizza_id 915 | ORDER BY 916 | order_id; 917 | 918 | DROP TABLE IF EXISTS pizzas_details; 919 | CREATE TEMP TABLE pizzas_details AS WITH first_layer AS ( 920 | SELECT 921 | row_number_order, 922 | order_id, 923 | customer_id, 924 | pizza_id, 925 | pizza_name, 926 | topping_id 927 | FROM 928 | classical_recipe 929 | EXCEPT 930 | SELECT 931 | * 932 | FROM 933 | orders_exclusions 934 | UNION ALL 935 | SELECT 936 | * 937 | FROM 938 | orders_extras 939 | WHERE 940 | extras != 0 941 | ) 942 | SELECT 943 | row_number_order, 944 | order_id, 945 | customer_id, 946 | pizza_id, 947 | pizza_name, 948 | first_layer.topping_id, 949 | topping_name 950 | FROM 951 | first_layer 952 | LEFT JOIN pizza_toppings ON first_layer.topping_id = pizza_toppings.topping_id 953 | ORDER BY 954 | row_number_order, 955 | order_id, 956 | pizza_id, 957 | topping_id; 958 | 959 | 960 | --Step 2: Detail of the query to get the ingredients' cost per order_id 961 | 962 | SELECT 963 | order_id, 964 | COUNT(topping_id) * 0.5 as ingredient_costs 965 | FROM 966 | pizzas_details 967 | GROUP BY 968 | order_id 969 | ORDER BY 970 | order_id; 971 | 972 | | order_id | ingredient_costs | 973 | | -------- | ---------------- | 974 | | 1 | 4.0 | 975 | | 2 | 4.0 | 976 | | 3 | 7.0 | 977 | | 4 | 9.5 | 978 | | 5 | 4.5 | 979 | | 6 | 3.0 | 980 | | 7 | 3.5 | 981 | | 8 | 4.0 | 982 | | 9 | 4.5 | 983 | | 10 | 8.0 | 984 | 985 | 986 | --Step 3: Now let's fill this in the query of the previous question: 987 | WITH pizza_revenues AS( 988 | SELECT 989 | t1.order_id, 990 | pizza_id, 991 | CASE 992 | WHEN pizza_id = 1 THEN COUNT(pizza_id) * 12 993 | ELSE COUNT(pizza_id) * 10 994 | END AS pizza_revenues 995 | FROM 996 | customer_orders_cleaned t1 997 | LEFT JOIN runner_orders_cleaned t2 ON t1.order_id = t2.order_id 998 | WHERE 999 | cancellation IS NULL 1000 | GROUP BY 1001 | t1.order_id, 1002 | pizza_id 1003 | ), 1004 | revenues_delivery AS( 1005 | SELECT 1006 | t1.order_id, 1007 | t2.distance * 0.3 AS delivery_cost, 1008 | SUM(t1.pizza_revenues) AS order_revenues, 1009 | t3.ingredient_costs 1010 | FROM 1011 | pizza_revenues t1 1012 | LEFT JOIN Global_table t2 ON t1.order_id = t2.order_id 1013 | LEFT JOIN ( 1014 | SELECT 1015 | order_id, 1016 | COUNT(topping_id) * 0.5 as ingredient_costs 1017 | FROM 1018 | pizzas_details 1019 | GROUP BY 1020 | order_id 1021 | ) AS t3 ON t1.order_id = t3.order_id 1022 | GROUP BY 1023 | t1.order_id, 1024 | distance, 1025 | t3.ingredient_costs 1026 | ) 1027 | SELECT 1028 | ROUND( 1029 | SUM(order_revenues) - SUM(delivery_COST) - SUM(ingredient_costs), 1030 | 2 1031 | ) AS revenues_left 1032 | FROM 1033 | revenues_delivery; 1034 | 1035 | | revenues_left | 1036 | | ------------- | 1037 | | 49.94 | 1038 | 1039 | --- 1040 | 1041 | [View on DB Fiddle](https://www.db-fiddle.com/f/7VcQKQwsS3CTkGRFG7vu98/4) 1042 | -------------------------------------------------------------------------------- /Case Study #1 - Danny's Diner/README.md: -------------------------------------------------------------------------------- 1 | # :pizza: Case Study #1: Danny's Diner (19/05/2021) 2 | Image 3 | 4 | ## 📕 Table of Contents 5 | - [Business Inquiry](#business-inquiry) 6 | - [Entity Relationship Diagram](#entity-relationship-diagram) 7 | - [Case Study Questions](#case-study-questions) 8 | - [Solution Code](https://github.com/AymericPeltier/8-Week-SQL-Challenge/blob/main/Case%20Study%20%231%20-%20Danny's%20Diner/SQL_code.sql) 9 | - [Solution output](https://github.com/AymericPeltier/8-Week-SQL-Challenge/blob/main/Case%20Study%20%231%20-%20Danny's%20Diner/SQL_Output) 10 | 11 | *** 12 | 13 | ## Business Inquiry 14 | Danny just started a japonese food business. He wants to leverage the data that he collected by creating some Datasets to answer a few questions regarding his customers, their habits and whether to expand the customer loyalty program or not. 15 | 16 | ## Entity Relationship Diagram 17 | 18 | ![Entity diagram](/images/ER_case_1.png?raw=true "ER case 1") 19 | 20 | ## Case Study Questions 21 | 22 | 1. What is the total amount each customer spent at the restaurant? 23 | 2. How many days has each customer visited the restaurant? 24 | 3. What was the first item from the menu purchased by each customer? 25 | 4. What is the most purchased item on the menu and how many times was it purchased by all customers? 26 | 5. Which item was the most popular for each customer? 27 | 6. Which item was purchased first by the customer after they became a member? 28 | 7. Which item was purchased just before the customer became a member? 29 | 10. What is the total items and amount spent for each member before they became a member? 30 | 11. If each $1 spent equates to 10 points and sushi has a 2x points multiplier - how many points would each customer have? 31 | 12. In the first week after a customer joins the program (including their join date) they earn 2x points on all items, not just sushi - how many points do customer A and B have at the end of January? 32 | 33 | *** 34 | -------------------------------------------------------------------------------- /Case Study #1 - Danny's Diner/SQL_Output: -------------------------------------------------------------------------------- 1 | ------------------------------------------------- 2 | -- Data with Danny - 8 Week Challenge (Week 1) -- 3 | -- https://8weeksqlchallenge.com/case-study-1/ -- 4 | ------------------------------------------------- 5 | -- Done with PostgreSQL 6 | -- by Aymeric Peltier 7 | 8 | -- For the schema, please refer to https://github.com/AymericPeltier/8-Week-SQL-Challenge/blob/main/Case%20Study%20%231%20-%20Danny's%20Diner/SQL_code.sql 9 | 10 | -- Case Study Questions 11 | -- Each of the following case study questions can be answered using a single SQL statement: 12 | -- 13 | -- 1) What is the total amount each customer spent at the restaurant? 14 | -- 2) How many days has each customer visited the restaurant? 15 | -- 3) What was the first item from the menu purchased by each customer? 16 | -- 4) What is the most purchased item on the menu and how many times was it purchased by all customers? 17 | -- 5)Which item was the most popular for each customer? 18 | -- 6) Which item was purchased first by the customer after they became a member? 19 | -- 7) Which item was purchased just before the customer became a member? 20 | -- 8) What is the total items and amount spent for each member before they became a member? 21 | -- 9) If each $1 spent equates to 10 points and sushi has a 2x points multiplier - how many points would each customer have? 22 | -- 10) In the first week after a customer joins the program (including their join date) they earn 2x points on all items, not just sushi - how many points do customer A and B have at the end of January? 23 | 24 | -- Bonus Questions: recreate 2 tables 25 | -- 1) Join all the things (see case link) 26 | -- 2) Rank all the things (see case link) 27 | 28 | -------------------------------------------------------------------------------------------------------------------------------------------------------- 29 | -- BONUS QUESTION 1; Join All The Things 30 | 31 | SELECT 32 | S.customer_id, 33 | S.order_date, 34 | S.product_id, 35 | MU.product_name, 36 | MU.price, 37 | CASE WHEN (S.order_date >= MB.join_date) THEN 'Y' else 'N' END AS member 38 | FROM 39 | sales AS S 40 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 41 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 42 | ORDER BY customer_id, order_date; 43 | 44 | | customer_id | order_date | product_id | product_name | price | member | 45 | | ----------- | ------------------------ | ---------- | ------------ | ----- | ------ | 46 | | A | 2021-01-01T00:00:00.000Z | 1 | sushi | 10 | N | 47 | | A | 2021-01-01T00:00:00.000Z | 2 | curry | 15 | N | 48 | | A | 2021-01-07T00:00:00.000Z | 2 | curry | 15 | Y | 49 | | A | 2021-01-10T00:00:00.000Z | 3 | ramen | 12 | Y | 50 | | A | 2021-01-11T00:00:00.000Z | 3 | ramen | 12 | Y | 51 | | A | 2021-01-11T00:00:00.000Z | 3 | ramen | 12 | Y | 52 | | B | 2021-01-01T00:00:00.000Z | 2 | curry | 15 | N | 53 | | B | 2021-01-02T00:00:00.000Z | 2 | curry | 15 | N | 54 | | B | 2021-01-04T00:00:00.000Z | 1 | sushi | 10 | N | 55 | | B | 2021-01-11T00:00:00.000Z | 1 | sushi | 10 | Y | 56 | | B | 2021-01-16T00:00:00.000Z | 3 | ramen | 12 | Y | 57 | | B | 2021-02-01T00:00:00.000Z | 3 | ramen | 12 | Y | 58 | | C | 2021-01-01T00:00:00.000Z | 3 | ramen | 12 | N | 59 | | C | 2021-01-01T00:00:00.000Z | 3 | ramen | 12 | N | 60 | | C | 2021-01-07T00:00:00.000Z | 3 | ramen | 12 | N | 61 | 62 | --- 63 | -- BONUS QUESTION 2: Rank All The Things 64 | 65 | WITH joined_table AS( 66 | SELECT 67 | S.customer_id, 68 | S.order_date, 69 | S.product_id, 70 | MU.product_name, 71 | MU.price, 72 | CASE WHEN (S.order_date >= MB.join_date) THEN 'Y' else 'N' END AS member 73 | FROM 74 | sales AS S 75 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 76 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 77 | ORDER BY customer_id, order_date 78 | ) 79 | SELECT 80 | customer_id, 81 | order_date, 82 | product_id, 83 | product_name, 84 | price, 85 | member, 86 | CASE WHEN member = 'Y' THEN rank() OVER (PARTITION BY customer_id, member ORDER BY order_date) ELSE NULL END as ranking 87 | FROM 88 | joined_table; 89 | 90 | | customer_id | order_date | product_id | product_name | price | member | ranking | 91 | | ----------- | ------------------------ | ---------- | ------------ | ----- | ------ | ------- | 92 | | A | 2021-01-01T00:00:00.000Z | 1 | sushi | 10 | N | | 93 | | A | 2021-01-01T00:00:00.000Z | 2 | curry | 15 | N | | 94 | | A | 2021-01-07T00:00:00.000Z | 2 | curry | 15 | Y | 1 | 95 | | A | 2021-01-10T00:00:00.000Z | 3 | ramen | 12 | Y | 2 | 96 | | A | 2021-01-11T00:00:00.000Z | 3 | ramen | 12 | Y | 3 | 97 | | A | 2021-01-11T00:00:00.000Z | 3 | ramen | 12 | Y | 3 | 98 | | B | 2021-01-01T00:00:00.000Z | 2 | curry | 15 | N | | 99 | | B | 2021-01-02T00:00:00.000Z | 2 | curry | 15 | N | | 100 | | B | 2021-01-04T00:00:00.000Z | 1 | sushi | 10 | N | | 101 | | B | 2021-01-11T00:00:00.000Z | 1 | sushi | 10 | Y | 1 | 102 | | B | 2021-01-16T00:00:00.000Z | 3 | ramen | 12 | Y | 2 | 103 | | B | 2021-02-01T00:00:00.000Z | 3 | ramen | 12 | Y | 3 | 104 | | C | 2021-01-01T00:00:00.000Z | 3 | ramen | 12 | N | | 105 | | C | 2021-01-01T00:00:00.000Z | 3 | ramen | 12 | N | | 106 | | C | 2021-01-07T00:00:00.000Z | 3 | ramen | 12 | N | | 107 | 108 | ------------------------------------------------------ 109 | 110 | -- 1. What is the total amount each customer spent at the restaurant? 111 | 112 | SELECT 113 | customer_id, 114 | SUM(price) as total_spent 115 | FROM 116 | ( 117 | SELECT 118 | S.customer_id, 119 | S.order_date, 120 | S.product_id, 121 | MU.product_name, 122 | MU.price, 123 | CASE 124 | WHEN (S.order_date >= MB.join_date) THEN 'Y' 125 | else 'N' 126 | END AS member 127 | FROM 128 | sales AS S 129 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 130 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 131 | ORDER BY 132 | customer_id, 133 | order_date 134 | ) as bonus_table 135 | GROUP BY 136 | customer_id 137 | ORDER BY 138 | customer_id; 139 | 140 | | customer_id | total_spent | 141 | | ----------- | ----------- | 142 | | A | 76 | 143 | | B | 74 | 144 | | C | 36 | 145 | 146 | 147 | ------------------------------------------------------ 148 | -- 2. How many days has each customer visited the restaurant? 149 | 150 | SELECT 151 | customer_id, 152 | COUNT(DISTINCT order_date) 153 | FROM 154 | sales 155 | GROUP BY 156 | customer_id; 157 | 158 | | customer_id | count | 159 | | ----------- | ----- | 160 | | A | 4 | 161 | | B | 6 | 162 | | C | 2 | 163 | 164 | ------------------------------------------------------ 165 | -- 3. What was the first item from the menu purchased by each customer? 166 | 167 | SELECT 168 | customer_id, 169 | product_name 170 | FROM 171 | ( 172 | WITH table_name AS( 173 | SELECT 174 | S.customer_id, 175 | S.order_date, 176 | M.product_name 177 | FROM 178 | sales as S 179 | LEFT JOIN menu as M ON S.product_id = M.product_id 180 | ORDER BY 181 | order_date 182 | ) 183 | SELECT 184 | customer_id, 185 | product_name, 186 | RANK() OVER (ORDER BY order_date) as rank_order 187 | FROM table_name ) as rank_product 188 | WHERE 189 | rank_order = 1 190 | GROUP BY 191 | customer_id, 192 | product_name 193 | ORDER BY 194 | customer_id; 195 | 196 | | customer_id | product_name | 197 | | ----------- | ------------ | 198 | | A | curry | 199 | | A | sushi | 200 | | B | curry | 201 | | C | ramen | 202 | 203 | ------------------------------------------------------ 204 | -- 4. What is the most purchased item on the menu and how many times was it purchased by all customers? 205 | 206 | SELECT 207 | S.product_id, 208 | M.product_name, 209 | COUNT(S.product_id) as total_order 210 | FROM 211 | sales S 212 | LEFT JOIN menu M 213 | ON S.product_id = M.product_id 214 | GROUP BY 215 | S.product_id, 216 | M.product_name 217 | ORDER BY 218 | total_order DESC 219 | LIMIT 1; 220 | 221 | | product_id | product_name | total_order | 222 | | ---------- | ------------ | ----------- | 223 | | 3 | ramen | 8 | 224 | 225 | -------------------------------------------------------- 226 | -- 5. Which item was the most popular for each customer? 227 | 228 | SELECT 229 | customer_id, 230 | string_agg( CAST(product_id AS CHAR), ', ') AS favorite_product 231 | FROM 232 | ( 233 | 234 | SELECT 235 | customer_id, 236 | product_id, 237 | product_name, 238 | total_order, 239 | rank 240 | FROM 241 | ( 242 | WITH table_name AS ( 243 | SELECT 244 | S.customer_id, 245 | S.product_id, 246 | M.product_name, 247 | COUNT(S.product_id) as total_order 248 | FROM 249 | sales S 250 | LEFT JOIN menu M ON S.product_id = M.product_id 251 | GROUP BY 252 | S.customer_id, 253 | S.product_id, 254 | M.product_name 255 | ) 256 | SELECT 257 | customer_id, 258 | product_id, 259 | product_name, 260 | total_order, 261 | RANK() OVER (PARTITION BY customer_id ORDER BY total_order DESC) as Rank 262 | FROM 263 | table_name ) as rank_order 264 | WHERE 265 | rank = 1) as ranking_table 266 | GROUP BY 267 | customer_id; 268 | 269 | | customer_id | favorite_product | 270 | | ----------- | ---------------- | 271 | | A | 3 | 272 | | B | 3, 1, 2 | 273 | | C | 3 | 274 | 275 | ------------------------------------------------------ 276 | -- 6. Which item was purchased first by the customer after they became a member? 277 | 278 | SELECT 279 | customer_id, 280 | product_id, 281 | product_name, 282 | order_date 283 | FROM 284 | ( 285 | WITH joined_table AS( 286 | SELECT 287 | S.customer_id, 288 | S.order_date, 289 | S.product_id, 290 | MU.product_name, 291 | MU.price, 292 | CASE 293 | WHEN (S.order_date >= MB.join_date) THEN 'Y' 294 | else 'N' 295 | END AS member 296 | FROM 297 | sales AS S 298 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 299 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 300 | ORDER BY 301 | customer_id, 302 | order_date 303 | ) 304 | SELECT 305 | customer_id, 306 | order_date, 307 | product_id, 308 | product_name, 309 | price, 310 | member, 311 | CASE 312 | WHEN member = 'Y' THEN rank() OVER ( 313 | PARTITION BY customer_id, 314 | member 315 | ORDER BY 316 | order_date 317 | ) 318 | ELSE NULL 319 | END as ranking 320 | FROM 321 | joined_table 322 | ) as ranking_table 323 | WHERE ranking = 1; 324 | 325 | | customer_id | product_id | product_name | order_date | 326 | | ----------- | ---------- | ------------ | ------------------------ | 327 | | A | 2 | curry | 2021-01-07T00:00:00.000Z | 328 | | B | 1 | sushi | 2021-01-11T00:00:00.000Z | 329 | 330 | ------------------------------------------------------ 331 | -- 7. Which item was purchased just before the customer became a member? 332 | 333 | SELECT 334 | customer_id, 335 | string_agg(product_name, ', ') AS favorite_product 336 | FROM( 337 | SELECT 338 | customer_id, 339 | join_date, 340 | order_date, 341 | product_id, 342 | product_name, 343 | price 344 | FROM 345 | ( 346 | WITH joined_table AS( 347 | SELECT 348 | S.customer_id, 349 | S.order_date, 350 | S.product_id, 351 | MU.product_name, 352 | MU.price, 353 | MB.join_date, 354 | CASE 355 | WHEN (S.order_date >= MB.join_date) THEN 'Y' 356 | else 'N' 357 | END AS member 358 | FROM 359 | sales AS S 360 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 361 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 362 | ORDER BY 363 | customer_id, 364 | order_date 365 | ) 366 | SELECT 367 | customer_id, 368 | join_date, 369 | order_date, 370 | product_id, 371 | product_name, 372 | price, 373 | member, 374 | CASE 375 | WHEN member = 'Y' THEN rank() OVER ( 376 | PARTITION BY customer_id, 377 | member 378 | ORDER BY 379 | order_date 380 | ) 381 | ELSE NULL 382 | END as ranking, 383 | CASE 384 | WHEN member = 'N' THEN rank() OVER ( 385 | PARTITION BY customer_id, 386 | member 387 | ORDER BY 388 | order_date DESC 389 | ) 390 | ELSE NULL 391 | END as inverse_ranking 392 | FROM 393 | joined_table 394 | ) as ranking_table 395 | WHERE 396 | join_date IS NOT NULL 397 | AND inverse_ranking = 1 398 | ) as ranking_table 399 | GROUP BY 400 | customer_id; 401 | 402 | | customer_id | favorite_product | 403 | | ----------- | ---------------- | 404 | | A | curry, sushi | 405 | | B | sushi | 406 | 407 | ------------------------------------------------------ 408 | -- 8) What is the total items and amount spent for each member before they became a member? 409 | 410 | SELECT 411 | customer_id, 412 | COUNT(order_date) as items, 413 | SUM(price) as price_paid 414 | FROM 415 | ( 416 | WITH joined_table AS( 417 | SELECT 418 | S.customer_id, 419 | S.order_date, 420 | S.product_id, 421 | MU.product_name, 422 | MU.price, 423 | MB.join_date, 424 | CASE 425 | WHEN (S.order_date >= MB.join_date) THEN 'Y' 426 | else 'N' 427 | END AS member 428 | FROM 429 | sales AS S 430 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 431 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 432 | ORDER BY 433 | customer_id, 434 | order_date 435 | ) 436 | SELECT 437 | customer_id, 438 | join_date, 439 | order_date, 440 | product_id, 441 | product_name, 442 | price, 443 | member, 444 | CASE 445 | WHEN member = 'Y' THEN rank() OVER ( 446 | PARTITION BY customer_id, 447 | member 448 | ORDER BY 449 | order_date 450 | ) 451 | ELSE NULL 452 | END as ranking, 453 | CASE 454 | WHEN member = 'N' THEN rank() OVER ( 455 | PARTITION BY customer_id, 456 | member 457 | ORDER BY 458 | order_date DESC 459 | ) 460 | ELSE NULL 461 | END as inverse_ranking 462 | FROM 463 | joined_table 464 | ) as ranking_table 465 | WHERE 466 | join_date IS NOT NULL 467 | AND member = 'N' 468 | GROUP BY 469 | customer_id; 470 | 471 | | customer_id | items | price_paid | 472 | | ----------- | ----- | ---------- | 473 | | B | 3 | 40 | 474 | | A | 2 | 25 | 475 | 476 | 477 | ------------------------------------------------------ 478 | -- 9. If each $1 spent equates to 10 points and sushi has a 2x points multiplier - how many points would each customer have? 479 | 480 | SELECT 481 | customer_id, 482 | SUM(CASE WHEN product_name = 'sushi' THEN price*20 ELSE price*10 END) as customer_points 483 | FROM 484 | ( 485 | WITH joined_table AS( 486 | SELECT 487 | S.customer_id, 488 | S.order_date, 489 | S.product_id, 490 | MU.product_name, 491 | MU.price, 492 | CASE WHEN (S.order_date >= MB.join_date) THEN 'Y' else 'N' END AS member 493 | FROM 494 | sales AS S 495 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 496 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 497 | ORDER BY customer_id, order_date 498 | ) 499 | SELECT 500 | customer_id, 501 | order_date, 502 | product_id, 503 | product_name, 504 | price, 505 | member, 506 | CASE WHEN member = 'Y' THEN rank() OVER (PARTITION BY customer_id, member ORDER BY order_date) ELSE NULL END as ranking 507 | FROM 508 | joined_table) as ranking_table 509 | WHERE 510 | member = 'Y' 511 | GROUP BY 512 | customer_id 513 | ORDER BY 514 | customer_id; 515 | 516 | | customer_id | customer_points | 517 | | ----------- | --------------- | 518 | | A | 510 | 519 | | B | 440 | 520 | 521 | ------------------------------------------------------ 522 | -- 10. In the first week after a customer joins the program (including their join date) they earn 2x points on all items, 523 | -- not just sushi - how many points do customer A and B have at the end of January? 524 | 525 | SELECT 526 | customer_id, 527 | SUM(CASE WHEN first_week ='Y' THEN price*20 528 | ELSE CASE WHEN product_name = 'sushi' THEN price*20 ELSE price*10 END END) AS customer_points 529 | FROM 530 | ( 531 | WITH joined_table AS( 532 | SELECT 533 | S.customer_id, 534 | MB.join_date, 535 | S.order_date, 536 | S.product_id, 537 | MU.product_name, 538 | MU.price, 539 | CASE WHEN (S.order_date >= MB.join_date) THEN 'Y' else 'N' END AS member, 540 | CASE WHEN (S.order_date - MB.join_date) BETWEEN 0 and 6 THEN 'Y' else 'N' END AS first_week 541 | FROM 542 | sales AS S 543 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 544 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 545 | ORDER BY customer_id, order_date 546 | ) 547 | SELECT 548 | customer_id, 549 | join_date, 550 | order_date, 551 | product_id, 552 | product_name, 553 | price, 554 | member, 555 | first_week, 556 | CASE WHEN member = 'Y' THEN rank() OVER (PARTITION BY customer_id, member ORDER BY order_date) ELSE NULL END as ranking 557 | FROM 558 | joined_table) as ranking_table 559 | WHERE 560 | member = 'Y' 561 | GROUP BY 562 | customer_id 563 | ORDER BY 564 | customer_id; 565 | 566 | | customer_id | customer_points | 567 | | ----------- | --------------- | 568 | | A | 1020 | 569 | | B | 440 | 570 | 571 | --- 572 | 573 | [View on DB Fiddle](https://www.db-fiddle.com/f/2rM8RAnq7h5LLDTzZiRWcd/18) 574 | -------------------------------------------------------------------------------- /Case Study #1 - Danny's Diner/SQL_code.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------- 2 | -- Data with Danny - 8 Week Challenge (Week 1) -- 3 | -- https://8weeksqlchallenge.com/case-study-1/ -- 4 | ------------------------------------------------- 5 | -- Done with PostgreSQL 6 | -- By Aymeric Peltier 7 | -- Date: 19/05/2021 8 | 9 | -- **Schema (PostgreSQL v13)** 10 | CREATE TABLE sales ( 11 | "customer_id" VARCHAR(1), 12 | "order_date" DATE, 13 | "product_id" INTEGER 14 | ); 15 | INSERT INTO sales ("customer_id", "order_date", "product_id") 16 | VALUES ('A', '2021-01-01', '1'), 17 | ('A', '2021-01-01', '2'), 18 | ('A', '2021-01-07', '2'), 19 | ('A', '2021-01-10', '3'), 20 | ('A', '2021-01-11', '3'), 21 | ('A', '2021-01-11', '3'), 22 | ('B', '2021-01-01', '2'), 23 | ('B', '2021-01-02', '2'), 24 | ('B', '2021-01-04', '1'), 25 | ('B', '2021-01-11', '1'), 26 | ('B', '2021-01-16', '3'), 27 | ('B', '2021-02-01', '3'), 28 | ('C', '2021-01-01', '3'), 29 | ('C', '2021-01-01', '3'), 30 | ('C', '2021-01-07', '3'); 31 | CREATE TABLE menu ( 32 | "product_id" INTEGER, 33 | "product_name" VARCHAR(5), 34 | "price" INTEGER 35 | ); 36 | INSERT INTO menu ("product_id", "product_name", "price") 37 | VALUES ('1', 'sushi', '10'), 38 | ('2', 'curry', '15'), 39 | ('3', 'ramen', '12'); 40 | CREATE TABLE members ( 41 | "customer_id" VARCHAR(1), 42 | "join_date" DATE 43 | ); 44 | INSERT INTO members ("customer_id", "join_date") 45 | VALUES ('A', '2021-01-07'), 46 | ('B', '2021-01-09'); 47 | -- BONUS QUESTION 1; Join All The Things 48 | SELECT S.customer_id, 49 | S.order_date, 50 | S.product_id, 51 | MU.product_name, 52 | MU.price, 53 | CASE 54 | WHEN (S.order_date >= MB.join_date) THEN 'Y' 55 | else 'N' 56 | END AS member 57 | FROM sales AS S 58 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 59 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 60 | ORDER BY customer_id, 61 | order_date; 62 | -- BONUS QUESTION 2: Rank All The Things 63 | WITH joined_table AS( 64 | SELECT S.customer_id, 65 | S.order_date, 66 | S.product_id, 67 | MU.product_name, 68 | MU.price, 69 | CASE 70 | WHEN (S.order_date >= MB.join_date) THEN 'Y' 71 | else 'N' 72 | END AS member 73 | FROM sales AS S 74 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 75 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 76 | ORDER BY customer_id, 77 | order_date 78 | ) 79 | SELECT customer_id, 80 | order_date, 81 | product_id, 82 | product_name, 83 | price, 84 | member, 85 | CASE 86 | WHEN member = 'Y' THEN rank() OVER ( 87 | PARTITION BY customer_id, 88 | member 89 | ORDER BY order_date 90 | ) 91 | ELSE NULL 92 | END as ranking 93 | FROM joined_table; 94 | -- ---------------------------------------------------- 95 | -- 1. What is the total amount each customer spent at the restaurant? 96 | SELECT customer_id, 97 | SUM(price) as total_spent 98 | FROM ( 99 | SELECT S.customer_id, 100 | S.order_date, 101 | S.product_id, 102 | MU.product_name, 103 | MU.price, 104 | CASE 105 | WHEN (S.order_date >= MB.join_date) THEN 'Y' 106 | else 'N' 107 | END AS member 108 | FROM sales AS S 109 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 110 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 111 | ORDER BY customer_id, 112 | order_date 113 | ) as bonus_table 114 | GROUP BY customer_id 115 | ORDER BY customer_id; 116 | -- ---------------------------------------------------- 117 | -- 2. How many days has each customer visited the restaurant? 118 | SELECT customer_id, 119 | COUNT(DISTINCT order_date) 120 | FROM sales 121 | GROUP BY customer_id; 122 | -- ---------------------------------------------------- 123 | -- 3. What was the first item from the menu purchased by each customer? 124 | SELECT customer_id, 125 | product_name 126 | FROM ( 127 | WITH table_name AS( 128 | SELECT S.customer_id, 129 | S.order_date, 130 | M.product_name 131 | FROM sales as S 132 | LEFT JOIN menu as M ON S.product_id = M.product_id 133 | ORDER BY order_date 134 | ) 135 | SELECT customer_id, 136 | product_name, 137 | RANK() OVER ( 138 | ORDER BY order_date 139 | ) as rank_order 140 | FROM table_name 141 | ) as rank_product 142 | WHERE rank_order = 1 143 | GROUP BY customer_id, 144 | product_name 145 | ORDER BY customer_id; 146 | -- ---------------------------------------------------- 147 | -- 4. What is the most purchased item on the menu and how many times was it purchased by all customers? 148 | SELECT S.product_id, 149 | M.product_name, 150 | COUNT(S.product_id) as total_order 151 | FROM sales S 152 | LEFT JOIN menu M ON S.product_id = M.product_id 153 | GROUP BY S.product_id, 154 | M.product_name 155 | ORDER BY total_order DESC 156 | LIMIT 1; 157 | -- ------------------------------------------------------ 158 | -- 5. Which item was the most popular for each customer? 159 | SELECT customer_id, 160 | string_agg(CAST(product_id AS CHAR), ', ') AS favorite_product 161 | FROM ( 162 | SELECT customer_id, 163 | product_id, 164 | product_name, 165 | total_order, 166 | rank 167 | FROM ( 168 | WITH table_name AS ( 169 | SELECT S.customer_id, 170 | S.product_id, 171 | M.product_name, 172 | COUNT(S.product_id) as total_order 173 | FROM sales S 174 | LEFT JOIN menu M ON S.product_id = M.product_id 175 | GROUP BY S.customer_id, 176 | S.product_id, 177 | M.product_name 178 | ) 179 | SELECT customer_id, 180 | product_id, 181 | product_name, 182 | total_order, 183 | RANK() OVER ( 184 | PARTITION BY customer_id 185 | ORDER BY total_order DESC 186 | ) as Rank 187 | FROM table_name 188 | ) as rank_order 189 | WHERE rank = 1 190 | ) as ranking_table 191 | GROUP BY customer_id; 192 | -- ---------------------------------------------------- 193 | -- 6. Which item was purchased first by the customer after they became a member? 194 | SELECT customer_id, 195 | product_id, 196 | product_name, 197 | order_date 198 | FROM ( 199 | WITH joined_table AS( 200 | SELECT S.customer_id, 201 | S.order_date, 202 | S.product_id, 203 | MU.product_name, 204 | MU.price, 205 | CASE 206 | WHEN (S.order_date >= MB.join_date) THEN 'Y' 207 | else 'N' 208 | END AS member 209 | FROM sales AS S 210 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 211 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 212 | ORDER BY customer_id, 213 | order_date 214 | ) 215 | SELECT customer_id, 216 | order_date, 217 | product_id, 218 | product_name, 219 | price, 220 | member, 221 | CASE 222 | WHEN member = 'Y' THEN rank() OVER ( 223 | PARTITION BY customer_id, 224 | member 225 | ORDER BY order_date 226 | ) 227 | ELSE NULL 228 | END as ranking 229 | FROM joined_table 230 | ) as ranking_table 231 | WHERE ranking = 1; 232 | -- ---------------------------------------------------- 233 | -- 7. Which item was purchased just before the customer became a member? 234 | SELECT customer_id, 235 | string_agg(product_name, ', ') AS favorite_product 236 | FROM( 237 | SELECT customer_id, 238 | join_date, 239 | order_date, 240 | product_id, 241 | product_name, 242 | price 243 | FROM ( 244 | WITH joined_table AS( 245 | SELECT S.customer_id, 246 | S.order_date, 247 | S.product_id, 248 | MU.product_name, 249 | MU.price, 250 | MB.join_date, 251 | CASE 252 | WHEN (S.order_date >= MB.join_date) THEN 'Y' 253 | else 'N' 254 | END AS member 255 | FROM sales AS S 256 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 257 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 258 | ORDER BY customer_id, 259 | order_date 260 | ) 261 | SELECT customer_id, 262 | join_date, 263 | order_date, 264 | product_id, 265 | product_name, 266 | price, 267 | member, 268 | CASE 269 | WHEN member = 'Y' THEN rank() OVER ( 270 | PARTITION BY customer_id, 271 | member 272 | ORDER BY order_date 273 | ) 274 | ELSE NULL 275 | END as ranking, 276 | CASE 277 | WHEN member = 'N' THEN rank() OVER ( 278 | PARTITION BY customer_id, 279 | member 280 | ORDER BY order_date DESC 281 | ) 282 | ELSE NULL 283 | END as inverse_ranking 284 | FROM joined_table 285 | ) as ranking_table 286 | WHERE join_date IS NOT NULL 287 | AND inverse_ranking = 1 288 | ) as ranking_table 289 | GROUP BY customer_id; 290 | -- ---------------------------------------------------- 291 | -- 8) What is the total items and amount spent for each member before they became a member? 292 | SELECT customer_id, 293 | COUNT(order_date) as items, 294 | SUM(price) as price_paid 295 | FROM ( 296 | WITH joined_table AS( 297 | SELECT S.customer_id, 298 | S.order_date, 299 | S.product_id, 300 | MU.product_name, 301 | MU.price, 302 | MB.join_date, 303 | CASE 304 | WHEN (S.order_date >= MB.join_date) THEN 'Y' 305 | else 'N' 306 | END AS member 307 | FROM sales AS S 308 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 309 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 310 | ORDER BY customer_id, 311 | order_date 312 | ) 313 | SELECT customer_id, 314 | join_date, 315 | order_date, 316 | product_id, 317 | product_name, 318 | price, 319 | member, 320 | CASE 321 | WHEN member = 'Y' THEN rank() OVER ( 322 | PARTITION BY customer_id, 323 | member 324 | ORDER BY order_date 325 | ) 326 | ELSE NULL 327 | END as ranking, 328 | CASE 329 | WHEN member = 'N' THEN rank() OVER ( 330 | PARTITION BY customer_id, 331 | member 332 | ORDER BY order_date DESC 333 | ) 334 | ELSE NULL 335 | END as inverse_ranking 336 | FROM joined_table 337 | ) as ranking_table 338 | WHERE join_date IS NOT NULL 339 | AND member = 'N' 340 | GROUP BY customer_id; 341 | -- ---------------------------------------------------- 342 | -- 9. If each $1 spent equates to 10 points and sushi has a 2x points multiplier - how many points would each customer have? 343 | SELECT customer_id, 344 | SUM( 345 | CASE 346 | WHEN product_name = 'sushi' THEN price * 20 347 | ELSE price * 10 348 | END 349 | ) as customer_points 350 | FROM ( 351 | WITH joined_table AS( 352 | SELECT S.customer_id, 353 | S.order_date, 354 | S.product_id, 355 | MU.product_name, 356 | MU.price, 357 | CASE 358 | WHEN (S.order_date >= MB.join_date) THEN 'Y' 359 | else 'N' 360 | END AS member 361 | FROM sales AS S 362 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 363 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 364 | ORDER BY customer_id, 365 | order_date 366 | ) 367 | SELECT customer_id, 368 | order_date, 369 | product_id, 370 | product_name, 371 | price, 372 | member, 373 | CASE 374 | WHEN member = 'Y' THEN rank() OVER ( 375 | PARTITION BY customer_id, 376 | member 377 | ORDER BY order_date 378 | ) 379 | ELSE NULL 380 | END as ranking 381 | FROM joined_table 382 | ) as ranking_table 383 | WHERE member = 'Y' 384 | GROUP BY customer_id 385 | ORDER BY customer_id; 386 | -- ---------------------------------------------------- 387 | -- 10. In the first week after a customer joins the program (including their join date) they earn 2x points on all items, 388 | -- not just sushi - how many points do customer A and B have at the end of January? 389 | SELECT customer_id, 390 | SUM( 391 | CASE 392 | WHEN first_week = 'Y' THEN price * 20 393 | ELSE CASE 394 | WHEN product_name = 'sushi' THEN price * 20 395 | ELSE price * 10 396 | END 397 | END 398 | ) AS customer_points 399 | FROM ( 400 | WITH joined_table AS( 401 | SELECT S.customer_id, 402 | MB.join_date, 403 | S.order_date, 404 | S.product_id, 405 | MU.product_name, 406 | MU.price, 407 | CASE 408 | WHEN (S.order_date >= MB.join_date) THEN 'Y' 409 | else 'N' 410 | END AS member, 411 | CASE 412 | WHEN (S.order_date - MB.join_date) BETWEEN 0 and 6 THEN 'Y' 413 | else 'N' 414 | END AS first_week 415 | FROM sales AS S 416 | LEFT JOIN menu AS MU ON S.product_id = MU.product_id 417 | LEFT JOIN members as MB ON S.customer_id = MB.customer_id 418 | ORDER BY customer_id, 419 | order_date 420 | ) 421 | SELECT customer_id, 422 | join_date, 423 | order_date, 424 | product_id, 425 | product_name, 426 | price, 427 | member, 428 | first_week, 429 | CASE 430 | WHEN member = 'Y' THEN rank() OVER ( 431 | PARTITION BY customer_id, 432 | member 433 | ORDER BY order_date 434 | ) 435 | ELSE NULL 436 | END as ranking 437 | FROM joined_table 438 | ) as ranking_table 439 | WHERE member = 'Y' 440 | GROUP BY customer_id 441 | ORDER BY customer_id; 442 | -------------------------------------------------------------------------------- /Case Study #2: Pizza Runner/README.md: -------------------------------------------------------------------------------- 1 | # Case Study #2: Pizza Runner (26/05/2021) 2 | Image 3 | 4 | ## 📕 Table of Contents 5 | - [Business Inquiries](#business-inquiries) 6 | - [Entity Relationship Diagram](#entity-relationship-diagram) 7 | - [Case Study Questions](#case-study-questions) 8 | - [Solution Code](https://github.com/AymericPeltier/8-Week-SQL-Challenge/blob/main/Case%20Study%20%231%20-%20Danny's%20Diner/SQL_code.sql) 9 | - [Solution output](https://github.com/AymericPeltier/8-Week-SQL-Challenge/blob/main/Case%20Study%20%231%20-%20Danny's%20Diner/SQL_Output) 10 | 11 | *** 12 | 13 | ### Business Inquiries: 14 | Danny decided to expand his Pizza business and Uberize it. Thus, he launches "Pizza Runner": he recruited runners to deliver pizza from his Headquarters and is developping an app. 15 | 16 | He has many questions to be answered related to different general topic: 17 | * Pizza Metrics 18 | * Runner and Customer Experience 19 | * Ingredient Optimisation 20 | * Pricing and Ratings 21 | 22 | ## Entity Relationship Diagram 23 | 24 | ![Entity diagram](/images/ER_case_2.png?raw=true "ER case 2") 25 | 26 | ## Case Study Questions 27 | View my solution [here](https://github.com/AymericPeltier/8-Week-SQL-Challenge/blob/main/Case%20Study%20%232:%20Pizza%20Runner/SQL_code/Complete_Solution) 28 | 29 | ### A. Pizza Metrics 30 | 31 | 1. How many pizzas were ordered? 32 | 2. How many unique customer orders were made? 33 | 3. How many successful orders were delivered by each runner? 34 | 4. How many of each type of pizza was delivered? 35 | 5. How many Vegetarian and Meatlovers were ordered by each customer? 36 | 6. What was the maximum number of pizzas delivered in a single order? 37 | 7. For each customer, how many delivered pizzas had at least 1 change and how many had no changes? 38 | 8. How many pizzas were delivered that had both exclusions and extras? 39 | 9. What was the total volume of pizzas ordered for each hour of the day? 40 | 10. What was the volume of orders for each day of the week? 41 | 42 | ### B. Runner and Customer Experience 43 | 44 | 1. How many runners signed up for each 1 week period? (i.e. week starts 2021-01-01) 45 | 2. What was the average time in minutes it took for each runner to arrive at the Pizza Runner HQ to pickup the order? 46 | 3. Is there any relationship between the number of pizzas and how long the order takes to prepare? 47 | 4. What was the average distance travelled for each customer? 48 | 5. What was the difference between the longest and shortest delivery times for all orders? 49 | 6. What was the average speed for each runner for each delivery and do you notice any trend for these values? 50 | 7. What is the successful delivery percentage for each runner? 51 | 52 | ### C. Ingredient Optimisation 53 | 54 | 1. What are the standard ingredients for each pizza? 55 | 2. What was the most commonly added extra? 56 | 3. What was the most common exclusion? 57 | 4. Generate an order item for each record in the customers_orders table in the format of one of the following: 58 | - Meat Lovers 59 | - Meat Lovers - Exclude Beef 60 | - Meat Lovers - Extra Bacon 61 | - Meat Lovers - Exclude Cheese, Bacon - Extra Mushroom, Peppers 62 | 5. Generate an alphabetically ordered comma separated ingredient list for each pizza order from the customer_orders table and add a 2x in front of any relevant ingredients 63 | 6. For example: "Meat Lovers: 2xBacon, Beef, ... , Salami" 64 | 7. What is the total quantity of each ingredient used in all delivered pizzas sorted by most frequent first? 65 | 66 | ### D. Pricing and Ratings 67 | 68 | 1. If a Meat Lovers pizza costs $12 and Vegetarian costs $10 and there were no charges for changes - how much money has Pizza Runner made so far if there are no delivery fees? 69 | 2. What if there was an additional $1 charge for any pizza extras? 70 | - Add cheese is $1 extra 71 | 3. The Pizza Runner team now wants to add an additional ratings system that allows customers to rate their runner, how would you design an additional table for this new dataset generate a schema for this new table and insert your own data for ratings for each successful customer order between 1 to 5. 72 | 4. Using your newly generated table - can you join all of the information together to form a table which has the following information for successful deliveries? 73 | - customer_id 74 | - order_id 75 | - runner_id 76 | - rating 77 | - order_time 78 | - pickup_time 79 | - Time between order and pickup 80 | - Delivery duration 81 | - Average speed 82 | - Total number of pizzas 83 | 5. If a Meat Lovers pizza was $12 and Vegetarian $10 fixed prices with no cost for extras and each runner is paid $0.30 per kilometre traveled - how much money does Pizza Runner have left over after these deliveries? 84 | 85 | ### E. Bonus Questions 86 | 87 | If Danny wants to expand his range of pizzas - how would this impact the existing data design? Write an INSERT statement to demonstrate what would happen if a new Supreme pizza with all the toppings was added to the Pizza Runner menu? 88 | 89 | *** 90 | -------------------------------------------------------------------------------- /Case Study #2: Pizza Runner/SQL_output/1. SQL_Schema: -------------------------------------------------------------------------------- 1 | -- Data with Danny - 8 Week Challenge (Week 2) 2 | -- Case available at: https://8weeksqlchallenge.com/case-study-2/ 3 | 4 | -- **Schema (PostgreSQL v13)** 5 | 6 | DROP TABLE IF EXISTS runners; 7 | CREATE TABLE runners ( 8 | "runner_id" INTEGER, 9 | "registration_date" DATE 10 | ); 11 | INSERT INTO runners 12 | ("runner_id", "registration_date") 13 | VALUES 14 | (1, '2021-01-01'), 15 | (2, '2021-01-03'), 16 | (3, '2021-01-08'), 17 | (4, '2021-01-15'); 18 | 19 | 20 | DROP TABLE IF EXISTS customer_orders; 21 | CREATE TABLE customer_orders ( 22 | "order_id" INTEGER, 23 | "customer_id" INTEGER, 24 | "pizza_id" INTEGER, 25 | "exclusions" VARCHAR(4), 26 | "extras" VARCHAR(4), 27 | "order_time" TIMESTAMP 28 | ); 29 | 30 | INSERT INTO customer_orders 31 | ("order_id", "customer_id", "pizza_id", "exclusions", "extras", "order_time") 32 | VALUES 33 | ('1', '101', '1', '', '', '2020-01-01 18:05:02'), 34 | ('2', '101', '1', '', '', '2020-01-01 19:00:52'), 35 | ('3', '102', '1', '', '', '2020-01-02 12:51:23'), 36 | ('3', '102', '2', '', NULL, '2020-01-02 12:51:23'), 37 | ('4', '103', '1', '4', '', '2020-01-04 13:23:46'), 38 | ('4', '103', '1', '4', '', '2020-01-04 13:23:46'), 39 | ('4', '103', '2', '4', '', '2020-01-04 13:23:46'), 40 | ('5', '104', '1', 'null', '1', '2020-01-08 21:00:29'), 41 | ('6', '101', '2', 'null', 'null', '2020-01-08 21:03:13'), 42 | ('7', '105', '2', 'null', '1', '2020-01-08 21:20:29'), 43 | ('8', '102', '1', 'null', 'null', '2020-01-09 23:54:33'), 44 | ('9', '103', '1', '4', '1, 5', '2020-01-10 11:22:59'), 45 | ('10', '104', '1', 'null', 'null', '2020-01-11 18:34:49'), 46 | ('10', '104', '1', '2, 6', '1, 4', '2020-01-11 18:34:49'); 47 | 48 | 49 | DROP TABLE IF EXISTS runner_orders; 50 | CREATE TABLE runner_orders ( 51 | "order_id" INTEGER, 52 | "runner_id" INTEGER, 53 | "pickup_time" VARCHAR(19), 54 | "distance" VARCHAR(7), 55 | "duration" VARCHAR(10), 56 | "cancellation" VARCHAR(23) 57 | ); 58 | 59 | INSERT INTO runner_orders 60 | ("order_id", "runner_id", "pickup_time", "distance", "duration", "cancellation") 61 | VALUES 62 | ('1', '1', '2020-01-01 18:15:34', '20km', '32 minutes', ''), 63 | ('2', '1', '2020-01-01 19:10:54', '20km', '27 minutes', ''), 64 | ('3', '1', '2020-01-02 00:12:37', '13.4km', '20 mins', NULL), 65 | ('4', '2', '2020-01-04 13:53:03', '23.4', '40', NULL), 66 | ('5', '3', '2020-01-08 21:10:57', '10', '15', NULL), 67 | ('6', '3', 'null', 'null', 'null', 'Restaurant Cancellation'), 68 | ('7', '2', '2020-01-08 21:30:45', '25km', '25mins', 'null'), 69 | ('8', '2', '2020-01-10 00:15:02', '23.4 km', '15 minute', 'null'), 70 | ('9', '2', 'null', 'null', 'null', 'Customer Cancellation'), 71 | ('10', '1', '2020-01-11 18:50:20', '10km', '10minutes', 'null'); 72 | 73 | 74 | DROP TABLE IF EXISTS pizza_names; 75 | CREATE TABLE pizza_names ( 76 | "pizza_id" INTEGER, 77 | "pizza_name" TEXT 78 | ); 79 | INSERT INTO pizza_names 80 | ("pizza_id", "pizza_name") 81 | VALUES 82 | (1, 'Meatlovers'), 83 | (2, 'Vegetarian'); 84 | 85 | 86 | DROP TABLE IF EXISTS pizza_recipes; 87 | CREATE TABLE pizza_recipes ( 88 | "pizza_id" INTEGER, 89 | "toppings" TEXT 90 | ); 91 | INSERT INTO pizza_recipes 92 | ("pizza_id", "toppings") 93 | VALUES 94 | (1, '1, 2, 3, 4, 5, 6, 8, 10'), 95 | (2, '4, 6, 7, 9, 11, 12'); 96 | 97 | 98 | DROP TABLE IF EXISTS pizza_toppings; 99 | CREATE TABLE pizza_toppings ( 100 | "topping_id" INTEGER, 101 | "topping_name" TEXT 102 | ); 103 | INSERT INTO pizza_toppings 104 | ("topping_id", "topping_name") 105 | VALUES 106 | (1, 'Bacon'), 107 | (2, 'BBQ Sauce'), 108 | (3, 'Beef'), 109 | (4, 'Cheese'), 110 | (5, 'Chicken'), 111 | (6, 'Mushrooms'), 112 | (7, 'Onions'), 113 | (8, 'Pepperoni'), 114 | (9, 'Peppers'), 115 | (10, 'Salami'), 116 | (11, 'Tomatoes'), 117 | (12, 'Tomato Sauce'); 118 | -------------------------------------------------------------------------------- /Case Study #2: Pizza Runner/SQL_output/2. Solution_Pizza_Metrics: -------------------------------------------------------------------------------- 1 | -- Data with Danny - 8 Week Challenge (Week 2) 2 | -- https://8weeksqlchallenge.com/case-study-2/ 3 | 4 | -- Done with PostgreSQL 5 | 6 | --PART 1: PIZZA METRICS ! 7 | 8 | --1) How many pizzas were ordered? 9 | --2) How many unique customer orders were made? 10 | --3) How many successful orders were delivered by each runner? 11 | --4) How many of each type of pizza was delivered? 12 | --5) How many Vegetarian and Meatlovers were ordered by each customer? 13 | --6) What was the maximum number of pizzas delivered in a single order? 14 | --7) For each customer, how many delivered pizzas had at least 1 change and how many had no changes? 15 | --8) How many pizzas were delivered that had both exclusions and extras? 16 | --9) What was the total volume of pizzas ordered for each hour of the day? 17 | --10) What was the volume of orders for each day of the week? 18 | 19 | -------------------------------------------------------------------------------------------------------------------------------------------------------- 20 | -- BEFORE ANSWERING THE QUESTIONS, LET'S BEGIN BY FIXING THE TABLES 21 | 22 | 23 | DROP TABLE IF EXISTS customer_orders_cleaned; 24 | CREATE TEMP TABLE customer_orders_cleaned AS WITH first_layer AS ( 25 | SELECT 26 | order_id, 27 | customer_id, 28 | pizza_id, 29 | CASE 30 | WHEN exclusions = '' THEN NULL 31 | WHEN exclusions = 'null' THEN NULL 32 | ELSE exclusions 33 | END as exclusions, 34 | CASE 35 | WHEN extras = '' THEN NULL 36 | WHEN extras = 'null' THEN NULL 37 | ELSE extras 38 | END as extras, 39 | order_time 40 | FROM 41 | customer_orders 42 | ) 43 | SELECT 44 | ROW_NUMBER() OVER ( -- We are adding a row_number rank to deal with orders having multiple times the same pizza in it 45 | ORDER BY 46 | order_id, 47 | pizza_id 48 | ) AS row_number_order, 49 | order_id, 50 | customer_id, 51 | pizza_id, 52 | exclusions, 53 | extras, 54 | order_time 55 | FROM 56 | first_layer; 57 | 58 | --- 59 | 60 | 61 | DROP TABLE IF EXISTS runner_orders_cleaned; 62 | CREATE TEMP TABLE runner_orders_cleaned AS WITH first_layer AS ( 63 | SELECT 64 | order_id, 65 | runner_id, 66 | CAST( 67 | CASE 68 | WHEN pickup_time = 'null' THEN NULL 69 | ELSE pickup_time 70 | END AS timestamp 71 | ) AS pickup_time, 72 | CASE 73 | WHEN distance = '' THEN NULL 74 | WHEN distance = 'null' THEN NULL 75 | ELSE distance 76 | END as distance, 77 | CASE 78 | WHEN duration = '' THEN NULL 79 | WHEN duration = 'null' THEN NULL 80 | ELSE duration 81 | END as duration, 82 | CASE 83 | WHEN cancellation = '' THEN NULL 84 | WHEN cancellation = 'null' THEN NULL 85 | ELSE cancellation 86 | END as cancellation 87 | FROM 88 | runner_orders 89 | ) 90 | SELECT 91 | order_id, 92 | runner_id, 93 | CASE WHEN order_id = '3' THEN (pickup_time + INTERVAL '13 hour') ELSE pickup_time END AS pickup_time, 94 | CAST( regexp_replace(distance, '[a-z]+', '' ) AS DECIMAL(5,2) ) AS distance, 95 | CAST( regexp_replace(duration, '[a-z]+', '' ) AS INT ) AS duration, 96 | cancellation 97 | FROM 98 | first_layer; 99 | 100 | ------------------------------------------------------ 101 | --1) How many pizzas were ordered? 102 | 103 | SELECT 104 | COUNT(pizza_id) AS number_of_pizza_ordered 105 | FROM 106 | customer_orders_cleaned; 107 | 108 | | number_of_pizza_ordered | 109 | | ----------------------- | 110 | | 14 | 111 | 112 | ------------------------------------------------------ 113 | --2) How many unique customer orders were made? 114 | 115 | SELECT 116 | COUNT(DISTINCT order_id) AS distinct_orders 117 | FROM 118 | customer_orders_cleaned; 119 | 120 | | distinct_orders | 121 | | --------------- | 122 | | 10 | 123 | 124 | ------------------------------------------------------ 125 | --3) How many successful orders were delivered by each runner? 126 | 127 | SELECT 128 | COUNT(order_id) AS distinct_orders 129 | FROM 130 | runner_orders_cleaned 131 | WHERE 132 | cancellation IS NULL; 133 | 134 | | distinct_orders | 135 | | --------------- | 136 | | 8 | 137 | 138 | ------------------------------------------------------ 139 | --4) How many of each type of pizza was delivered? 140 | 141 | SELECT 142 | C.pizza_id, 143 | COUNT(C.pizza_id) as pizza_delivered 144 | FROM 145 | customer_orders_cleaned AS C 146 | LEFT JOIN runner_orders_cleaned AS R ON C.order_id = R.order_id 147 | WHERE 148 | R.cancellation IS NULL 149 | GROUP BY 150 | pizza_id; 151 | 152 | | pizza_id | pizza_delivered | 153 | | -------- | --------------- | 154 | | 1 | 9 | 155 | | 2 | 3 | 156 | 157 | ------------------------------------------------------ 158 | --5) How many Vegetarian and Meatlovers were ordered by each customer? 159 | 160 | SELECT 161 | customer_id, 162 | SUM(CASE WHEN pizza_id = 1 THEN 1 ELSE 0 END) as meatlovers, 163 | SUM(CASE WHEN pizza_id = 2 THEN 1 ELSE 0 END) as vegetarians 164 | FROM 165 | customer_orders_cleaned 166 | GROUP BY 167 | customer_id 168 | ORDER BY 169 | customer_id; 170 | 171 | | customer_id | meatlovers | vegetarians | 172 | | ----------- | ---------- | ----------- | 173 | | 101 | 2 | 1 | 174 | | 102 | 2 | 1 | 175 | | 103 | 3 | 1 | 176 | | 104 | 3 | 0 | 177 | | 105 | 0 | 1 | 178 | 179 | ------------------------------------------------------ 180 | --6) What was the maximum number of pizzas delivered in a single order? 181 | 182 | SELECT 183 | order_id, 184 | COUNT(pizza_id) as pizzas_delivered 185 | FROM 186 | customer_orders_cleaned 187 | GROUP BY 188 | order_id 189 | ORDER BY 190 | pizzas_delivered DESC; 191 | 192 | | order_id | pizzas_delivered | 193 | | -------- | ---------------- | 194 | | 4 | 3 | 195 | | 10 | 2 | 196 | | 3 | 2 | 197 | | 2 | 1 | 198 | | 7 | 1 | 199 | | 1 | 1 | 200 | | 9 | 1 | 201 | | 8 | 1 | 202 | | 5 | 1 | 203 | | 6 | 1 | 204 | 205 | ------------------------------------------------------ 206 | --7) For each customer, how many delivered pizzas had at least 1 change and how many had no changes? 207 | 208 | SELECT 209 | customer_id, 210 | SUM(CASE WHEN (exclusions IS NOT NULL OR extras IS NOT NULL) THEN 1 ELSE 0 END) as changes_performed, 211 | SUM(CASE WHEN (exclusions IS NULL AND extras IS NULL) THEN 1 ELSE 0 END) as no_changes 212 | FROM 213 | customer_orders_cleaned 214 | GROUP BY 215 | customer_id 216 | ORDER BY 217 | customer_id; 218 | 219 | | customer_id | changes_performed | no_changes | 220 | | ----------- | ----------------- | ---------- | 221 | | 101 | 0 | 3 | 222 | | 102 | 0 | 3 | 223 | | 103 | 4 | 0 | 224 | | 104 | 2 | 1 | 225 | | 105 | 1 | 0 | 226 | 227 | ------------------------------------------------------ 228 | --8) How many pizzas were delivered that had both exclusions and extras? 229 | 230 | SELECT 231 | SUM(CASE WHEN (exclusions IS NOT NULL AND extras IS NOT NULL) THEN 1 ELSE 0 END) as exclusions_and_extra 232 | FROM 233 | customer_orders_cleaned; 234 | 235 | | exclusions_and_extra | 236 | | -------------------- | 237 | | 2 | 238 | 239 | ------------------------------------------------------ 240 | --9) What was the total volume of pizzas ordered for each hour of the day? 241 | 242 | SELECT 243 | extract(hour from order_time) AS order_hour, 244 | COUNT(extract(hour from order_time)) AS count_pizza_ordered, 245 | ROUND( 100 * COUNT(extract(hour from order_time))/SUM(COUNT(*)) OVER (),2) AS volume_pizza_ordered 246 | FROM 247 | customer_orders_cleaned 248 | GROUP BY 249 | order_hour 250 | ORDER BY 251 | order_hour; 252 | 253 | | order_hour | count_pizza_ordered | volume_pizza_ordered | 254 | | ---------- | ------------------- | -------------------- | 255 | | 11 | 1 | 7.14 | 256 | | 12 | 2 | 14.29 | 257 | | 13 | 3 | 21.43 | 258 | | 18 | 3 | 21.43 | 259 | | 19 | 1 | 7.14 | 260 | | 21 | 3 | 21.43 | 261 | | 23 | 1 | 7.14 | 262 | 263 | ------------------------------------------------------ 264 | --10) What was the volume of orders for each day of the week? 265 | 266 | SELECT 267 | to_char(order_time, 'Day') AS day_ordered, 268 | COUNT(to_char(order_time, 'Day')) AS count_pizza_ordered, 269 | ROUND( 100 * COUNT(to_char(order_time, 'Day'))/SUM(COUNT(*)) OVER (),2) AS volume_pizza_ordered 270 | FROM 271 | customer_orders_cleaned 272 | GROUP BY 273 | day_ordered 274 | ORDER BY 275 | day_ordered; 276 | 277 | | day_ordered | count_pizza_ordered | volume_pizza_ordered | 278 | | ----------- | ------------------- | -------------------- | 279 | | Friday | 1 | 7.14 | 280 | | Saturday | 5 | 35.71 | 281 | | Thursday | 3 | 21.43 | 282 | | Wednesday | 5 | 35.71 | 283 | 284 | ------------------------------------------------------ 285 | 286 | [View on DB Fiddle](https://www.db-fiddle.com/f/7VcQKQwsS3CTkGRFG7vu98/4) 287 | -------------------------------------------------------------------------------- /Case Study #2: Pizza Runner/SQL_output/3. Solution_Runner_and_Customer_Experience: -------------------------------------------------------------------------------- 1 | -- Data with Danny - 8 Week Challenge (Week 2) 2 | -- https://8weeksqlchallenge.com/case-study-2/ 3 | 4 | -- Done with PostgreSQL 5 | 6 | --PART 2: Runner and Customer Experience! 7 | 8 | --1) How many runners signed up for each 1 week period? (i.e. week starts 2021-01-01) 9 | --2) What was the average time in minutes it took for each runner to arrive at the Pizza Runner HQ to pickup the order? 10 | --3) Is there any relationship between the number of pizzas and how long the order takes to prepare? 11 | --4) What was the average distance travelled for each customer? 12 | --5) What was the difference between the longest and shortest delivery times for all orders? 13 | --6) What was the average speed for each runner for each delivery and do you notice any trend for these values? 14 | --7) What is the successful delivery percentage for each runner? 15 | 16 | -------------------------------------------------------------------------------------------------------------------------------------------------------- 17 | --Previous tables which we will still use for this part: 18 | 19 | 20 | DROP TABLE IF EXISTS runner_orders_cleaned; 21 | CREATE TEMP TABLE runner_orders_cleaned AS WITH first_layer AS ( 22 | SELECT 23 | order_id, 24 | runner_id, 25 | CAST( 26 | CASE 27 | WHEN pickup_time = 'null' THEN NULL 28 | ELSE pickup_time 29 | END AS timestamp 30 | ) AS pickup_time, 31 | CASE 32 | WHEN distance = '' THEN NULL 33 | WHEN distance = 'null' THEN NULL 34 | ELSE distance 35 | END as distance, 36 | CASE 37 | WHEN duration = '' THEN NULL 38 | WHEN duration = 'null' THEN NULL 39 | ELSE duration 40 | END as duration, 41 | CASE 42 | WHEN cancellation = '' THEN NULL 43 | WHEN cancellation = 'null' THEN NULL 44 | ELSE cancellation 45 | END as cancellation 46 | FROM 47 | runner_orders 48 | ) 49 | SELECT 50 | order_id, 51 | runner_id, 52 | pickup_time, 53 | CAST( regexp_replace(distance, '[a-z]+', '' ) AS DECIMAL(5,2) ) AS distance, 54 | CAST( regexp_replace(duration, '[a-z]+', '' ) AS INT ) AS duration, 55 | cancellation 56 | FROM 57 | first_layer; 58 | 59 | --- 60 | 61 | DROP TABLE IF EXISTS customer_orders_cleaned; 62 | CREATE TEMP TABLE customer_orders_cleaned AS WITH first_layer AS ( 63 | SELECT 64 | order_id, 65 | customer_id, 66 | pizza_id, 67 | CASE 68 | WHEN exclusions = '' THEN NULL 69 | WHEN exclusions = 'null' THEN NULL 70 | ELSE exclusions 71 | END as exclusions, 72 | CASE 73 | WHEN extras = '' THEN NULL 74 | WHEN extras = 'null' THEN NULL 75 | ELSE extras 76 | END as extras, 77 | order_time 78 | FROM 79 | customer_orders 80 | ) 81 | SELECT 82 | ROW_NUMBER() OVER ( -- We are adding a row_number rank to deal with orders having multiple times the same pizza in it 83 | ORDER BY 84 | order_id, 85 | pizza_id 86 | ) AS row_number_order, 87 | order_id, 88 | customer_id, 89 | pizza_id, 90 | exclusions, 91 | extras, 92 | order_time 93 | FROM 94 | first_layer; 95 | 96 | 97 | 98 | --- 99 | -- New temp table for this part 100 | 101 | DROP TABLE IF EXISTS parties_experience; 102 | CREATE TEMP TABLE parties_experience AS 103 | SELECT 104 | C.order_id, 105 | C.customer_id, 106 | C.pizza_id, 107 | R.runner_id, 108 | R.distance, 109 | R.duration, 110 | C.order_time, 111 | R.pickup_time 112 | FROM 113 | customer_orders_cleaned AS C 114 | LEFT JOIN runner_orders_cleaned AS R ON C.order_id = R.order_id 115 | WHERE 116 | R.cancellation IS NULL 117 | ORDER BY 118 | order_id; 119 | 120 | ------------------------------------------------------ 121 | --1) How many runners signed up for each 1 week period? (i.e. week starts 2021-01-01) 122 | 123 | SELECT 124 | week_signed_up, 125 | COUNT(week_signed_up) as runners_signed_up 126 | FROM 127 | ( 128 | SELECT 129 | runner_id, 130 | CAST(to_char(registration_date, 'WW') AS NUMERIC) AS week_signed_up 131 | FROM 132 | runners) AS runner_sign_date 133 | GROUP BY 134 | week_signed_up 135 | ORDER BY 136 | week_signed_up; 137 | 138 | | week_signed_up | runners_signed_up | 139 | | -------------- | ----------------- | 140 | | 1 | 2 | 141 | | 2 | 1 | 142 | | 3 | 1 | 143 | 144 | ------------------------------------------------------ 145 | --2) What was the average time in minutes it took for each runner to arrive at the Pizza Runner HQ to pickup the order? 146 | 147 | SELECT 148 | runner_id, 149 | ROUND( 150 | CAST( 151 | AVG( 152 | ( 153 | DATE_PART('hour', pickup_time - order_time) * 60 + DATE_PART('minute', pickup_time - order_time) 154 | ) * 60 + DATE_PART('second', pickup_time - order_time) 155 | ) AS NUMERIC 156 | ), 157 | 2 158 | ) AS avg_delivery_time 159 | FROM 160 | parties_experience 161 | GROUP BY 162 | runner_id 163 | ORDER BY 164 | runner_id; 165 | 166 | | runner_id | avg_delivery_time | 167 | | --------- | ----------------- | 168 | | 1 | 940.67 | 169 | | 2 | 1423.20 | 170 | | 3 | 628.00 | 171 | 172 | ------------------------------------------------------ 173 | --3) Is there any relationship between the number of pizzas and how long the order takes to prepare? 174 | 175 | SELECT 176 | count_pizza_ordered, 177 | ROUND(AVG(avg_delivery_time),2) AS avg_preparation_time_seconds 178 | FROM 179 | ( 180 | SELECT 181 | order_id, 182 | COUNT(pizza_id) AS count_pizza_ordered, 183 | ROUND(CAST(AVG((DATE_PART('hour', pickup_time - order_time) * 60 184 | + DATE_PART('minute', pickup_time - order_time)) * 60 185 | + DATE_PART('second', pickup_time - order_time)) AS NUMERIC),2) AS avg_delivery_time 186 | FROM 187 | parties_experience 188 | GROUP BY 189 | order_id) AS order_metrics 190 | GROUP BY 191 | count_pizza_ordered 192 | ORDER BY 193 | count_pizza_ordered; 194 | 195 | | count_pizza_ordered | avg_preparation_time_seconds | 196 | | ------------------- | ---------------------------- | 197 | | 1 | 741.40 | 198 | | 2 | 1102.50 | 199 | | 3 | 1757.00 | 200 | 201 | 202 | -- The number of pizzas ordered seems to be correlated to the preparation time 203 | 204 | 205 | ------------------------------------------------------ 206 | --4) What was the average distance travelled for each customer? 207 | 208 | SELECT 209 | customer_id, 210 | ROUND(AVG(distance),2) 211 | FROM 212 | parties_experience 213 | GROUP BY 214 | customer_id 215 | ORDER BY 216 | customer_id; 217 | 218 | | customer_id | round | 219 | | ----------- | ----- | 220 | | 101 | 20.00 | 221 | | 102 | 16.73 | 222 | | 103 | 23.40 | 223 | | 104 | 10.00 | 224 | | 105 | 25.00 | 225 | 226 | ------------------------------------------------------ 227 | --5) What was the difference between the longest and shortest delivery times for all orders? 228 | 229 | SELECT 230 | max_duration - min_duration AS difference_delivery_time_seconds 231 | FROM 232 | ( 233 | SELECT 234 | MAX(duration) AS max_duration, 235 | MIN(duration) AS min_duration 236 | FROM 237 | parties_experience) as first_layer; 238 | 239 | | difference_delivery_time_seconds | 240 | | -------------------------------- | 241 | | 30 | 242 | 243 | ------------------------------------------------------ 244 | --6) What was the average speed for each runner for each delivery and do you notice any trend for these values? 245 | 246 | SELECT 247 | runner_id, 248 | order_id, 249 | ROUND( 250 | (distance::NUMERIC/(duration::NUMERIC/60)),2) AS speed, 251 | distance 252 | FROM 253 | parties_experience 254 | GROUP BY 255 | runner_id, 256 | order_id, 257 | speed, 258 | distance 259 | ORDER BY 260 | runner_id, order_id; 261 | 262 | | runner_id | order_id | speed | distance | 263 | | --------- | -------- | ----- | -------- | 264 | | 1 | 1 | 37.50 | 20.00 | 265 | | 1 | 2 | 44.44 | 20.00 | 266 | | 1 | 3 | 40.20 | 13.40 | 267 | | 1 | 10 | 60.00 | 10.00 | 268 | | 2 | 4 | 35.10 | 23.40 | 269 | | 2 | 7 | 60.00 | 25.00 | 270 | | 2 | 8 | 93.60 | 23.40 | 271 | | 3 | 5 | 40.00 | 10.00 | 272 | 273 | ------------------------------------------------------ 274 | --7) What is the successful delivery percentage for each runner? 275 | 276 | --UPDATE TEMP TABLE, this time taking in account the NULL values: 277 | DROP TABLE IF EXISTS parties_experience; 278 | CREATE TEMP TABLE parties_experience AS 279 | SELECT 280 | C.order_id, 281 | C.customer_id, 282 | C.pizza_id, 283 | R.runner_id, 284 | R.distance, 285 | R.duration, 286 | C.order_time, 287 | R.pickup_time, 288 | R.cancellation 289 | FROM 290 | customer_orders_cleaned AS C 291 | LEFT JOIN runner_orders_cleaned AS R ON C.order_id = R.order_id 292 | ORDER BY 293 | order_id; 294 | --- 295 | 296 | SELECT 297 | runner_id, 298 | ROUND( 299 | 100 * SUM(successful_orders::numeric) / COUNT(successful_orders::numeric),2) AS percentage_successful_delivery 300 | FROM 301 | (SELECT 302 | runner_id, 303 | order_id, 304 | CASE WHEN cancellation IS NOT NULL then 0 ELSE 1 END AS successful_orders 305 | FROM 306 | parties_experience 307 | GROUP BY 308 | runner_id, 309 | order_id, 310 | cancellation 311 | ORDER BY 312 | runner_id, order_id) as first_layer 313 | GROUP BY 314 | runner_id; 315 | 316 | | runner_id | percentage_successful_delivery | 317 | | --------- | ------------------------------ | 318 | | 1 | 100.00 | 319 | | 2 | 75.00 | 320 | | 3 | 50.00 | 321 | 322 | ------------------------------------------------------ 323 | 324 | [View on DB Fiddle](https://www.db-fiddle.com/f/7VcQKQwsS3CTkGRFG7vu98/4) 325 | -------------------------------------------------------------------------------- /Case Study #2: Pizza Runner/SQL_output/4. Ingredient_Optimisation: -------------------------------------------------------------------------------- 1 | -- Data with Danny - 8 Week Challenge (Week 2) 2 | -- https://8weeksqlchallenge.com/case-study-2/ 3 | 4 | -- Done with PostgreSQL 5 | 6 | --PART 3: Ingredient Optimisation! 7 | 8 | --Questions: 9 | -- 1) What are the standard ingredients for each pizza? 10 | -- 2) What was the most commonly added extra? 11 | -- 3) What was the most common exclusion? 12 | -- 4) Generate an order item for each record in the customers_orders table in the format of one of the following: 13 | -- Meat Lovers 14 | -- Meat Lovers - Exclude Beef 15 | -- Meat Lovers - Extra Bacon 16 | -- Meat Lovers - Exclude Cheese, Bacon - Extra Mushroom, Peppers 17 | -- 5) Generate an alphabetically ordered comma separated ingredient list for each pizza order from the customer_orders table and add a 2x in front of any relevant ingredients 18 | -- For example: "Meat Lovers: 2xBacon, Beef, ... , Salami" 19 | -- 6) What is the total quantity of each ingredient used in all delivered pizzas sorted by most frequent first? 20 | 21 | -------------------------------------------------------------------------------------------------------------------------------------------------------- 22 | 23 | --Previous tables which we will still use for this part: 24 | 25 | DROP TABLE IF EXISTS customer_orders_cleaned; 26 | CREATE TEMP TABLE customer_orders_cleaned AS WITH first_layer AS ( 27 | SELECT 28 | order_id, 29 | customer_id, 30 | pizza_id, 31 | CASE 32 | WHEN exclusions = '' THEN NULL 33 | WHEN exclusions = 'null' THEN NULL 34 | ELSE exclusions 35 | END as exclusions, 36 | CASE 37 | WHEN extras = '' THEN NULL 38 | WHEN extras = 'null' THEN NULL 39 | ELSE extras 40 | END as extras, 41 | order_time 42 | FROM 43 | customer_orders 44 | ) 45 | SELECT 46 | ROW_NUMBER() OVER ( 47 | ORDER BY 48 | order_id, 49 | pizza_id 50 | ) AS row_number_order, 51 | order_id, 52 | customer_id, 53 | pizza_id, 54 | exclusions, 55 | extras, 56 | order_time 57 | FROM 58 | first_layer; 59 | 60 | --- 61 | 62 | 63 | DROP TABLE IF EXISTS runner_orders_cleaned; 64 | CREATE TEMP TABLE runner_orders_cleaned AS WITH first_layer AS ( 65 | SELECT 66 | order_id, 67 | runner_id, 68 | CAST( 69 | CASE 70 | WHEN pickup_time = 'null' THEN NULL 71 | ELSE pickup_time 72 | END AS timestamp 73 | ) AS pickup_time, 74 | CASE 75 | WHEN distance = '' THEN NULL 76 | WHEN distance = 'null' THEN NULL 77 | ELSE distance 78 | END as distance, 79 | CASE 80 | WHEN duration = '' THEN NULL 81 | WHEN duration = 'null' THEN NULL 82 | ELSE duration 83 | END as duration, 84 | CASE 85 | WHEN cancellation = '' THEN NULL 86 | WHEN cancellation = 'null' THEN NULL 87 | ELSE cancellation 88 | END as cancellation 89 | FROM 90 | runner_orders 91 | ) 92 | SELECT 93 | order_id, 94 | runner_id, 95 | CASE WHEN order_id = '3' THEN (pickup_time + INTERVAL '13 hour') ELSE pickup_time END AS pickup_time, 96 | CAST( regexp_replace(distance, '[a-z]+', '' ) AS DECIMAL(5,2) ) AS distance, 97 | CAST( regexp_replace(duration, '[a-z]+', '' ) AS INT ) AS duration, 98 | cancellation 99 | FROM 100 | first_layer; 101 | 102 | 103 | 104 | ------------------------------------------------------ 105 | -- 1) What are the standard ingredients for each pizza? 106 | 107 | WITH pizza_recipes_unstacked AS ( 108 | SELECT 109 | pizza_id, 110 | CAST( 111 | UNNEST( 112 | string_to_array(toppings, ', ') 113 | ) AS INT 114 | ) AS topping_id 115 | FROM 116 | pizza_recipes 117 | ) 118 | SELECT 119 | t1.pizza_id, 120 | t1.pizza_name, 121 | t2.topping_id, 122 | t3.topping_name 123 | FROM 124 | pizza_names t1 125 | JOIN pizza_recipes_unstacked t2 ON t1.pizza_id = t2.pizza_id 126 | JOIN pizza_toppings t3 ON t2.topping_id = t3.topping_id 127 | ORDER BY 128 | t1.pizza_id, 129 | t2.topping_id; 130 | 131 | | pizza_id | pizza_name | topping_id | topping_name | 132 | | -------- | ---------- | ---------- | ------------ | 133 | | 1 | Meatlovers | 1 | Bacon | 134 | | 1 | Meatlovers | 2 | BBQ Sauce | 135 | | 1 | Meatlovers | 3 | Beef | 136 | | 1 | Meatlovers | 4 | Cheese | 137 | | 1 | Meatlovers | 5 | Chicken | 138 | | 1 | Meatlovers | 6 | Mushrooms | 139 | | 1 | Meatlovers | 8 | Pepperoni | 140 | | 1 | Meatlovers | 10 | Salami | 141 | | 2 | Vegetarian | 4 | Cheese | 142 | | 2 | Vegetarian | 6 | Mushrooms | 143 | | 2 | Vegetarian | 7 | Onions | 144 | | 2 | Vegetarian | 9 | Peppers | 145 | 146 | ------------------------------------------------------ 147 | --2) What was the most commonly added extra? 148 | 149 | SELECT 150 | extras, 151 | topping_name, 152 | COUNT(extras) AS times_ordered 153 | FROM 154 | ( 155 | SELECT 156 | order_id, 157 | CAST( 158 | UNNEST(string_to_array(extras, ', ')) AS INT 159 | ) AS extras 160 | FROM 161 | customer_orders_cleaned 162 | ) AS extras_information 163 | JOIN pizza_toppings ON pizza_toppings.topping_id = extras_information.extras 164 | GROUP BY 165 | extras, 166 | topping_name 167 | ORDER BY 168 | times_ordered DESC; 169 | 170 | | extras | topping_name | times_ordered | 171 | | ------ | ------------ | ------------- | 172 | | 1 | Bacon | 4 | 173 | | 4 | Cheese | 1 | 174 | | 5 | Chicken | 1 | 175 | 176 | ------------------------------------------------------ 177 | -- 3) What was the most common exclusion? 178 | 179 | SELECT 180 | exclusions, 181 | topping_name, 182 | COUNT(exclusions) AS times_ordered 183 | FROM 184 | ( 185 | SELECT 186 | order_id, 187 | CAST( 188 | UNNEST(string_to_array(exclusions, ', ')) AS INT 189 | ) AS exclusions 190 | FROM 191 | customer_orders_cleaned 192 | ) AS exclusions_information 193 | JOIN pizza_toppings ON pizza_toppings.topping_id = exclusions_information.exclusions 194 | GROUP BY 195 | exclusions, 196 | topping_name 197 | ORDER BY 198 | times_ordered DESC; 199 | 200 | | exclusions | topping_name | times_ordered | 201 | | ---------- | ------------ | ------------- | 202 | | 4 | Cheese | 4 | 203 | | 2 | BBQ Sauce | 1 | 204 | | 6 | Mushrooms | 1 | 205 | 206 | ------------------------------------------------------ 207 | -- 4) Generate an order item for each record in the customers_orders table in the format of one of the following: 208 | -- Meat Lovers 209 | -- Meat Lovers - Exclude Beef 210 | -- Meat Lovers - Extra Bacon 211 | -- Meat Lovers - Exclude Cheese, Bacon - Extra Mushroom, Peppers 212 | 213 | DROP VIEW IF EXISTS extras_exclusions; 214 | CREATE VIEW extras_exclusions AS 215 | SELECT 216 | order_id, 217 | customers_info.pizza_id, 218 | pizza_names.pizza_name, 219 | exclusion_col1, 220 | top1.topping_name AS topping_name1, 221 | CASE 222 | WHEN exclusion_col2 = '' THEN NULL 223 | ELSE TRIM(exclusion_col2) :: INTEGER 224 | END as exclusion_col2, 225 | extras_col1, 226 | top2.topping_name AS topping_name3, 227 | CASE 228 | WHEN extras_col2 = '' THEN NULL 229 | ELSE TRIM(extras_col2) :: INTEGER 230 | END as extras_col2 231 | FROM 232 | ( 233 | SELECT 234 | order_id, 235 | pizza_id, 236 | split_part(exclusions, ',', 1) AS exclusion_col1, 237 | split_part(exclusions, ',', 2) AS exclusion_col2, 238 | split_part(extras, ',', 1) AS extras_col1, 239 | split_part(extras, ',', 2) AS extras_col2 240 | FROM 241 | customer_orders_cleaned 242 | ORDER BY 243 | order_id 244 | ) AS customers_info 245 | JOIN pizza_names ON customers_info.pizza_id = pizza_names.pizza_id 246 | LEFT JOIN pizza_toppings top1 ON customers_info.exclusion_col1 :: INT = top1.topping_id 247 | LEFT JOIN pizza_toppings top2 ON customers_info.extras_col1 :: INT = top2.topping_id; 248 | 249 | --- 250 | 251 | SELECT 252 | order_id, 253 | CONCAT(pizza_name, ' ', exclusions, ' ', extras) AS pizza_details 254 | FROM 255 | ( 256 | WITH tabular_modifications AS( 257 | SELECT 258 | order_id, 259 | pizza_id, 260 | pizza_name, 261 | exclusion_col1, 262 | topping_name1, 263 | exclusion_col2 :: INT, 264 | t2.topping_name AS topping_name2, 265 | extras_col1, 266 | topping_name3, 267 | extras_col2 :: INT, 268 | t3.topping_name AS topping_name4 269 | FROM 270 | extras_exclusions t1 271 | LEFT JOIN pizza_toppings t2 ON t1.exclusion_col2 = t2.topping_id 272 | LEFT JOIN pizza_toppings t3 ON t1.extras_col2 = t3.topping_id 273 | ) 274 | SELECT 275 | order_id, 276 | pizza_id, 277 | pizza_name, 278 | CASE 279 | WHEN exclusion_col1 IS NULL THEN CONCAT(topping_name1, ' ', topping_name2) 280 | WHEN exclusion_col2 IS NULL THEN CONCAT('- Exclude', ' ', topping_name1) 281 | ELSE CONCAT('- Exclude', ' ', topping_name1, ', ', topping_name2) 282 | END AS exclusions, 283 | CASE 284 | WHEN extras_col1 IS NULL THEN CONCAT(topping_name3, ' ', topping_name4) 285 | WHEN extras_col2 IS NULL THEN CONCAT('- Extra', ' ', topping_name3) 286 | ELSE CONCAT('- Extra', ' ', topping_name3, ', ', topping_name4) 287 | END AS extras 288 | FROM 289 | tabular_modifications 290 | ) AS Modified_concat 291 | ORDER BY 292 | order_id; 293 | 294 | | order_id | pizza_details | 295 | | -------- | --------------------------------------------------------------- | 296 | | 1 | Meatlovers | 297 | | 2 | Meatlovers | 298 | | 3 | Vegetarian | 299 | | 3 | Meatlovers | 300 | | 4 | Meatlovers - Exclude Cheese | 301 | | 4 | Meatlovers - Exclude Cheese | 302 | | 4 | Vegetarian - Exclude Cheese | 303 | | 5 | Meatlovers - Extra Bacon | 304 | | 6 | Vegetarian | 305 | | 7 | Vegetarian - Extra Bacon | 306 | | 8 | Meatlovers | 307 | | 9 | Meatlovers - Exclude Cheese - Extra Bacon, Chicken | 308 | | 10 | Meatlovers - Exclude BBQ Sauce, Mushrooms - Extra Bacon, Cheese | 309 | | 10 | Meatlovers | 310 | 311 | ------------------------------------------------------ 312 | -- 5) Generate an alphabetically ordered comma separated ingredient list for each pizza order from the customer_orders table and add a 2x in front of any relevant ingredients 313 | -- For example: "Meat Lovers: 2xBacon, Beef, ... , Salami" 314 | 315 | -- Step 1: create basic recipe table (recycling question 1) 316 | DROP TABLE IF EXISTS classical_recipe; 317 | CREATE TEMP TABLE classical_recipe AS 318 | WITH pizza_recipes_unstacked AS ( 319 | SELECT 320 | pizza_id, 321 | CAST( 322 | UNNEST( 323 | string_to_array(toppings, ', ') 324 | ) AS INT 325 | ) AS topping_id 326 | FROM 327 | pizza_recipes 328 | ) 329 | SELECT 330 | t4.row_number_order, 331 | t4.order_id, 332 | t4.customer_id, 333 | t1.pizza_id, 334 | t1.pizza_name, 335 | t2.topping_id, 336 | t3.topping_name 337 | FROM 338 | pizza_names t1 339 | JOIN pizza_recipes_unstacked t2 ON t1.pizza_id = t2.pizza_id 340 | JOIN pizza_toppings t3 ON t2.topping_id = t3.topping_id 341 | RIGHT JOIN customer_orders_cleaned t4 ON t1.pizza_id = t4.pizza_id; 342 | 343 | 344 | 345 | -- Step 2: unpivot extras and exclusions table into 2 separated table: 346 | 347 | DROP TABLE IF EXISTS orders_exclusions; 348 | CREATE TEMP TABLE orders_exclusions AS 349 | SELECT 350 | row_number_order, 351 | order_id, 352 | customer_id, 353 | customer_orders_cleaned.pizza_id, 354 | pizza_name, 355 | CAST(UNNEST(string_to_array(COALESCE(exclusions, '0'), ',')) AS INT) AS exclusions 356 | FROM 357 | customer_orders_cleaned 358 | JOIN pizza_names ON customer_orders_cleaned.pizza_id = pizza_names.pizza_id 359 | ORDER BY 360 | order_id; 361 | 362 | --- 363 | 364 | DROP TABLE IF EXISTS orders_extras; 365 | CREATE TEMP TABLE orders_extras AS 366 | SELECT 367 | row_number_order, 368 | order_id, 369 | customer_id, 370 | customer_orders_cleaned.pizza_id, 371 | pizza_name, 372 | CAST(UNNEST(string_to_array(COALESCE(extras, '0'), ',')) AS INT) AS extras 373 | FROM 374 | customer_orders_cleaned 375 | JOIN pizza_names ON customer_orders_cleaned.pizza_id = pizza_names.pizza_id 376 | ORDER BY 377 | order_id; 378 | 379 | 380 | --step 3: Join all the tables (Union extras, Except exclusions): 381 | 382 | DROP TABLE IF EXISTS pizzas_details; 383 | CREATE TEMP TABLE pizzas_details AS 384 | WITH first_layer AS (SELECT 385 | row_number_order, 386 | order_id, 387 | customer_id, 388 | pizza_id, 389 | pizza_name, 390 | topping_id 391 | FROM 392 | classical_recipe 393 | EXCEPT 394 | SELECT 395 | * 396 | FROM 397 | orders_exclusions 398 | UNION ALL 399 | SELECT 400 | * 401 | FROM 402 | orders_extras 403 | WHERE 404 | extras != 0) 405 | SELECT 406 | row_number_order, 407 | order_id, 408 | customer_id, 409 | pizza_id, 410 | pizza_name, 411 | first_layer.topping_id, 412 | topping_name 413 | FROM 414 | first_layer 415 | LEFT JOIN pizza_toppings ON first_layer.topping_id = pizza_toppings.topping_id 416 | ORDER BY 417 | row_number_order, 418 | order_id, 419 | pizza_id, 420 | topping_id; 421 | 422 | 423 | -- Step 4: let's now reshape the data to answer the question 424 | 425 | WITH counting_table AS( 426 | SELECT 427 | row_number_order, 428 | order_id, 429 | customer_id 430 | pizza_id, 431 | pizza_name, 432 | topping_id, 433 | topping_name, 434 | COUNT(topping_id) AS count_ingredient 435 | FROM 436 | pizzas_details 437 | GROUP BY 438 | row_number_order, 439 | order_id, 440 | customer_id, 441 | pizza_id, 442 | pizza_name, 443 | topping_id, 444 | topping_name) 445 | , text_table AS( 446 | SELECT 447 | row_number_order, 448 | order_id, 449 | pizza_id, 450 | pizza_name, 451 | topping_id, 452 | CASE WHEN count_ingredient = 1 THEN topping_name 453 | ELSE CONCAT(count_ingredient, 'x ',topping_name) END AS ingredient_count 454 | FROM 455 | counting_table) 456 | , group_text AS( 457 | SELECT 458 | row_number_order, 459 | order_id, 460 | pizza_id, 461 | pizza_name, 462 | STRING_AGG(ingredient_count, ', ') AS recipe 463 | FROM 464 | text_table 465 | GROUP BY 466 | row_number_order, 467 | order_id, 468 | pizza_id, 469 | pizza_name) 470 | SELECT 471 | row_number_order, 472 | order_id, 473 | CONCAT(pizza_name, ': ', recipe) 474 | FROM 475 | group_text 476 | ORDER BY 477 | row_number_order, order_id; 478 | 479 | | row_number_order | order_id | concat | 480 | | ---------------- | -------- | ------------------------------------------------------------------------------------ | 481 | | 1 | 1 | Meatlovers: Cheese, Chicken, Salami, Bacon, Beef, Pepperoni, Mushrooms, BBQ Sauce | 482 | | 2 | 2 | Meatlovers: Chicken, BBQ Sauce, Pepperoni, Salami, Cheese, Beef, Bacon, Mushrooms | 483 | | 3 | 3 | Meatlovers: Salami, Chicken, BBQ Sauce, Beef, Bacon, Mushrooms, Pepperoni, Cheese | 484 | | 4 | 3 | Vegetarian: Onions, Tomato Sauce, Mushrooms, Tomatoes, Peppers, Cheese | 485 | | 5 | 4 | Meatlovers: BBQ Sauce, Mushrooms, Beef, Salami, Pepperoni, Bacon, Chicken | 486 | | 6 | 4 | Meatlovers: Chicken, Mushrooms, Beef, Pepperoni, Bacon, BBQ Sauce, Salami | 487 | | 7 | 4 | Vegetarian: Tomato Sauce, Onions, Tomatoes, Peppers, Mushrooms | 488 | | 8 | 5 | Meatlovers: Cheese, Pepperoni, BBQ Sauce, 2x Bacon, Chicken, Salami, Mushrooms, Beef | 489 | | 9 | 6 | Vegetarian: Tomato Sauce, Onions, Mushrooms, Cheese, Tomatoes, Peppers | 490 | | 10 | 7 | Vegetarian: Mushrooms, Bacon, Tomato Sauce, Peppers, Onions, Tomatoes, Cheese | 491 | | 11 | 8 | Meatlovers: Pepperoni, Beef, Salami, Cheese, Bacon, Mushrooms, Chicken, BBQ Sauce | 492 | | 12 | 9 | Meatlovers: Beef, Pepperoni, Mushrooms, 2x Chicken, 2x Bacon, BBQ Sauce, Salami | 493 | | 13 | 10 | Meatlovers: Mushrooms, Chicken, Bacon, Salami, Cheese, BBQ Sauce, Beef, Pepperoni | 494 | | 14 | 10 | Meatlovers: 2x Bacon, Chicken, Beef, 2x Cheese, Salami, Pepperoni | 495 | 496 | ------------------------------------------------------ 497 | -- 6) What is the total quantity of each ingredient used in all delivered pizzas sorted by most frequent first? 498 | 499 | SELECT 500 | topping_id, 501 | topping_name, 502 | COUNT(topping_id) as time_used 503 | FROM 504 | pizzas_details 505 | GROUP BY 506 | topping_id, 507 | topping_name 508 | ORDER BY 509 | time_used DESC; 510 | 511 | | topping_id | topping_name | time_used | 512 | | ---------- | ------------ | --------- | 513 | | 1 | Bacon | 14 | 514 | | 6 | Mushrooms | 13 | 515 | | 5 | Chicken | 11 | 516 | | 4 | Cheese | 11 | 517 | | 8 | Pepperoni | 10 | 518 | | 10 | Salami | 10 | 519 | | 3 | Beef | 10 | 520 | | 2 | BBQ Sauce | 9 | 521 | | 9 | Peppers | 4 | 522 | | 7 | Onions | 4 | 523 | | 11 | Tomatoes | 4 | 524 | | 12 | Tomato Sauce | 4 | 525 | 526 | --- 527 | 528 | [View on DB Fiddle](https://www.db-fiddle.com/f/7VcQKQwsS3CTkGRFG7vu98/4) 529 | -------------------------------------------------------------------------------- /Case Study #2: Pizza Runner/SQL_output/5. Pricing_And_Ratings: -------------------------------------------------------------------------------- 1 | -- Data with Danny - 8 Week Challenge (Week 2) 2 | -- https://8weeksqlchallenge.com/case-study-2/ 3 | 4 | -- Done with PostgreSQL 5 | 6 | PART 4: Pricing and Ratings! 7 | 8 | 9 | --Questions: 10 | -- 1) If a Meat Lovers pizza costs $12 and Vegetarian costs $10 and there were no charges for changes - how much money has Pizza Runner 11 | -- made so far if there are no delivery fees? 12 | -- 2) What if there was an additional $1 charge for any pizza extras? 13 | -- - Add cheese is $1 extra 14 | -- 3) What if substitutes were allowed at no additional cost but any additional extras were charged at $1? 15 | -- - Exclude Cheese and add Bacon is free 16 | -- - Exclude Cheese but add bacon and beef costs $1 extra 17 | -- 4) What if meat substitutes and vegetable substitutes were allowed but any change outside were charged at $2 and $1 respectively? 18 | -- - Exclude Cheese and add Bacon is $2 extra 19 | -- - Exclude Beef and add mushroom is $1 extra 20 | -- - Exclude Beef and add Bacon is free 21 | -- - Exclude Beef and Mushroom, and add Bacon and Cheese is free 22 | -- 5)The Pizza Runner team now wants to add an additional ratings system that allows customers to rate their runner, 23 | -- how would you design an additional table for this new dataset - generate a schema for this new table and insert 24 | -- your own data for ratings for each successful customer order between 1 to 5. 25 | -- 6)Using your newly generated table - can you join all of the information together to form a table which has the following information for successful deliveries? 26 | -- - customer_id 27 | -- - order_id 28 | -- - runner_id 29 | -- - rating 30 | -- - order_time 31 | -- - pickup_time 32 | -- - Time between order and pickup 33 | -- - Delivery duration 34 | -- - Average speed 35 | -- - Total number of pizzas 36 | -- 7) If a Meat Lovers pizza was $12 and Vegetarian $10 fixed prices with no cost for extras and each runner is paid $0.30 per kilometre 37 | -- traveled - how much money does Pizza Runner have left over after these deliveries? 38 | -- 8) If 1 unit of each ingredient costs $0.50 - how much net revenue will Pizza Runner make if the costs from question 30 are used? 39 | 40 | 41 | -------------------------------------------------------------------------------------------------------------------------------------------------------- 42 | 43 | --Previous tables which we will still use for this part: 44 | 45 | 46 | DROP TABLE IF EXISTS customer_orders_cleaned; 47 | CREATE TEMP TABLE customer_orders_cleaned AS WITH first_layer AS ( 48 | SELECT 49 | order_id, 50 | customer_id, 51 | pizza_id, 52 | CASE 53 | WHEN exclusions = '' THEN NULL 54 | WHEN exclusions = 'null' THEN NULL 55 | ELSE exclusions 56 | END as exclusions, 57 | CASE 58 | WHEN extras = '' THEN NULL 59 | WHEN extras = 'null' THEN NULL 60 | ELSE extras 61 | END as extras, 62 | order_time 63 | FROM 64 | customer_orders 65 | ) 66 | SELECT 67 | ROW_NUMBER() OVER ( 68 | ORDER BY 69 | order_id, 70 | pizza_id 71 | ) AS row_number_order, 72 | order_id, 73 | customer_id, 74 | pizza_id, 75 | exclusions, 76 | extras, 77 | order_time 78 | FROM 79 | first_layer; 80 | 81 | --- 82 | 83 | 84 | DROP TABLE IF EXISTS runner_orders_cleaned; 85 | CREATE TEMP TABLE runner_orders_cleaned AS WITH first_layer AS ( 86 | SELECT 87 | order_id, 88 | runner_id, 89 | CAST( 90 | CASE 91 | WHEN pickup_time = 'null' THEN NULL 92 | ELSE pickup_time 93 | END AS timestamp 94 | ) AS pickup_time, 95 | CASE 96 | WHEN distance = '' THEN NULL 97 | WHEN distance = 'null' THEN NULL 98 | ELSE distance 99 | END as distance, 100 | CASE 101 | WHEN duration = '' THEN NULL 102 | WHEN duration = 'null' THEN NULL 103 | ELSE duration 104 | END as duration, 105 | CASE 106 | WHEN cancellation = '' THEN NULL 107 | WHEN cancellation = 'null' THEN NULL 108 | ELSE cancellation 109 | END as cancellation 110 | FROM 111 | runner_orders 112 | ) 113 | SELECT 114 | order_id, 115 | runner_id, 116 | CASE 117 | WHEN order_id = '3' THEN (pickup_time + INTERVAL '13 hour') 118 | ELSE pickup_time 119 | END AS pickup_time, 120 | CAST( 121 | regexp_replace(distance, '[a-z]+', '') AS DECIMAL(5, 2) 122 | ) AS distance, 123 | CAST(regexp_replace(duration, '[a-z]+', '') AS INT) AS duration, 124 | cancellation 125 | FROM 126 | first_layer; 127 | 128 | 129 | ------------------------------------------------------ 130 | -- 1) If a Meat Lovers pizza costs $12 and Vegetarian costs $10 and there were no charges for changes - how much money has Pizza Runner 131 | -- made so far if there are no delivery fees? 132 | 133 | 134 | --Let's create a temp table to make this more organized and get used to the syntax. I do not append those information to existing tables as it would require discussion 135 | -- with the person managing the database (in a real situation). I'll use another method. 136 | 137 | 138 | DROP TABLE IF EXISTS pizza_prices; 139 | CREATE TEMP TABLE pizza_prices ( 140 | "pizza_id" INTEGER, 141 | "price" INTEGER 142 | ); 143 | INSERT INTO 144 | pizza_prices ("pizza_id", "price") 145 | VALUES 146 | (1, 12), 147 | (2, 10); 148 | 149 | --- 150 | 151 | WITH profit_table AS ( 152 | SELECT 153 | C.pizza_id, 154 | COUNT(C.pizza_id) * price as pizza_revenues 155 | FROM 156 | customer_orders_cleaned AS C 157 | LEFT JOIN runner_orders_cleaned AS R ON C.order_id = R.order_id 158 | LEFT JOIN pizza_prices AS P ON C.pizza_id = P.pizza_id 159 | WHERE 160 | R.cancellation IS NULL 161 | GROUP BY 162 | C.pizza_id, 163 | price 164 | ) 165 | SELECT 166 | SUM(pizza_revenues) AS total_revenue 167 | FROM 168 | profit_table; 169 | 170 | | total_revenue | 171 | | ------------- | 172 | | 138 | 173 | 174 | 175 | 176 | ------------------------------------------------------ 177 | -- 2) What if there was an additional $1 charge for any pizza extras? 178 | -- - Add cheese is $1 extra 179 | 180 | -- let's recycle last part queries: 181 | 182 | DROP TABLE IF EXISTS orders_extras; 183 | CREATE TEMP TABLE orders_extras AS 184 | SELECT 185 | row_number_order, 186 | order_id, 187 | customer_id, 188 | customer_orders_cleaned.pizza_id, 189 | pizza_name, 190 | CAST( 191 | UNNEST(string_to_array(COALESCE(extras, '0'), ',')) AS INT 192 | ) AS extras 193 | FROM 194 | customer_orders_cleaned 195 | JOIN pizza_names ON customer_orders_cleaned.pizza_id = pizza_names.pizza_id 196 | ORDER BY 197 | order_id; 198 | 199 | 200 | WITH segmented_revenues AS ( 201 | SELECT 202 | table1.pizza_id, 203 | table1.pizza_revenues, 204 | table2.extras_revenues, 205 | (table1.pizza_revenues + table2.extras_revenues) AS total_revenues 206 | FROM 207 | ( 208 | SELECT 209 | C.pizza_id, 210 | COUNT(C.pizza_id) * price as pizza_revenues 211 | FROM 212 | customer_orders_cleaned AS C 213 | LEFT JOIN runner_orders_cleaned AS R ON C.order_id = R.order_id 214 | LEFT JOIN pizza_prices AS P ON C.pizza_id = P.pizza_id 215 | WHERE 216 | R.cancellation IS NULL 217 | GROUP BY 218 | C.pizza_id, 219 | price 220 | ) AS table1 221 | LEFT JOIN ( 222 | SELECT 223 | t1.pizza_id, 224 | SUM( 225 | CASE 226 | WHEN t1.extras > 0 THEN 1 227 | ELSE 0 228 | END 229 | ) AS extras_revenues 230 | FROM 231 | orders_extras t1 232 | LEFT JOIN pizza_prices t2 ON t1.pizza_id = t2.pizza_id 233 | LEFT JOIN runner_orders_cleaned t3 ON t1.order_id = t3.order_id 234 | WHERE 235 | t3.cancellation IS NULL 236 | GROUP BY 237 | t1.pizza_id 238 | ) AS table2 ON table1.pizza_id = table2.pizza_id 239 | ) 240 | SELECT 241 | SUM(total_revenues) AS total_revenues 242 | FROM 243 | segmented_revenues; 244 | 245 | | total_revenues | 246 | | -------------- | 247 | | 142 | 248 | 249 | 250 | 251 | 252 | ------------------------------------------------------ 253 | -- 3) What if substitutes were allowed at no additional cost but any additional extras were charged at $1? 254 | -- - Exclude Cheese and add Bacon is free 255 | -- - Exclude Cheese but add bacon and beef costs $1 extra 256 | 257 | 258 | -- Step 1: create an unstacked table with the extras and exceptions 259 | DROP TABLE IF EXISTS exclusions_extras_unstacked; 260 | CREATE TEMP TABLE exclusions_extras_unstacked AS 261 | SELECT 262 | row_number_order, 263 | order_id, 264 | customer_id, 265 | customer_orders_cleaned.pizza_id, 266 | pizza_name, 267 | CAST( 268 | UNNEST(string_to_array(COALESCE(exclusions, '0'), ',')) AS INT 269 | ) AS exclusions, 270 | CAST( 271 | UNNEST(string_to_array(COALESCE(extras, '0'), ',')) AS INT 272 | ) AS extras 273 | FROM 274 | customer_orders_cleaned 275 | JOIN pizza_names ON customer_orders_cleaned.pizza_id = pizza_names.pizza_id 276 | ORDER BY 277 | order_id; 278 | 279 | --Step 2: create a balance to see if we had more extras than exclusions 280 | WITH order_layer AS ( 281 | SELECT 282 | row_number_order, 283 | order_id, 284 | pizza_id, 285 | SUM( 286 | CASE 287 | WHEN extras > 0 THEN 1 288 | ELSE 0 289 | END 290 | ) - SUM( 291 | CASE 292 | WHEN exclusions > 0 THEN 1 293 | ELSE 0 294 | END 295 | ) AS substitutes_cost 296 | FROM 297 | exclusions_extras_unstacked 298 | GROUP BY 299 | row_number_order, 300 | order_id, 301 | pizza_id 302 | ), 303 | pizza_layer AS( 304 | SELECT 305 | row_number_order, 306 | order_id, 307 | pizza_id, 308 | CASE 309 | WHEN substitutes_cost < 0 THEN 0 310 | ELSE substitutes_cost 311 | END AS substitutes_cost 312 | FROM 313 | order_layer 314 | ) 315 | SELECT 316 | pizza_id, 317 | SUM(substitutes_cost) AS substitutes_cost 318 | FROM 319 | pizza_layer 320 | GROUP BY 321 | pizza_id; 322 | 323 | | pizza_id | substitutes_cost | 324 | | -------- | ---------------- | 325 | | 2 | 1 | 326 | | 1 | 2 | 327 | 328 | --Step 3: Change the LEFT JOIN in our last question query with the one created in step 2. 329 | WITH segmented_revenues AS ( 330 | SELECT 331 | table1.pizza_id, 332 | table1.pizza_revenues, 333 | table2.substitutes_cost, 334 | (table1.pizza_revenues + table2.substitutes_cost) AS total_revenues 335 | FROM 336 | ( 337 | SELECT 338 | C.pizza_id, 339 | COUNT(C.pizza_id) * price as pizza_revenues 340 | FROM 341 | customer_orders_cleaned AS C 342 | LEFT JOIN runner_orders_cleaned AS R ON C.order_id = R.order_id 343 | LEFT JOIN pizza_prices AS P ON C.pizza_id = P.pizza_id 344 | WHERE 345 | R.cancellation IS NULL 346 | GROUP BY 347 | C.pizza_id, 348 | price 349 | ) AS table1 350 | LEFT JOIN ( 351 | WITH order_layer AS ( 352 | SELECT 353 | row_number_order, 354 | order_id, 355 | pizza_id, 356 | SUM( 357 | CASE 358 | WHEN extras > 0 THEN 1 359 | ELSE 0 360 | END 361 | ) - SUM( 362 | CASE 363 | WHEN exclusions > 0 THEN 1 364 | ELSE 0 365 | END 366 | ) AS substitutes_cost 367 | FROM 368 | exclusions_extras_unstacked 369 | GROUP BY 370 | row_number_order, 371 | order_id, 372 | pizza_id 373 | ), 374 | pizza_layer AS( 375 | SELECT 376 | row_number_order, 377 | order_id, 378 | pizza_id, 379 | CASE 380 | WHEN substitutes_cost < 0 THEN 0 381 | ELSE substitutes_cost 382 | END AS substitutes_cost 383 | FROM 384 | order_layer 385 | ) 386 | SELECT 387 | pizza_id, 388 | SUM(substitutes_cost) AS substitutes_cost 389 | FROM 390 | pizza_layer 391 | GROUP BY 392 | pizza_id 393 | ) AS table2 ON table1.pizza_id = table2.pizza_id 394 | ) 395 | SELECT 396 | SUM(total_revenues) AS total_revenues 397 | FROM 398 | segmented_revenues; 399 | 400 | | total_revenues | 401 | | -------------- | 402 | | 141 | 403 | 404 | 405 | 406 | ------------------------------------------------------ 407 | -- 4) What if meat substitutes and vegetable substitutes were allowed but any change outside were charged at $2 and $1 respectively? 408 | -- - Exclude Cheese and add Bacon is $2 extra 409 | -- - Exclude Beef and add mushroom is $1 extra 410 | -- - Exclude Beef and add Bacon is free 411 | -- - Exclude Beef and Mushroom, and add Bacon and Cheese is free 412 | 413 | -- Table 2: Just as before, we will not modify existing tables. 414 | 415 | DROP TABLE IF EXISTS modification_prices; 416 | CREATE TEMP TABLE modification_prices ( 417 | "topping_id" INTEGER, 418 | "topping_name" TEXT, 419 | "type" INTEGER, 420 | "type_name" TEXT, 421 | "modification_price" INTEGER 422 | ); 423 | INSERT INTO 424 | modification_prices ( 425 | "topping_id", 426 | "topping_name", 427 | "type", 428 | "type_name", 429 | "modification_price" 430 | ) 431 | VALUES 432 | ('1', 'Bacon', '1', 'Vegetable', '2'), 433 | ('2', 'BBQ Sauce', '0', 'Sauce', '0'), 434 | ('3', 'Beef', '1', 'Meat', '2'), 435 | ('4', 'Cheese', '2', 'Vegetable', '1'), 436 | ('5', 'Chicken', '1', 'Meat', '2'), 437 | ('6', 'Mushrooms', '2', 'Vegetable', '1'), 438 | ('7', 'Onions', '2', 'Vegetable', '1'), 439 | ('8', 'Pepperoni', '1', 'Meat', '2'), 440 | ('9', 'Peppers', '2', 'Vegetable', '1'), 441 | ('10', 'Salami', '1', 'Meat', '2'), 442 | ('11', 'Tomatoes', '2', 'Vegetable', '1'), 443 | ('12', 'Tomato Sauce', '0', 'Sauce', '0'); 444 | 445 | 446 | --Step 2: compute the fees using the table previously created 447 | WITH unstacking AS( 448 | SELECT 449 | t1.row_number_order, 450 | t1.order_id, 451 | t1.pizza_id, 452 | t1.exclusions, 453 | t1.extras, 454 | t2.type AS exclusion_type, 455 | t3.type AS extras_type, 456 | t3.modification_price AS extras_price 457 | FROM 458 | exclusions_extras_unstacked t1 459 | LEFT JOIN modification_prices t2 ON t1.exclusions = t2.topping_id 460 | LEFT JOIN modification_prices t3 ON t1.extras = t3.topping_id 461 | ORDER BY 462 | order_id 463 | ), 464 | condition_type AS( 465 | SELECT 466 | row_number_order, 467 | order_id, 468 | pizza_id, 469 | extras_price, 470 | CASE 471 | WHEN exclusion_type = 1 THEN 1 472 | ELSE 0 473 | END AS exclusion_type1, 474 | CASE 475 | WHEN exclusion_type = 2 THEN 1 476 | ELSE 0 477 | END AS exclusion_type2, 478 | CASE 479 | WHEN extras_type = 1 THEN 1 480 | ELSE 0 481 | END AS extras_type1, 482 | CASE 483 | WHEN extras_type = 2 THEN 1 484 | ELSE 0 485 | END AS extras_type2 486 | FROM 487 | unstacking 488 | ), 489 | count_type AS( 490 | SELECT 491 | row_number_order, 492 | order_id, 493 | pizza_id, 494 | extras_price, 495 | SUM(exclusion_type1) AS exclusion_type1, 496 | SUM(exclusion_type2) AS exclusion_type2, 497 | SUM(extras_type1) AS extras_type1, 498 | SUM(extras_type2) AS extras_type2 499 | FROM 500 | condition_type 501 | GROUP BY 502 | row_number_order, 503 | order_id, 504 | pizza_id, 505 | extras_price 506 | ORDER BY 507 | row_number_order 508 | ), 509 | fees_type AS( 510 | SELECT 511 | row_number_order, 512 | order_id, 513 | pizza_id, 514 | CASE 515 | WHEN (extras_type1 - exclusion_type1) * extras_price < 0 THEN 0 516 | ELSE (extras_type1 - exclusion_type1) * extras_price 517 | END AS fees_type1, 518 | CASE 519 | WHEN (extras_type2 - exclusion_type2) * extras_price < 0 THEN 0 520 | ELSE (extras_type2 - exclusion_type2) * extras_price 521 | END AS fees_type2 522 | FROM 523 | count_type 524 | ) 525 | SELECT 526 | pizza_id, 527 | SUM(fees_type1) + SUM(fees_type2) AS substitutes_cost 528 | FROM 529 | fees_type 530 | GROUP BY 531 | pizza_id; 532 | 533 | | pizza_id | substitutes_cost | 534 | | -------- | ---------------- | 535 | | 2 | 2 | 536 | | 1 | 8 | 537 | 538 | 539 | --Step 3: Compute the total revenues with the previously used queries: 540 | WITH segmented_revenues AS ( 541 | SELECT 542 | table1.pizza_id, 543 | table1.pizza_revenues, 544 | table2.substitutes_cost, 545 | (table1.pizza_revenues + table2.substitutes_cost) AS total_revenues 546 | FROM 547 | ( 548 | SELECT 549 | C.pizza_id, 550 | COUNT(C.pizza_id) * price as pizza_revenues 551 | FROM 552 | customer_orders_cleaned AS C 553 | LEFT JOIN runner_orders_cleaned AS R ON C.order_id = R.order_id 554 | LEFT JOIN pizza_prices AS P ON C.pizza_id = P.pizza_id 555 | WHERE 556 | R.cancellation IS NULL 557 | GROUP BY 558 | C.pizza_id, 559 | price 560 | ) AS table1 561 | LEFT JOIN ( 562 | WITH unstacking AS( 563 | SELECT 564 | t1.row_number_order, 565 | t1.order_id, 566 | t1.pizza_id, 567 | t1.exclusions, 568 | t1.extras, 569 | t2.type AS exclusion_type, 570 | t3.type AS extras_type, 571 | t3.modification_price AS extras_price 572 | FROM 573 | exclusions_extras_unstacked t1 574 | LEFT JOIN modification_prices t2 ON t1.exclusions = t2.topping_id 575 | LEFT JOIN modification_prices t3 ON t1.extras = t3.topping_id 576 | ORDER BY 577 | order_id 578 | ), 579 | condition_type AS( 580 | SELECT 581 | row_number_order, 582 | order_id, 583 | pizza_id, 584 | extras_price, 585 | CASE 586 | WHEN exclusion_type = 1 THEN 1 587 | ELSE 0 588 | END AS exclusion_type1, 589 | CASE 590 | WHEN exclusion_type = 2 THEN 1 591 | ELSE 0 592 | END AS exclusion_type2, 593 | CASE 594 | WHEN extras_type = 1 THEN 1 595 | ELSE 0 596 | END AS extras_type1, 597 | CASE 598 | WHEN extras_type = 2 THEN 1 599 | ELSE 0 600 | END AS extras_type2 601 | FROM 602 | unstacking 603 | ), 604 | count_type AS( 605 | SELECT 606 | row_number_order, 607 | order_id, 608 | pizza_id, 609 | extras_price, 610 | SUM(exclusion_type1) AS exclusion_type1, 611 | SUM(exclusion_type2) AS exclusion_type2, 612 | SUM(extras_type1) AS extras_type1, 613 | SUM(extras_type2) AS extras_type2 614 | FROM 615 | condition_type 616 | GROUP BY 617 | row_number_order, 618 | order_id, 619 | pizza_id, 620 | extras_price 621 | ORDER BY 622 | row_number_order 623 | ), 624 | fees_type AS( 625 | SELECT 626 | row_number_order, 627 | order_id, 628 | pizza_id, 629 | CASE 630 | WHEN (extras_type1 - exclusion_type1) * extras_price < 0 THEN 0 631 | ELSE (extras_type1 - exclusion_type1) * extras_price 632 | END AS fees_type1, 633 | CASE 634 | WHEN (extras_type2 - exclusion_type2) * extras_price < 0 THEN 0 635 | ELSE (extras_type2 - exclusion_type2) * extras_price 636 | END AS fees_type2 637 | FROM 638 | count_type 639 | ) 640 | SELECT 641 | pizza_id, 642 | SUM(fees_type1) + SUM(fees_type2) AS substitutes_cost 643 | FROM 644 | fees_type 645 | GROUP BY 646 | pizza_id 647 | ) AS table2 ON table1.pizza_id = table2.pizza_id 648 | ) 649 | SELECT 650 | SUM(total_revenues) AS total_revenues 651 | FROM 652 | segmented_revenues; 653 | 654 | | total_revenues | 655 | | -------------- | 656 | | 148 | 657 | 658 | 659 | 660 | ------------------------------------------------------ 661 | -- 5)The Pizza Runner team now wants to add an additional ratings system that allows customers to rate their runner, 662 | -- how would you design an additional table for this new dataset - generate a schema for this new table and insert 663 | -- your own data for ratings for each successful customer order between 1 to 5. 664 | 665 | DROP TABLE IF EXISTS runner_ratings; 666 | CREATE TABLE runner_ratings ( 667 | "order_id" INTEGER, 668 | "rating" INTEGER CONSTRAINT check1to5_rating CHECK ( 669 | "rating" between 1 670 | and 5 671 | ), 672 | "comment" VARCHAR(150) 673 | ); 674 | INSERT INTO 675 | runner_ratings ("order_id", "rating", "comment") 676 | VALUES 677 | ('1', '2', 'Tasty'), 678 | ('2', '4', ''), 679 | ('3', '4', ''), 680 | ('4', '5', 'The pizza arrived cold, really bad service'), 681 | ('5', '2', ''), 682 | ('6', NULL, ''), 683 | ('7', '5', ''), 684 | ('8', '4', 'Great service'), 685 | ('9', NULL, ''), 686 | ('10', '1', 'The pizza arrived upside down, really disappointed'); 687 | 688 | SELECT 689 | * 690 | FROM 691 | runner_ratings; 692 | 693 | | order_id | rating | comment | 694 | | -------- | ------ | -------------------------------------------------- | 695 | | 1 | 2 | Tasty | 696 | | 2 | 4 | | 697 | | 3 | 4 | | 698 | | 4 | 5 | The pizza arrived cold, really bad service | 699 | | 5 | 2 | | 700 | | 6 | | | 701 | | 7 | 5 | | 702 | | 8 | 4 | Great service | 703 | | 9 | | | 704 | | 10 | 1 | The pizza arrived upside down, really disappointed | 705 | 706 | 707 | ------------------------------------------------------ 708 | -- 6)Using your newly generated table - can you join all of the information together to form a table which has the following information for successful deliveries? 709 | -- - customer_id 710 | -- - order_id 711 | -- - runner_id 712 | -- - rating 713 | -- - order_time 714 | -- - pickup_time 715 | -- - Time between order and pickup 716 | -- - Delivery duration 717 | -- - Average speed 718 | -- - Total number of pizzas 719 | 720 | DROP TABLE IF EXISTS Global_table; 721 | CREATE TEMP TABLE Global_table AS WITH runner_layer1 AS ( 722 | SELECT 723 | order_id, 724 | runner_id, 725 | CAST( 726 | CASE 727 | WHEN pickup_time = 'null' THEN NULL 728 | ELSE pickup_time 729 | END AS timestamp 730 | ) AS pickup_time, 731 | CASE 732 | WHEN distance = '' THEN NULL 733 | WHEN distance = 'null' THEN NULL 734 | ELSE distance 735 | END as distance, 736 | CASE 737 | WHEN duration = '' THEN NULL 738 | WHEN duration = 'null' THEN NULL 739 | ELSE duration 740 | END as duration, 741 | CASE 742 | WHEN cancellation = '' THEN NULL 743 | WHEN cancellation = 'null' THEN NULL 744 | ELSE cancellation 745 | END as cancellation 746 | FROM 747 | runner_orders 748 | ), 749 | runner_layer2 AS( 750 | SELECT 751 | order_id, 752 | runner_id, 753 | CASE 754 | WHEN order_id = '3' THEN (pickup_time + INTERVAL '13 hour') 755 | ELSE pickup_time 756 | END AS pickup_time, 757 | CAST( 758 | regexp_replace(distance, '[a-z]+', '') AS DECIMAL(5, 2) 759 | ) AS distance, 760 | CAST(regexp_replace(duration, '[a-z]+', '') AS INT) AS duration, 761 | cancellation 762 | FROM 763 | runner_layer1 764 | ) 765 | SELECT 766 | t1.order_id, 767 | t2.customer_id, 768 | t1.runner_id, 769 | t3.rating, 770 | t2.order_time, 771 | t1.pickup_time, 772 | ( 773 | DATE_PART('hour', t1.pickup_time - t2.order_time) * 60 + DATE_PART('minute', t1.pickup_time - t2.order_time) 774 | ) * 60 + DATE_PART('second', t1.pickup_time - t2.order_time) AS time_between_order_and_pickup, 775 | t1.distance, 776 | t1.duration, 777 | ROUND( 778 | ( 779 | t1.distance :: NUMERIC /(t1.duration :: NUMERIC / 60) 780 | ), 781 | 2 782 | ) AS average_speed, 783 | COUNT(t2.pizza_id) AS count_pizza 784 | FROM 785 | runner_layer2 t1 786 | LEFT JOIN customer_orders t2 ON t1.order_id = t2.order_id 787 | LEFT JOIN runner_ratings t3 ON t1.order_id = t3.order_id 788 | WHERE 789 | cancellation IS NULL 790 | GROUP BY 791 | t1.order_id, 792 | t1.runner_id, 793 | t1.pickup_time, 794 | t1.distance, 795 | t1.duration, 796 | ROUND( 797 | ( 798 | t1.distance :: NUMERIC /(t1.duration :: NUMERIC / 60) 799 | ), 800 | 2 801 | ), 802 | t2.customer_id, 803 | t2.order_time, 804 | t3.rating; 805 | 806 | 807 | ------------------------------------------------------ 808 | -- 7) If a Meat Lovers pizza was $12 and Vegetarian $10 fixed prices with no cost for extras and each runner is paid $0.30 per kilometre 809 | -- traveled - how much money does Pizza Runner have left over after these deliveries? 810 | 811 | WITH pizza_revenues AS( 812 | SELECT 813 | t1.order_id, 814 | pizza_id, 815 | CASE 816 | WHEN pizza_id = 1 THEN COUNT(pizza_id) * 12 817 | ELSE COUNT(pizza_id) * 10 818 | END AS pizza_revenues 819 | FROM 820 | customer_orders_cleaned t1 821 | LEFT JOIN runner_orders_cleaned t2 ON t1.order_id = t2.order_id 822 | WHERE 823 | cancellation IS NULL 824 | GROUP BY 825 | t1.order_id, 826 | pizza_id 827 | ), 828 | revenues_delivery AS( 829 | SELECT 830 | t1.order_id, 831 | t2.distance * 0.3 AS delivery_cost, 832 | SUM(t1.pizza_revenues) AS order_revenues 833 | FROM 834 | pizza_revenues t1 835 | LEFT JOIN Global_table t2 ON t1.order_id = t2.order_id 836 | GROUP BY 837 | t1.order_id, 838 | distance 839 | ) 840 | SELECT 841 | ROUND(SUM(order_revenues) - SUM(delivery_COST), 2) AS revenues_afterdelivery 842 | FROM 843 | revenues_delivery; 844 | 845 | | revenues_afterdelivery | 846 | | ---------------------- | 847 | | 94.44 | 848 | 849 | 850 | 851 | ------------------------------------------------------ 852 | -- 8) If 1 unit of each ingredient costs $0.50 - how much net revenue will Pizza Runner make if the costs from question 30 are used? 853 | 854 | --Step 1: Let's go back to previous queries where we obtained how many times each ingredients were used (question 5 & 6 of part Ingredient Optimization) 855 | -- Note that those lines are added to make the SQL works as I divided this assignment in multiple parts for readability ! 856 | DROP TABLE IF EXISTS classical_recipe; 857 | CREATE TEMP TABLE classical_recipe AS WITH pizza_recipes_unstacked AS ( 858 | SELECT 859 | pizza_id, 860 | CAST( 861 | UNNEST( 862 | string_to_array(toppings, ', ') 863 | ) AS INT 864 | ) AS topping_id 865 | FROM 866 | pizza_recipes 867 | ) 868 | SELECT 869 | t4.row_number_order, 870 | t4.order_id, 871 | t4.customer_id, 872 | t1.pizza_id, 873 | t1.pizza_name, 874 | t2.topping_id, 875 | t3.topping_name 876 | FROM 877 | pizza_names t1 878 | JOIN pizza_recipes_unstacked t2 ON t1.pizza_id = t2.pizza_id 879 | JOIN pizza_toppings t3 ON t2.topping_id = t3.topping_id 880 | RIGHT JOIN customer_orders_cleaned t4 ON t1.pizza_id = t4.pizza_id; 881 | 882 | 883 | DROP TABLE IF EXISTS orders_exclusions; 884 | CREATE TEMP TABLE orders_exclusions AS 885 | SELECT 886 | row_number_order, 887 | order_id, 888 | customer_id, 889 | customer_orders_cleaned.pizza_id, 890 | pizza_name, 891 | CAST( 892 | UNNEST(string_to_array(COALESCE(exclusions, '0'), ',')) AS INT 893 | ) AS exclusions 894 | FROM 895 | customer_orders_cleaned 896 | JOIN pizza_names ON customer_orders_cleaned.pizza_id = pizza_names.pizza_id 897 | ORDER BY 898 | order_id; 899 | 900 | 901 | DROP TABLE IF EXISTS orders_extras; 902 | CREATE TEMP TABLE orders_extras AS 903 | SELECT 904 | row_number_order, 905 | order_id, 906 | customer_id, 907 | customer_orders_cleaned.pizza_id, 908 | pizza_name, 909 | CAST( 910 | UNNEST(string_to_array(COALESCE(extras, '0'), ',')) AS INT 911 | ) AS extras 912 | FROM 913 | customer_orders_cleaned 914 | JOIN pizza_names ON customer_orders_cleaned.pizza_id = pizza_names.pizza_id 915 | ORDER BY 916 | order_id; 917 | 918 | DROP TABLE IF EXISTS pizzas_details; 919 | CREATE TEMP TABLE pizzas_details AS WITH first_layer AS ( 920 | SELECT 921 | row_number_order, 922 | order_id, 923 | customer_id, 924 | pizza_id, 925 | pizza_name, 926 | topping_id 927 | FROM 928 | classical_recipe 929 | EXCEPT 930 | SELECT 931 | * 932 | FROM 933 | orders_exclusions 934 | UNION ALL 935 | SELECT 936 | * 937 | FROM 938 | orders_extras 939 | WHERE 940 | extras != 0 941 | ) 942 | SELECT 943 | row_number_order, 944 | order_id, 945 | customer_id, 946 | pizza_id, 947 | pizza_name, 948 | first_layer.topping_id, 949 | topping_name 950 | FROM 951 | first_layer 952 | LEFT JOIN pizza_toppings ON first_layer.topping_id = pizza_toppings.topping_id 953 | ORDER BY 954 | row_number_order, 955 | order_id, 956 | pizza_id, 957 | topping_id; 958 | 959 | 960 | --Step 2: Detail of the query to get the ingredients' cost per order_id 961 | 962 | SELECT 963 | order_id, 964 | COUNT(topping_id) * 0.5 as ingredient_costs 965 | FROM 966 | pizzas_details 967 | GROUP BY 968 | order_id 969 | ORDER BY 970 | order_id; 971 | 972 | | order_id | ingredient_costs | 973 | | -------- | ---------------- | 974 | | 1 | 4.0 | 975 | | 2 | 4.0 | 976 | | 3 | 7.0 | 977 | | 4 | 9.5 | 978 | | 5 | 4.5 | 979 | | 6 | 3.0 | 980 | | 7 | 3.5 | 981 | | 8 | 4.0 | 982 | | 9 | 4.5 | 983 | | 10 | 8.0 | 984 | 985 | 986 | --Step 3: Now let's fill this in the query of the previous question: 987 | WITH pizza_revenues AS( 988 | SELECT 989 | t1.order_id, 990 | pizza_id, 991 | CASE 992 | WHEN pizza_id = 1 THEN COUNT(pizza_id) * 12 993 | ELSE COUNT(pizza_id) * 10 994 | END AS pizza_revenues 995 | FROM 996 | customer_orders_cleaned t1 997 | LEFT JOIN runner_orders_cleaned t2 ON t1.order_id = t2.order_id 998 | WHERE 999 | cancellation IS NULL 1000 | GROUP BY 1001 | t1.order_id, 1002 | pizza_id 1003 | ), 1004 | revenues_delivery AS( 1005 | SELECT 1006 | t1.order_id, 1007 | t2.distance * 0.3 AS delivery_cost, 1008 | SUM(t1.pizza_revenues) AS order_revenues, 1009 | t3.ingredient_costs 1010 | FROM 1011 | pizza_revenues t1 1012 | LEFT JOIN Global_table t2 ON t1.order_id = t2.order_id 1013 | LEFT JOIN ( 1014 | SELECT 1015 | order_id, 1016 | COUNT(topping_id) * 0.5 as ingredient_costs 1017 | FROM 1018 | pizzas_details 1019 | GROUP BY 1020 | order_id 1021 | ) AS t3 ON t1.order_id = t3.order_id 1022 | GROUP BY 1023 | t1.order_id, 1024 | distance, 1025 | t3.ingredient_costs 1026 | ) 1027 | SELECT 1028 | ROUND( 1029 | SUM(order_revenues) - SUM(delivery_COST) - SUM(ingredient_costs), 1030 | 2 1031 | ) AS revenues_left 1032 | FROM 1033 | revenues_delivery; 1034 | 1035 | | revenues_left | 1036 | | ------------- | 1037 | | 49.94 | 1038 | 1039 | --- 1040 | 1041 | [View on DB Fiddle](https://www.db-fiddle.com/f/7VcQKQwsS3CTkGRFG7vu98/4) 1042 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # 8 Week SQL Challenge 2 | 3 | Thanks @DataWithDanny for the excellent SQL case studies! 👋🏻 4 | * Find his challenge website on **[#8WeekSQLChallenge](https://8weeksqlchallenge.com)** 5 | * Furthermore, I would recommend his course for anyone looking to get advanced SQL skills **[Serious-SQL](https://www.datawithdanny.com/courses/serious-sql)** 6 | 7 | ## 📕 Table of Contents 8 | - [Case Study #1: Danny's Diner](#case-study-1-dannys-diner) 9 | - [Case Study #2: Pizza Runner](#case-study-2-pizza-runner) 10 | 11 | ## Case Study #1: Danny's Diner 12 | Image 13 | 14 | [Link to case study](https://8weeksqlchallenge.com/case-study-1/) 15 | 16 | ### Business Problem: 17 | Danny just started a japonese food business. He wants to leverage the data that he collected by creating some Dataset and answer a few questions regarding his customer, their habits and whether to expand the customer loyalty program or not. 18 | 19 | ### Entity Relationship Diagram: 20 | 21 | ![Entity diagram](/images/ER_case_1.png?raw=true "ER case 1") 22 | 23 | ### Case Study Questions: 24 |
25 | 26 | Click here to expand! 27 | 28 | 29 | 1. What is the total amount each customer spent at the restaurant? 30 | 2. How many days has each customer visited the restaurant? 31 | 3. What was the first item from the menu purchased by each customer? 32 | 4. What is the most purchased item on the menu and how many times was it purchased by all customers? 33 | 5. Which item was the most popular for each customer? 34 | 6. Which item was purchased first by the customer after they became a member? 35 | 7. Which item was purchased just before the customer became a member? 36 | 10. What is the total items and amount spent for each member before they became a member? 37 | 11. If each $1 spent equates to 10 points and sushi has a 2x points multiplier - how many points would each customer have? 38 | 12. In the first week after a customer joins the program (including their join date) they earn 2x points on all items, not just sushi - how many points do customer A and B have at the end of January? 39 | 40 | + some bonus questions! 41 |
42 | 43 | 44 | 45 | ## Case Study #2: Pizza Runner 46 | Image 47 | 48 | [Link to case study](https://8weeksqlchallenge.com/case-study-2/) 49 | 50 | ### Business Problem: 51 | Danny decided to expand his Pizza business and Uberize it. Thus, he launches "Pizza Runner": he recruited runners to deliver pizza from his Headquarters and is developping an app. 52 | 53 | He has many questions to be answered related to different general topic: 54 | * Pizza Metrics 55 | * Runner and Customer Experience 56 | * Ingredient Optimisation 57 | * Pricing and Ratings 58 | 59 | ### Entity Relationship Diagram: 60 | 61 | ![Entity diagram](/images/ER_case_2.png?raw=true "ER case 2") 62 | 63 | ### Case Study Questions: 64 |
65 | 66 | Click here to expand! 67 | 68 | 69 | 1. How many pizzas were ordered? 70 | 2. How many unique customer orders were made? 71 | 3. How many successful orders were delivered by each runner? 72 | 4. How many of each type of pizza was delivered? 73 | 5. How many Vegetarian and Meatlovers were ordered by each customer? 74 | 6. What was the maximum number of pizzas delivered in a single order? 75 | 7. For each customer, how many delivered pizzas had at least 1 change and how many had no changes? 76 | 8. How many pizzas were delivered that had both exclusions and extras? 77 | 9. What was the total volume of pizzas ordered for each hour of the day? 78 | 10. What was the volume of orders for each day of the week? 79 | 80 |
81 | 82 | #### B. Runner and Customer Experience 83 | 84 |
85 | 86 | Click here to expand! 87 | 88 | 89 | 1. How many runners signed up for each 1 week period? (i.e. week starts 2021-01-01) 90 | 2. What was the average time in minutes it took for each runner to arrive at the Pizza Runner HQ to pickup the order? 91 | 3. Is there any relationship between the number of pizzas and how long the order takes to prepare? 92 | 4. What was the average distance travelled for each customer? 93 | 5. What was the difference between the longest and shortest delivery times for all orders? 94 | 6. What was the average speed for each runner for each delivery and do you notice any trend for these values? 95 | 7. What is the successful delivery percentage for each runner? 96 | 97 |
98 | 99 | #### C. Ingredient Optimisation 100 | 101 |
102 | 103 | Click here to expand! 104 | 105 | 106 | 1. What are the standard ingredients for each pizza? 107 | 2. What was the most commonly added extra? 108 | 3. What was the most common exclusion? 109 | 4. Generate an order item for each record in the customers_orders table in the format of one of the following: 110 | - Meat Lovers 111 | - Meat Lovers - Exclude Beef 112 | - Meat Lovers - Extra Bacon 113 | - Meat Lovers - Exclude Cheese, Bacon - Extra Mushroom, Peppers 114 | 5. Generate an alphabetically ordered comma separated ingredient list for each pizza order from the customer_orders table and add a 2x in front of any relevant ingredients 115 | 6. For example: "Meat Lovers: 2xBacon, Beef, ... , Salami" 116 | 7. What is the total quantity of each ingredient used in all delivered pizzas sorted by most frequent first? 117 | 118 |
119 | 120 | #### D. Pricing and Ratings 121 | 122 |
123 | 124 | Click here to expand! 125 | 126 | 127 | 1. If a Meat Lovers pizza costs $12 and Vegetarian costs $10 and there were no charges for changes - how much money has Pizza Runner made so far if there are no delivery fees? 128 | 2. What if there was an additional $1 charge for any pizza extras? 129 | - Add cheese is $1 extra 130 | 3. The Pizza Runner team now wants to add an additional ratings system that allows customers to rate their runner, how would you design an additional table for this new dataset generate a schema for this new table and insert your own data for ratings for each successful customer order between 1 to 5. 131 | 4. Using your newly generated table - can you join all of the information together to form a table which has the following information for successful deliveries? 132 | - customer_id 133 | - order_id 134 | - runner_id 135 | - rating 136 | - order_time 137 | - pickup_time 138 | - Time between order and pickup 139 | - Delivery duration 140 | - Average speed 141 | - Total number of pizzas 142 | 5. If a Meat Lovers pizza was $12 and Vegetarian $10 fixed prices with no cost for extras and each runner is paid $0.30 per kilometre traveled - how much money does Pizza Runner have left over after these deliveries? 143 | 144 |
145 | 146 | #### E. Bonus Questions 147 | 148 |
149 | 150 | Click here to expand! 151 | 152 | 153 | If Danny wants to expand his range of pizzas - how would this impact the existing data design? Write an INSERT statement to demonstrate what would happen if a new Supreme pizza with all the toppings was added to the Pizza Runner menu? 154 | 155 |
156 | -------------------------------------------------------------------------------- /images/.gitkeep: -------------------------------------------------------------------------------- 1 | 2 | -------------------------------------------------------------------------------- /images/ER_case_1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/AymericPeltier/8-Week-SQL-Challenge/f428fbd55245e70f08f57f1c51d3f301edb5116c/images/ER_case_1.png -------------------------------------------------------------------------------- /images/ER_case_2.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/AymericPeltier/8-Week-SQL-Challenge/f428fbd55245e70f08f57f1c51d3f301edb5116c/images/ER_case_2.png --------------------------------------------------------------------------------