@@ -317,10 +317,255 @@ FROM Salaries;
317
317
318
318
/* ------------------------------------------------------------------------------------------------------------*/
319
319
320
+ /* ************ 13) Solving for Current Salary ***********/
321
+ -- using GROUP BY isn't a good way to solve this problem because we need to pass in a lot of condition in GROUP BY clause.
322
+ SELECT emp_no, salary, to_date
323
+ FROM salaries
324
+ GROUP BY emp_no, salary, to_date
325
+ ORDER BY to_date DESC
326
+ LIMIT 10 ;
327
+
328
+ -- using window function for this problem
329
+ -- within frame, we compare the salary with salary of following and preceding one along the way.
330
+ -- LAST VALUE returns that very last value that won the salary comparing competition.
331
+ -- We order by from date Ascending order, so we knew ahead that the current salary should be the one on the most bottom.
332
+ SELECT
333
+ DISTINCT e .emp_no , e .first_name , d .dept_name ,
334
+ LAST_VALUE(s .salary ) OVER(
335
+ PARTITION BY e .emp_no
336
+ ORDER BY s .from_date
337
+ RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
338
+ ) AS " Current Salary"
339
+ FROM salaries s
340
+ JOIN employees e USING(emp_no)
341
+ JOIN dept_emp de USING (emp_no)
342
+ JOIN departments d USING (dept_no)
343
+ ORDER BY emp_no;
344
+
345
+ -- checking out the unique salary for each employees
346
+ SELECT emp_no, salary, from_date, to_date,
347
+ COUNT (salary) OVER(
348
+ PARTITION BY emp_no
349
+ ORDER BY to_date
350
+ )
351
+ FROM salaries;
352
+
353
+ /* -------------------------------------------------------------------------------------------------------------*/
354
+
355
+
356
+ /* *********************************** WINDOW FUNCTIONS ****************************************************/
357
+ /*
358
+ ---------------------------------------------------------------------------------------------------------------------
359
+ | Function | Purpose |
360
+ ----------------------------|---------------------------------------------------------------------------------------|
361
+ | SUM / MIN / MAX / AVG | Get the sum, min, .. of all the records in the partition |
362
+ | FIRST_VALUE | Return the value evaluated against the first row within the partition. |
363
+ | LAST_VALUE | Return the value evaluated against the last row within the partition. |
364
+ | NTH_VALUE | Return the value evaluated against the nth row in ordered partition. |
365
+ | PERCENT_RANK | Return the relative rank of the current row (rank-1) / (total rows - 1) |
366
+ | RANK | Rank the current row within its partition with gaps. |
367
+ | ROW_NUMBER | Number the current row within its partition starting from 1. (regardelss of framing)|
368
+ | LAG / LEAD | Access the values from the previous or next row. |
369
+ --------------------------------------------------------------------------------------------------------------------
370
+ */
371
+
372
+ /* ************ 14) FIRST_VALUE ***********/
373
+
374
+ /* I want to know how my price compares to the item with the LOWEST price in the SAME category */
375
+ SELECT
376
+ prod_id, price, category,
377
+ FIRST_VALUE(price) OVER(
378
+ PARTITION BY category
379
+ ORDER BY price
380
+ ) AS " Cheapest in the category"
381
+ FROM products
382
+ ORDER BY category, prod_id;
383
+
384
+ -- getting the same result using MIN which is easier, not needing ORDER BY too.
385
+ SELECT
386
+ prod_id, price, category,
387
+ MIN (price) OVER(
388
+ PARTITION BY category
389
+ ) AS " Cheapest in the category"
390
+ FROM products
391
+ ORDER BY category, prod_id;
320
392
321
393
394
+ /* ************ 15) LAST VALUE ****************/
322
395
396
+ /* I want to know how my price to the item with the HIGHEST PRICE in the SAME category */
397
+ SELECT
398
+ prod_id, price, category,
399
+ LAST_VALUE(price) OVER(
400
+ PARTITION BY category
401
+ ORDER BY price
402
+ RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
403
+ ) AS " Most Expensive Price in Category"
404
+ FROM products
405
+ ORDER BY category, prod_id;
406
+
407
+ -- using MAX
408
+ SELECT
409
+ prod_id, price, category,
410
+ MAX (price) OVER(
411
+ PARTITION BY category
412
+ ) AS " Highest Price in Category"
413
+ FROM products
414
+ ORDER BY category, prod_id;
415
+
416
+
417
+ /* ***************** 16) SUM ************************/
418
+
419
+ /* I want to see how much Cumulatively a customer has ordered at our store */
420
+ SELECT
421
+ customerid, orderid, orderdate, netamount,
422
+ SUM (netamount) OVER(
423
+ PARTITION BY customerid
424
+ ORDER BY orderid
425
+ ) AS " Cumulative Spending"
426
+ FROM orders
427
+ ORDER BY customerid, orderid;
323
428
324
429
430
+ /* *************** 17) ROW_NUMBER ****************/
431
+ -- ROW_NUMBER ignores the framing
432
+ -- no need to put parameters in ROW_NUMBER() function
433
+
434
+ /* I want to know where my product is positioned in the category by price */
435
+ SELECT
436
+ category, prod_id, price,
437
+ ROW_NUMBER() OVER(
438
+ PARTITION BY category
439
+ ORDER BY price
440
+ ) AS " Position in category by price"
441
+ FROM products
442
+ ORDER BY category
443
+
444
+ /* ------------------------------------------------------------------------------------------------------------*/
445
+
446
+ /* ******************** 19) Conditional Statements ***********************/
447
+
448
+ /* ********* CASE ************/
449
+ /*
450
+ SELECT a,
451
+ CASE
452
+ WHEN a=1 THEN 'one'
453
+ WHEN a=2 THEN 'two'
454
+ ELSE 'other'
455
+ END
456
+ FROM test;
457
+ */
325
458
459
+ -- 1) CASE statement can be used anywhere
460
+ SELECT
461
+ orderid, customerid,
462
+ CASE
463
+ WHEN customerid= 1 THEN ' my first customer'
464
+ ELSE ' not my first customer'
465
+ END AS " customer status" ,
466
+ netamount
467
+ FROM orders
468
+ ORDER BY customerid;
469
+
470
+ -- 2) using CASE in combination with WHERE
471
+ SELECT
472
+ orderid, customerid, netamount
473
+ FROM orders
474
+ WHERE
475
+ CASE
476
+ WHEN customerid > 10 THEN netamount < 100
477
+ ELSE netamount > 100
478
+ END
479
+ ORDER BY customerid;
480
+
481
+
482
+ -- 3) using CASE statement with Aggregate function
483
+
484
+ /* doing gesture of good faith, refunding 100$ for that order where spending is less than 100$ */
485
+ SELECT
486
+ SUM (
487
+ CASE
488
+ WHEN netamount < 100 THEN - 100
489
+ ELSE netamount
490
+ END
491
+ ) AS " Returns" ,
492
+ SUM (netamount) AS " Normal Total" ,
493
+ FROM orders;
494
+
495
+ /* ----------------------------------------------------------------------------------------------------------- */
496
+
497
+ /* ****************** 20) NULL IF *******************/
498
+ /*
499
+ Use NULLIF to fill in empty spots with a NULL value to avoid divide by zero issues
500
+
501
+ NULLIF(val1, val2)
502
+
503
+ if value 1 is equal to value 2, return NULL
504
+ */
505
+
506
+ SELECT NULLIF(0 , 0 ); -- returns null
507
+
508
+ SELECT NULLIF(' ABC' , ' DEF' ); -- returns ABC
509
+
510
+
511
+ /* ----------------------------------------------------------------------------------------------------------- */
512
+
513
+
514
+ /* ******************* 21) VIEWS *********************/
515
+ /*
516
+ Views allow you to store the results and query of previously run queries.
517
+
518
+ There are 2 types of views: 1) Materialized and 2) Non-Materialized Views.
519
+
520
+ 1) Materialzed View - stores the data PHYSICIALLY AND PERIODICALLY UPDATES it when tables change.
521
+ 2) Non-Materialized View - Query gets RE-RUN each time the view is called on.
522
+
523
+ */
524
+
525
+ /* ************** 22) VIEW syntax **************/
526
+ /*
527
+ + views are OUTPUT of query we ran.
528
+ + views act like TABLES you can query them.
529
+ + (Non-Materialized View): views tak VERY LITTLE SPACE to store. We only store the definition of the view, NOT ALL the data that it returns.
530
+ */
531
+
532
+ -- Create a view
533
+ CREATE VIEW view_name
534
+ AS query;
535
+
536
+ -- Update a view
537
+ CREATE OR REPLACE view_name
538
+ AS query;
539
+
540
+ -- Rename a view
541
+ ALTER VIEW exisitng_view_name RENAME TO new_view_name;
542
+
543
+ -- Delete a view
544
+ DROP VIEW IF EXISTS view_name;
545
+
546
+ /* ************** 23) Using VIEWS ******************/
547
+
548
+ -- get the last salary change of each employee
549
+ CREATE VIEW last_salary_change AS
550
+ SELECT e .emp_no ,
551
+ MAX (s .from_date )
552
+ FROM salaries s
553
+ JOIN employees e USING(emp_no)
554
+ JOIN dept_emp de USING(emp_no)
555
+ JOIN departments d USING(dept_no)
556
+ GROUP BY e .emp_no
557
+ ORDER BY e .emp_no ;
558
+
559
+ -- query entire data from that view
560
+ SELECT * FROM last_salary_change;
561
+
562
+ -- combine with view to get the latest salary of each employee
563
+ SELECT
564
+ s .emp_no , d .dept_name , s .from_date , s .salary
565
+ FROM last_salary_change lsc
566
+ JOIN salaries s USING(emp_no)
567
+ JOIN dept_emp de USING(emp_no)
568
+ JOIN departments d USING(dept_no)
569
+ WHERE s .from_date = lsc .max
570
+ ORDER BY s .emp_no ;
326
571
0 commit comments