├── .gitignore
├── QUESTIONS_AND_ANSWERS.md
├── README.md
├── docker-compose.yaml
└── source_data
├── cte_vs_subquery.sql
├── monthly_report.sql
├── sql_query.sql
├── sql_sales_project
├── build_table.sql
├── sales_data.csv
├── sales_project.md
├── sales_project.sql
└── vscode_screenshot.PNG
└── teachers_and_classes.sql
/.gitignore:
--------------------------------------------------------------------------------
1 | /db/pgdata
2 | ./vscode
--------------------------------------------------------------------------------
/QUESTIONS_AND_ANSWERS.md:
--------------------------------------------------------------------------------
1 | ## Common SQL interview Questions and Answers
2 |
3 | **Author**: Jaime M. Shaker
4 | **Email**: jaime.m.shaker@gmail.com
5 | **Website**: https://www.shaker.dev
6 | **LinkedIn**: https://www.linkedin.com/in/jaime-shaker/
7 |
8 | :exclamation: If you find this repository helpful, please consider giving it a :star:. Thanks! :exclamation:
9 |
10 |
11 | ❗ **Note** ❗
12 |
13 | ### Introduction:
14 |
15 | This repository contains entry-level SQL interview questions that appear in many interview preperation resources found online.
16 |
17 |
18 | #### 1. How do you find duplicates entries in a table?
19 |
20 | To find the duplicates in a table, first create a table with duplicate rows.
21 |
22 | ````sql
23 | DROP TABLE IF EXISTS animals;
24 | CREATE TABLE animals (
25 | animal_id int GENERATED ALWAYS AS IDENTITY,
26 | animal_type TEXT
27 | );
28 |
29 | INSERT INTO animals (animal_type)
30 | VALUES
31 | ('dog'),
32 | ('cat'),
33 | ('fish'),
34 | ('hamster'),
35 | ('dog'),
36 | ('pig'),
37 | ('cat'),
38 | ('cat'),
39 | ('rabbit'),
40 | ('turtle');
41 | ````
42 |
43 | Use a **select** **\*** statement to see all of our entries.
44 |
45 | ````sql
46 | SELECT * FROM animals;
47 | ````
48 |
49 | **Results:**
50 |
51 | animal_id|animal_type|
52 | ---------|-----------|
53 | 1|dog |
54 | 2|cat |
55 | 3|fish |
56 | 4|hamster |
57 | 5|dog |
58 | 6|pig |
59 | 7|cat |
60 | 8|cat |
61 | 9|rabbit |
62 | 10|turtle |
63 |
64 | Use the **COUNT()** function to find all duplicate rows.
65 |
66 | ````sql
67 | SELECT
68 | -- Get the column.
69 | animal_type,
70 | -- Count how many times this animal_type occurs.
71 | count(*)
72 | FROM
73 | animals
74 | GROUP BY
75 | -- Using an aggregate function forces us to group all like animal_types together.
76 | animal_type
77 | HAVING
78 | -- Only select values that have a count greater than one (multiple entries).
79 | count(*) > 1;
80 | ````
81 |
82 | **Results:**
83 |
84 | The results show all the names that appear more than once and their count.
85 |
86 | animal_type|count|
87 | -----------|-----|
88 | dog | 2|
89 | cat | 3|
90 |
91 | Back To Questions
92 |
93 |
94 | #### 2. How do you delete multiple entries from a table?
95 |
96 | You can delete duplicate rows by using a **DELETE USING** statement.
97 |
98 | Use the table created in the previous question to show how to delete those duplicates entries.
99 |
100 | ```sql
101 | DELETE
102 | FROM
103 | -- Add an alias to the id's we wish to keep
104 | animals AS a1
105 | USING
106 | -- Add an alias to the duplicate id's
107 | animals AS a2
108 | WHERE
109 | -- This statement will remove the greater value id's.
110 | a1.animal_id > a2.animal_id
111 | AND
112 | -- This statement ensures that both values are identical.
113 | a1.animal_type = a2.animal_type;
114 | ```
115 | Run the previous query to check again for duplicate entries.
116 |
117 | ```sql
118 | SELECT
119 | -- Get the column.
120 | animal_type,
121 | -- Count how many times this animal_type occurs.
122 | count(*)
123 | FROM
124 | animals
125 | GROUP BY
126 | -- Using an aggregate function forces us to group all like animal_types together.
127 | animal_type
128 | HAVING
129 | -- Only select values that have a count greater than one (multiple entries).
130 | count(*) > 1;
131 | ```
132 | Now, let's check the contents of the table. From the results returned, we can see that the duplicate entries have been deleted.
133 |
134 | ```sql
135 | SELECT * FROM animals;
136 | ```
137 |
138 | **Results:**
139 |
140 | animal_id|animal_type|
141 | ---------|-----------|
142 | 1|dog |
143 | 2|cat |
144 | 3|fish |
145 | 4|hamster |
146 | 6|pig |
147 | 9|rabbit |
148 | 10|turtle |
149 |
150 | Back To Questions
151 |
152 |
153 | #### 3. What is the difference between union and union all?
154 |
155 | The union operator combines two or more **SELECT** statements into one result set.
156 | * **UNION** returns only DISTINCT values. So no duplicate values in the final result set.
157 | * **UNION ALL** returns EVERYTHING including duplicates.
158 |
159 | Please note that to use UNION, each SELECT statement must
160 | 1. Have the same number of columns selected.
161 | 2. Have the same number of column expressions.
162 | 3. All columns must have the same data type.
163 | 4. All columns must have the same order.
164 |
165 | Let's create two small tables to illustrate this.
166 |
167 | ```sql
168 | DROP TABLE IF EXISTS coolest_guy_ever;
169 | CREATE TABLE coolest_guy_ever (
170 | name TEXT,
171 | year smallint
172 | );
173 |
174 | INSERT INTO coolest_guy_ever (name, year)
175 | VALUES
176 | ('jaime shaker', '1998'),
177 | ('jame dean', '1954'),
178 | ('arthur fonzarelli', '1960');
179 |
180 | DROP TABLE IF EXISTS sexiest_guy_ever;
181 | CREATE TABLE sexiest_guy_ever (
182 | name TEXT,
183 | year smallint
184 | );
185 |
186 | INSERT INTO sexiest_guy_ever (name, year)
187 | VALUES
188 | ('brad pitt', '1994'),
189 | ('jaime shaker', '1998'),
190 | ('george clooney', '2001');
191 | ```
192 | Let's use a simple **UNION** with our SQL statements.
193 |
194 | ```sql
195 | SELECT * FROM coolest_guy_ever
196 | UNION
197 | SELECT * FROM sexiest_guy_ever;
198 | ```
199 | **Results:** (Only distinct values are returned)
200 |
201 | name |year|
202 | -----------------|----|
203 | jame dean |1954|
204 | george clooney |2001|
205 | brad pitt |1994|
206 | arthur fonzarelli|1960|
207 | jaime shaker |1998|
208 |
209 | Let's use a simple **UNION ALL**.
210 |
211 | ```sql
212 | SELECT * FROM coolest_guy_ever
213 | UNION ALL
214 | SELECT * FROM sexiest_guy_ever;
215 | ```
216 | **Results:** (Returns duplicate values)
217 |
218 | name |year|
219 | -----------------|----|
220 | **jaime shaker** |**1998**|
221 | jame dean |1954|
222 | arthur fonzarelli|1960|
223 | brad pitt |1994|
224 | **jaime shaker** |**1998**|
225 | george clooney |2001|
226 |
227 | Back To Questions
228 |
229 |
230 | #### 4. Difference between rank,row_number and dense_rank?
231 |
232 | RANK, DENSE_RANK and ROW_NUMBER are called window functions. They must be used with the
233 | **OVER** clause.
234 | * **RANK**: Will rank a column but will skip a value if there are ties.
235 | * **DENSE_RANK**: Will rank a column bbut will NOT skip a value for ties.
236 | * **ROW_NUMBER**: Assigns a unique row number to each row.
237 |
238 | Let's display these functions with a simple table of users and salaries.
239 |
240 | ```sql
241 | DROP TABLE IF EXISTS user_salary;
242 | CREATE TABLE user_salary (
243 | user_name TEXT,
244 | salary int
245 | );
246 |
247 | INSERT INTO user_salary (user_name, salary)
248 | VALUES
249 | ('jaime', 100000),
250 | ('robert', 105000),
251 | ('elizabeth', 150000),
252 | ('josh', 80000),
253 | ('mary', 105000),
254 | ('heather', 80000),
255 | ('jennifer', 75000),
256 | ('ken', 80000);
257 | ```
258 | Lets use the window functions to show how they work.
259 |
260 | ```sql
261 | SELECT
262 | user_name,
263 | salary,
264 | RANK() OVER (ORDER BY salary desc),
265 | DENSE_RANK() OVER (ORDER BY salary desc),
266 | ROW_NUMBER() OVER ()
267 | FROM
268 | user_salary;
269 | ```
270 |
271 | The results are ordered by salary in descending order.
272 | * **RANK**: Shows that some user salaries tied, but then skips that amount until the next rank.
273 | * **DENSE_RANK**: Shows that some user salaries tied, but does NOT skip anything and goes immediately to the next rank.
274 | * **ROW_NUMBER**: Gives a unique row number to every row.
275 |
276 | **Results:**
277 |
278 | user_name|salary|rank|dense_rank|row_number|
279 | ---------|------|----|----------|----------|
280 | elizabeth|150000| 1| 1| 1|
281 | mary |105000| 2| 2| 2|
282 | robert |105000| 2| 2| 3|
283 | jaime |100000| 4| 3| 4|
284 | josh | 80000| 5| 4| 5|
285 | heather | 80000| 5| 4| 6|
286 | ken | 80000| 5| 4| 7|
287 | jennifer | 75000| 8| 5| 8|
288 |
289 |
290 | Back To Questions
291 |
292 |
293 | #### 5. Find records in a table which are not present in another table.
294 |
295 | This type of a join is called an **anti-join**. An anti-join does not have it's own syntax.
296 | It is basically a left join (or right join) with a **WHERE** clause.
297 |
298 | We can display this by performing a **LEFT ANTI-JOIN**.
299 |
300 | Let's create 2 different tables for this query.
301 |
302 | ```sql
303 | -- Create first table and add values
304 | DROP TABLE IF EXISTS left_table;
305 | CREATE TABLE left_table (
306 | id int
307 | );
308 |
309 | INSERT INTO left_table (id)
310 | VALUES
311 | (1),
312 | (2),
313 | (3),
314 | (4),
315 | (5),
316 | (6);
317 | ```
318 |
319 | ```sql
320 | -- Create second table and add values
321 | DROP TABLE IF EXISTS right_table;
322 | CREATE TABLE right_table (
323 | id int
324 | );
325 |
326 | INSERT INTO right_table (id)
327 | VALUES
328 | (2),
329 | (2),
330 | (3),
331 | (6),
332 | (6),
333 | (6);
334 | ```
335 |
336 | Let's perform our **LEFT ANTI-JOIN**.
337 |
338 | ```sql
339 | SELECT
340 | lt.id
341 | FROM left_table AS lt
342 | LEFT JOIN right_table AS rt
343 | ON lt.id = rt.id
344 | WHERE rt.id IS null;
345 | ```
346 |
347 | **Results:**
348 |
349 | This query returns the values in the LEFT TABLE that are **NOT**
350 | in the RIGHT TABLE.
351 |
352 | id|
353 | --|
354 | 1|
355 | 4|
356 | 5|
357 |
358 | Back To Questions
359 |
360 |
361 | #### 6. Find second highest salary employees in each department.
362 |
363 | This question will require us to rank salaries and partition that ranking
364 | by the department of each individual employee.
365 |
366 | I will add a manager id column to be used in the next question.
367 |
368 | ```sql
369 | DROP TABLE IF EXISTS employee;
370 | CREATE TABLE employee (
371 | emp_id int,
372 | emp_name TEXT,
373 | manager_id int,
374 | department TEXT,
375 | salary int
376 | );
377 |
378 | INSERT INTO employee (emp_id, emp_name, manager_id, department, salary)
379 | VALUES
380 | (1, 'jaime', 0, 'IT', 85000),
381 | (2, 'robert', 1, 'IT', 75000),
382 | (3, 'lisa', 1, 'IT', 65000),
383 | (4, 'chris', 1, 'IT', 55000),
384 | (5, 'mary', 7, 'SALES', 55000),
385 | (6, 'richard', 7, 'SALES', 85000),
386 | (7, 'jane', 0, 'SALES', 80000),
387 | (8, 'trevor', 7, 'SALES', 65000),
388 | (9, 'joan', 12, 'HR', 55000),
389 | (10, 'jennifer', 12, 'HR', 71000),
390 | (11, 'trish', 12, 'HR', 58000),
391 | (12, 'marge', 0, 'HR', 70000);
392 | ```
393 |
394 | Let's create a CTE (**Common Table Expression**) that assigns a rank value to each row by partition.
395 |
396 | ```sql
397 | WITH get_salary_rank AS (
398 | SELECT
399 | emp_name,
400 | department,
401 | salary,
402 | DENSE_RANK() OVER (PARTITION BY department ORDER BY salary desc) AS rnk
403 | FROM
404 | employee
405 | )
406 | ```
407 | Now, lets select **name**, **department** and **salary** where the rank = 2 from the CTE result set.
408 |
409 | ```sql
410 | SELECT
411 | emp_name,
412 | department,
413 | salary,
414 | rnk
415 | FROM
416 | get_salary_rank
417 | WHERE
418 | rnk = 2;
419 | ```
420 |
421 | **Results:**
422 |
423 | emp_name|department|salary|rnk|
424 | --------|----------|------|---|
425 | marge |HR | 70000| 2|
426 | robert |IT | 75000| 2|
427 | jane |SALES | 80000| 2|
428 |
429 | Back To Questions
430 |
431 |
432 | #### 7. Find employees with salaries greater than their manager's salary.
433 |
434 | Using the employee salary from the previous question, we can
435 | find this answer using a sub-query in the **WHERE** clause. I added
436 | a sub-query to the select statement to also show the manager's salary for reference.
437 |
438 | ```sql
439 | SELECT
440 | e1.emp_name,
441 | e1.department,
442 | e1.salary AS employee_salary,
443 | (SELECT salary from employee WHERE emp_id = e1.manager_id) AS manager_salary
444 | FROM
445 | employee AS e1
446 | WHERE
447 | e1.salary > (SELECT salary from employee WHERE emp_id = e1.manager_id);
448 | ```
449 |
450 | **Results:**
451 |
452 | emp_name|department|employee_salary|manager_salary|
453 | --------|----------|---------------|--------------|
454 | richard |SALES | 85000| 80000|
455 | jennifer|HR | 71000| 70000|
456 |
457 | Back To Questions
458 |
459 |
460 | #### 8. Difference between inner and left join?
461 |
462 | An **INNER JOIN** will return only join matching rows between tables.
463 | A **LEFT JOIN** will return all items in the left table and matching rows from the right table.
464 |
465 | Using the left_table and right_table from question #5, we can see how they work.
466 |
467 | **INNER JOIN**:
468 |
469 | ```sql
470 | SELECT
471 | lt.id
472 | FROM
473 | left_table AS lt
474 | INNER JOIN
475 | right_table AS rt
476 | ON
477 | lt.id = rt.id;
478 | ```
479 |
480 | **Results:**
481 |
482 | These results exclude id **#1** and **#5** from the left_table because they do not exist in the right_table. It will also return a result for EVERY match that occurs in both tables.
483 |
484 | id|
485 | --|
486 | 2|
487 | 2|
488 | 3|
489 | 6|
490 | 6|
491 | 6|
492 |
493 | **LEFT JOIN**:
494 |
495 | ```sql
496 | SELECT
497 | lt.id
498 | FROM
499 | left_table AS lt
500 | LEFT JOIN
501 | right_table AS rt
502 | ON
503 | lt.id = rt.id;
504 | ```
505 |
506 | **Results:**
507 |
508 | These results include **ALL** rows from the left_table and only those that match from the right table.
509 |
510 | id|
511 | --|
512 | 1|
513 | 2|
514 | 2|
515 | 3|
516 | 4|
517 | 5|
518 | 6|
519 | 6|
520 | 6|
521 |
522 | Back To Questions
523 |
524 |
525 | #### 9. Update a table and swap gender values.
526 |
527 | This question can be answered using a **CASE** statement in an update query.
528 |
529 | First, lets create a table where (**M**)ales have an odd id number and (**F**)emales have an even id number.
530 |
531 | ```sql
532 | DROP TABLE IF EXISTS people;
533 | CREATE TABLE people (
534 | id int GENERATED ALWAYS AS IDENTITY,
535 | name TEXT,
536 | gender varchar(1)
537 | );
538 |
539 | INSERT INTO people (name, gender)
540 | VALUES
541 | ('mike', 'M'),
542 | ('sarah', 'F'),
543 | ('john', 'M'),
544 | ('lisa', 'F'),
545 | ('jacob', 'M'),
546 | ('ellen', 'F'),
547 | ('christopher', 'M'),
548 | ('maria', 'F');
549 | ```
550 | Let's take a look at the table.
551 |
552 | ```sql
553 | SELECT * FROM people;
554 | ```
555 |
556 | **Results:**
557 |
558 | id|name |gender|
559 | --|-----------|------|
560 | 1|mike |M |
561 | 2|sarah |F |
562 | 3|john |M |
563 | 4|lisa |F |
564 | 5|jacob |M |
565 | 6|ellen |F |
566 | 7|christopher|M |
567 | 8|maria |F |
568 |
569 | Now let's **UPDATE** the table and swap the gender values using a **CASE** statement.
570 |
571 | ```sql
572 | UPDATE people
573 | SET gender =
574 | CASE
575 | WHEN gender = 'M' THEN 'F'
576 | ELSE 'M'
577 | END
578 | WHERE
579 | gender IS NOT NULL;
580 | ```
581 |
582 | Let's take a look at the table.
583 |
584 | ```sql
585 | SELECT * FROM people;
586 | ```
587 |
588 | **Results:**
589 |
590 | id|name |gender|
591 | --|-----------|------|
592 | 1|mike |F |
593 | 2|sarah |M |
594 | 3|john |F |
595 | 4|lisa |M |
596 | 5|jacob |F |
597 | 6|ellen |M |
598 | 7|christopher|F |
599 | 8|maria |M |
600 |
601 | Back To Questions
602 |
603 |
604 | #### 10. Number of records in output with different kinds of join.
605 |
606 | Let's create two new tables to display the different types of joins.
607 |
608 | * INNER JOIN
609 | * LEFT JOIN
610 | * RIGHT JOIN
611 | * FULL OUTER JOIN
612 | * CROSS JOIN
613 |
614 | ```sql
615 | DROP TABLE IF EXISTS left_names;
616 | CREATE TABLE left_names (
617 | id text
618 | );
619 |
620 | INSERT INTO left_names
621 | VALUES
622 | ('jaime'),
623 | ('melissa'),
624 | ('samuel'),
625 | ('aaron'),
626 | ('norma'),
627 | (NULL),
628 | ('christopher');
629 |
630 | DROP TABLE IF EXISTS right_names;
631 | CREATE TABLE right_names (
632 | id text
633 | );
634 |
635 | INSERT INTO right_names
636 | VALUES
637 | ('jaime'),
638 | ('janet'),
639 | (NULL),
640 | ('sonia'),
641 | ('melissa'),
642 | ('melissa'),
643 | ('chris'),
644 | ('jaime');
645 | ```
646 | **INNER JOIN**
647 |
648 | ```sql
649 | SELECT
650 | count(*) result_count
651 | from
652 | (SELECT
653 | l.id
654 | FROM
655 | left_names AS l
656 | INNER JOIN
657 | right_names AS r
658 | ON
659 | l.id = r.id) AS tmp
660 | ```
661 |
662 | **Inner-Query Results**:
663 |
664 | id |
665 | -------|
666 | jaime |
667 | jaime |
668 | melissa|
669 | melissa|
670 |
671 | **Outer-Query Results**:
672 |
673 | result_count|
674 | ------------|
675 | 4|
676 |
677 | **LEFT JOIN**
678 |
679 | ```sql
680 | SELECT
681 | count(*) result_count
682 | from
683 | (SELECT
684 | l.id
685 | FROM
686 | left_names AS l
687 | LEFT JOIN
688 | right_names AS r
689 | ON
690 | l.id = r.id) AS tmp
691 | ```
692 |
693 | **Inner-Query Results**:
694 |
695 | id |
696 | -----------|
697 | aaron |
698 | christopher|
699 | jaime |
700 | jaime |
701 | melissa |
702 | melissa |
703 | norma |
704 | samuel |
705 | **NULL**|
706 |
707 | **Outer-Query Results**:
708 |
709 | result_count|
710 | ------------|
711 | 9|
712 |
713 | **RIGHT JOIN**
714 |
715 | ```sql
716 | SELECT
717 | count(*) result_count
718 | from
719 | (SELECT
720 | r.id
721 | FROM
722 | left_names AS l
723 | RIGHT JOIN
724 | right_names AS r
725 | ON
726 | l.id = r.id) AS tmp
727 | ```
728 |
729 | **Inner-Query Results**:
730 |
731 | id |
732 | -------|
733 | chris |
734 | jaime |
735 | jaime |
736 | janet |
737 | melissa|
738 | melissa|
739 | sonia |
740 | **NULL**|
741 |
742 | **Outer-Query Results**:
743 |
744 | result_count|
745 | ------------|
746 | 8|
747 |
748 | **FULL OUTER JOIN**
749 |
750 | ```sql
751 | SELECT
752 | count(*) result_count
753 | from
754 | (SELECT
755 | l.id AS left_table,
756 | r.id AS right_table
757 | FROM
758 | left_names AS l
759 | FULL OUTER JOIN
760 | right_names AS r
761 | ON
762 | l.id = r.id) AS tmp
763 | ```
764 |
765 | **Inner-Query Results**:
766 |
767 | left_table |right_table|
768 | -----------|-----------|
769 | aaron | Null |
770 | Null |chris |
771 | christopher| Null |
772 | jaime |jaime |
773 | jaime |jaime |
774 | |janet | Null
775 | melissa |melissa |
776 | melissa |melissa |
777 | norma | Null |
778 | samuel | Null |
779 | Null | Null |
780 | Null |sonia |
781 | | Null | Null
782 |
783 | **Outer-Query Results**:
784 |
785 | result_count|
786 | ------------|
787 | 13|
788 |
789 | **CROSS JOIN**
790 |
791 | ```sql
792 | SELECT
793 | count(*) result_count
794 | from
795 | (SELECT
796 | l.id
797 | FROM
798 | left_names AS l
799 | CROSS JOIN
800 | right_names AS r) AS tmp
801 | ```
802 |
803 | **Inner-Query Results**:
804 |
805 | Every row in the left table will be joined to every row in the right table.
806 |
807 | **Outer-Query Results**:
808 |
809 | result_count|
810 | ------------|
811 | 56|
812 |
813 | Back To Questions
814 |
815 |
816 | #### 11. What is the difference between the DELETE, TRUNCATE and DROP statement?
817 |
818 | - **DELETE** is a DML (Data Manipulation Language) command that is used to delete rows from a table.
819 | - **TRUNCATE** is a DDL (Data Definition Language) command that is used to empty/delete **ALL** rows from a table but maintains the tables structure.
820 | - **DROP** is a DDL (Data Definition Language) command that is used to completly delete the table and its structure from the schema/database.
821 |
822 | ```sql
823 | DROP TABLE IF EXISTS generic_table;
824 | CREATE TABLE generic_table (
825 | id int
826 | );
827 |
828 | INSERT INTO generic_table
829 | VALUES
830 | (1),
831 | (2),
832 | (3),
833 | (4),
834 | (5),
835 | (6);
836 | ```
837 |
838 | Lets take a look at our generic table.
839 |
840 | ```sql
841 | select * from generic_table;
842 | ```
843 | **Results**:
844 |
845 | id|
846 | --|
847 | 1|
848 | 2|
849 | 3|
850 | 4|
851 | 5|
852 | 6|
853 |
854 | Let's **DELETE** all rows with even number ID's.
855 |
856 | ```sql
857 | DELETE FROM generic_table
858 | WHERE (id % 2) = 0;
859 | ```
860 |
861 | Let's take a look at our generic table after the **DELETE** statement.
862 |
863 | ```sql
864 | select * from generic_table;
865 | ```
866 | **Results**:
867 |
868 | id|
869 | --|
870 | 1|
871 | 3|
872 | 5|
873 |
874 | Let's use the **TRUNCATE** statement.
875 |
876 | ```sql
877 | TRUNCATE TABLE generic_table;
878 | ```
879 | Lets take a look at our generic table after the **TRUNCATE** statement.
880 |
881 | ```sql
882 | select * from generic_table;
883 | ```
884 | **Results**:
885 |
886 | id|
887 | --|
888 |
889 | Let's use the **DROP** statement.
890 |
891 | ```sql
892 | DROP TABLE generic_table;
893 | ```
894 | Lets take a look at our generic table after the **DROP** statement.
895 |
896 | ```sql
897 | select * from generic_table;
898 | ```
899 | **Results**:
900 |
901 | This results in an error.
902 | ❗ **SQL Error: ERROR: relation "generic_table" does not exist** ❗
903 |
904 | Back To Questions
905 |
906 |
907 | #### 12. What is the difference between the NOW() and CURRENT_DATE functions?
908 |
909 | - **NOW()** returns the timestamp (YYYY-MM-DD HH:MM:SS) of when the function was executed.
910 | - **CURRENT_DATE** returns the date of the current day (YYYY-MM-DD).
911 |
912 | ```sql
913 | SELECT
914 | now(),
915 | current_date;
916 | ```
917 |
918 | **Results**:
919 |
920 | now |current_date|
921 | -----------------------------|------------|
922 | 2022-12-04 07:19:52.891 -0600| 2022-12-04|
923 |
924 | Back To Questions
925 |
926 |
927 | #### 13. What is the difference between the ‘IN’ and ‘BETWEEN’ condition operators?
928 |
929 | - **IN** is used to check for values contained in a specific set of values.
930 | - **BETWEEN** is used to return rows within a range of values.
931 |
932 | Create a new table.
933 |
934 | ```sql
935 | DROP TABLE IF EXISTS student_grades;
936 | CREATE TABLE student_grades (
937 | student_name TEXT,
938 | score int
939 | );
940 |
941 | INSERT INTO student_grades (student_name, score)
942 | VALUES
943 | ('john', 95),
944 | ('mary', 80),
945 | ('jacob', 79),
946 | ('calvin', 98),
947 | ('jennifer', 100),
948 | ('chris', 89),
949 | ('brenda', 90),
950 | ('michael', 71),
951 | ('xavier', 69);
952 | ```
953 |
954 | Let's use the **IN** operator to returns students who missed the next letter grade by one point.
955 |
956 | ```sql
957 | SELECT
958 | student_name,
959 | score
960 | FROM
961 | student_grades
962 | WHERE score IN (69, 79, 89);
963 | ```
964 |
965 | **Results**:
966 |
967 | student_name|score|
968 | ------------|-----|
969 | jacob | 79|
970 | chris | 89|
971 | xavier | 69|
972 |
973 | Let's use the BETWEEN operator to returns students who have a score between 85 and 95.
974 |
975 | ```sql
976 | SELECT
977 | student_name,
978 | score
979 | FROM
980 | student_grades
981 | WHERE score BETWEEN 85 AND 95;
982 | ```
983 |
984 | **Results**:
985 |
986 | student_name|score|
987 | ------------|-----|
988 | john | 95|
989 | chris | 89|
990 | brenda | 90|
991 |
992 | Back To Questions
993 |
994 |
995 | #### 14. What is the difference between the WHERE and the HAVING clause?
996 |
997 | Both of these clauses are used for filtering results, but this question is easier to understand if you understand that there is a difference between '**The order of execution**' and '**The order of writing**' an SQL query.
998 |
999 | The order of execution is as follows:
1000 |
1001 | 1. FROM/JOIN
1002 | 2. WHERE
1003 | 3. GROUP BY
1004 | 4. HAVING
1005 | 5. SELECT
1006 | 6. Distinct
1007 | 7. ORDER BY
1008 | 8. LIMIT / OFFSET
1009 |
1010 | - **WHERE** is used to filter individual rows BEFORE groupings are made. Which is why aggregate functions CANNOT be used in a where clause
1011 | because the GROUP does NOT exist when the WHERE clause if filtering.
1012 | - **HAVING** is used for filtering values from a GROUP which would allow you to use aggregate functions within its conditions.
1013 |
1014 | Create a table where we can illustrate the differences.
1015 |
1016 | ```sql
1017 | DROP TABLE IF EXISTS avg_student_grades;
1018 | CREATE TABLE avg_student_grades (
1019 | student_name TEXT,
1020 | score int
1021 | );
1022 |
1023 | INSERT INTO avg_student_grades (student_name, score)
1024 | VALUES
1025 | ('john', 89),
1026 | ('mary', 99),
1027 | ('jacob', 79),
1028 | ('john', 83),
1029 | ('mary', 92),
1030 | ('jacob', 75);
1031 | ```
1032 |
1033 | Use a **WHERE** clause to find all test scores greater than 80.
1034 |
1035 | ```sql
1036 | SELECT
1037 | student_name,
1038 | score
1039 | FROM
1040 | avg_student_grades
1041 | WHERE
1042 | score > 80
1043 | ORDER BY
1044 | student_name;
1045 | ```
1046 |
1047 | **Results**:
1048 |
1049 | student_name|score|
1050 | ------------|-----|
1051 | john | 89|
1052 | john | 83|
1053 | mary | 99|
1054 | mary | 92|
1055 |
1056 | Use a **HAVING** clause to find the **MAX()** score in a group for test scores greater than 80.
1057 |
1058 | ```sql
1059 | SELECT
1060 | student_name,
1061 | max(score)AS max_score
1062 | FROM
1063 | avg_student_grades
1064 | GROUP BY
1065 | student_name
1066 | HAVING
1067 | max(score) > 80;
1068 | ```
1069 |
1070 | **Results**:
1071 |
1072 | student_name|max_score|
1073 | ------------|---------|
1074 | john | 89|
1075 | mary | 99|
1076 |
1077 | Back To Questions
1078 |
1079 |
1080 | #### 15. From a table of names, write a query that only returns EVEN number rows.
1081 |
1082 | For this query we will use the **ROW_NUMBER()** window function in a CTE (Common Table Expression) and the **MODULO** (remainder) operator. For easier tracking, I will use common MALE names for odd number entries and FEMALE names for the even number entries.
1083 |
1084 | ```sql
1085 | DROP TABLE IF EXISTS common_names;
1086 | CREATE TABLE common_names (
1087 | user_name TEXT
1088 | );
1089 |
1090 | INSERT INTO common_names (user_name)
1091 | VALUES
1092 | ('aaron'),
1093 | ('mary'),
1094 | ('luke'),
1095 | ('jennifer'),
1096 | ('mark'),
1097 | ('laura'),
1098 | ('john'),
1099 | ('olivia');
1100 | ```
1101 | We will use a CTE to give each entry a unique row number.
1102 |
1103 | ```sql
1104 | WITH get_row_number as (
1105 | SELECT
1106 | ROW_NUMBER() OVER () AS rn,
1107 | user_name
1108 | FROM
1109 | common_names
1110 | )
1111 | ```
1112 | Now let's select only the names where the newly assigned row number is EVEN.
1113 |
1114 | ```sql
1115 | SELECT
1116 | rn as even_id,
1117 | user_name
1118 | FROM
1119 | get_row_number
1120 | WHERE
1121 | (rn % 2) = 0;
1122 | ```
1123 |
1124 | **Results**:
1125 |
1126 | even_id|user_name|
1127 | -------|---------|
1128 | 2|mary |
1129 | 4|jennifer |
1130 | 6|laura |
1131 | 8|olivia |
1132 |
1133 | Back To Questions
1134 |
1135 |
1136 | #### 16. How can we copy the contents of one table to a new table?
1137 |
1138 | Create a new table.
1139 |
1140 | ```sql
1141 | DROP TABLE IF EXISTS original_table;
1142 | CREATE TABLE original_table (
1143 | user_id serial,
1144 | user_name TEXT,
1145 | user_age smallint
1146 | );
1147 |
1148 | INSERT INTO original_table (user_name, user_age)
1149 | VALUES
1150 | ('william', 34),
1151 | ('marjorie', 22),
1152 | ('larence', 55),
1153 | ('maria', 19),
1154 | ('moses', 40),
1155 | ('britney', 39),
1156 | ('jake', 27),
1157 | ('barbara', 42);
1158 | ```
1159 | First we have to create a new table with the same structure as the original table and without data.
1160 |
1161 | ```sql
1162 | DROP TABLE IF EXISTS copied_table;
1163 | CREATE TABLE copied_table AS
1164 | TABLE original_table
1165 | WITH NO DATA;
1166 | ```
1167 | This statement creates an empty table with the same structure as the original table. We can now **INSERT** (copy) the data from the original table.
1168 |
1169 | ```sql
1170 | INSERT INTO copied_table
1171 | (SELECT * FROM original_table);
1172 | ```
1173 | We can take a look at our copied table.
1174 |
1175 | ```sql
1176 | SELECT * FROM copied_table;
1177 | ```
1178 | **Results**:
1179 |
1180 | user_id|user_name|user_age|
1181 | -------|---------|--------|
1182 | 1|william | 34|
1183 | 2|marjorie | 22|
1184 | 3|larence | 55|
1185 | 4|maria | 19|
1186 | 5|moses | 40|
1187 | 6|britney | 39|
1188 | 7|jake | 27|
1189 | 8|barbara | 42|
1190 |
1191 | We can now **DROP** the original table.
1192 |
1193 | ```sql
1194 | DROP TABLE original_table;
1195 | ```
1196 |
1197 | Back To Questions
1198 |
1199 |
1200 | #### 17. In string pattern matching, what is the difference between LIKE and ILIKE?
1201 |
1202 | LIKE and ILIKE are both used in pattern matching.
1203 |
1204 | - **LIKE** is used for case-sensitive pattern matching.
1205 | - **ILIKE** is used for case-insensitive pattern matching.
1206 |
1207 | ```sql
1208 | DROP TABLE IF EXISTs case_sensitivity;
1209 | CREATE TABLE case_sensitivity (
1210 | crazy_case TEXT
1211 | );
1212 |
1213 | INSERT INTO
1214 | case_sensitivity (crazy_case)
1215 | VALUES
1216 | ('jaime'),
1217 | ('JAIME'),
1218 | ('jAImE');
1219 | ```
1220 | Let's see what LIKE pattern matching returns when using upper-case characters.
1221 |
1222 | ```sql
1223 | SELECT
1224 | *
1225 | FROM case_sensitivity
1226 | WHERE crazy_case LIKE '%JAIME%';
1227 | ```
1228 |
1229 | **Results**: (Exact match)
1230 |
1231 | crazy_case|
1232 | ----------|
1233 | JAIME |
1234 |
1235 | Now let's see what ILIKE pattern matching returns.
1236 |
1237 | ```sql
1238 | SELECT
1239 | *
1240 | FROM case_sensitivity
1241 | WHERE crazy_case ILIKE '%JAIME%';
1242 | ```
1243 |
1244 | **Results**:
1245 |
1246 | crazy_case|
1247 | ----------|
1248 | jaime |
1249 | JAIME |
1250 | jAImE |
1251 |
1252 | ❗ Make note that ILIKE **CANNOT** use an index created on a case-sensitive column for optimization. ❗
1253 |
1254 | Back To Questions
1255 |
1256 |
1257 | #### 18. What are Aggregate and Scalar functions in an RDBMS and can you provide an example of their use?
1258 |
1259 | Aggregate functions are calculations that are applied to a set or group of values in a column that returns a single, summarized value. Some of the most common functions include:
1260 |
1261 | - COUNT()
1262 | - AVG()
1263 | - MIN()
1264 | - MAX()
1265 | - SUM()
1266 |
1267 | Scalar functions are calculations that are applied to a value provided by user input and return a single value. Some Scalar functions such as NOW() do not require user input. String functions can provide great examples of Scalar functions such as:
1268 |
1269 | - LENGTH()
1270 | - LOWER()
1271 | - UPPER()
1272 | - REVERSE()
1273 | - REPLACE()
1274 | - SUBSTRING()
1275 |
1276 | ```sql
1277 | DROP TABLE IF EXISTS function_examples;
1278 | CREATE TABLE function_examples (
1279 | student_name TEXT,
1280 | score int
1281 | );
1282 |
1283 | INSERT INTO function_examples (student_name, score)
1284 | VALUES
1285 | ('Jaime', 94),
1286 | ('Sophia', 95),
1287 | ('William', 79),
1288 | ('Jaime', 83),
1289 | ('Sophia', 88),
1290 | ('William', 68),
1291 | ('Jaime', 70),
1292 | ('Sophia', 85),
1293 | ('William', 86),
1294 | ('Jaime', 77),
1295 | ('Sophia', 81),
1296 | ('William', 80);
1297 | ```
1298 | Let's return values using the **Aggregate** functions. Order from highest total_score to lowest. We will also round the AVG to two decimal points.
1299 |
1300 | ```sql
1301 | SELECT
1302 | student_name,
1303 | COUNT(*) AS name_count,
1304 | round(AVG(score), 2) AS avg_score,
1305 | MIN(score) AS min_score,
1306 | MAX(score) AS max_score,
1307 | SUM(score) AS total_score
1308 | FROM
1309 | function_examples
1310 | GROUP BY
1311 | student_name
1312 | ORDER BY
1313 | total_score DESC;
1314 | ```
1315 |
1316 | **Results**:
1317 |
1318 | student_name|name_count|avg_score|min_score|max_score|total_score|
1319 | ------------|----------|---------|---------|---------|-----------|
1320 | Sophia | 4| 87.25| 81| 95| 349|
1321 | Jaime | 4| 81.00| 70| 94| 324|
1322 | William | 4| 78.25| 68| 86| 313|
1323 |
1324 | Let's return values using the **Scalar** functions.
1325 |
1326 | ```sql
1327 | SELECT
1328 | DISTINCT student_name,
1329 | LENGTH(student_name) AS string_length,
1330 | LOWER(student_name) AS lower_case,
1331 | UPPER(student_name) AS upper_case,
1332 | REVERSE(student_name) AS reversed_name,
1333 | REPLACE(student_name, 'a', '*') AS replaced_A,
1334 | SUBSTRING(student_name, 1, 3) AS first_three_chars
1335 | FROM
1336 | function_examples;
1337 | ```
1338 |
1339 | **Results**:
1340 |
1341 | student_name|string_length|lower_case|upper_case|reversed_name|replaced_a|first_three_chars|
1342 | ------------|-------------|----------|----------|-------------|----------|-----------------|
1343 | Jaime | 5|jaime |JAIME |emiaJ |J*ime |Jai |
1344 | William | 7|william |WILLIAM |mailliW |Willi*m |Wil |
1345 | Sophia | 6|sophia |SOPHIA |aihpoS |Sophi* |Sop |
1346 |
1347 | Back To Questions
1348 |
1349 |
1350 | #### 19. How can you calculate the MEDIAN of a numerical field?
1351 |
1352 | Although PostgreSQL does not have a function to calculate the median of a column, it does provide a column that can find the 50th percentile. Finding the percentile can be done using the **PERCENTILE_CONT()** function.
1353 |
1354 | For simplicity, let's find the **MEDIAN** using a series of numbers from 1-25.
1355 |
1356 | ```sql
1357 | SELECT
1358 | PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY generate_series) AS median
1359 | FROM generate_series(1, 25);
1360 | ```
1361 | **Results**:
1362 |
1363 | median|
1364 | ------|
1365 | 13.0|
1366 |
1367 | Back To Questions
1368 |
1369 |
1370 | #### 20. Display two different methods to concatnate strings in PostgreSQL.
1371 |
1372 | In PostgreSQL we can concatnate (join) strings using the **CONCAT()** function or using **||** as an alternative method.
1373 |
1374 | Let's create a table with two columns. One for the users first name and one for their surname/last name.
1375 |
1376 | ```sql
1377 | DROP TABLE IF EXISTS full_names;
1378 | CREATE TABLE full_names (
1379 | first_name TEXT,
1380 | last_name TEXT
1381 | );
1382 |
1383 | INSERT INTO full_names (first_name, last_name)
1384 | VALUES
1385 | ('jaime', 'shaker'),
1386 | ('clint', 'eastwood'),
1387 | ('martha', 'stewart'),
1388 | ('captain', 'kangaroo');
1389 | ```
1390 |
1391 | Now we can use a select statement to concatnate our columns.
1392 |
1393 | ```sql
1394 | SELECT
1395 | concat(first_name, ' ', last_name) AS fullname_concat_function,
1396 | first_name || ' ' || last_name AS fullname_bar_alternative
1397 | FROM
1398 | full_names;
1399 | ```
1400 |
1401 | **Results**:
1402 |
1403 | fullname_concat_function|fullname_bar_alternative|
1404 | ------------------------|------------------------|
1405 | jaime shaker |jaime shaker |
1406 | clint eastwood |clint eastwood |
1407 | martha stewart |martha stewart |
1408 | captain kangaroo |captain kangaroo |
1409 |
1410 | Back To Questions
1411 |
1412 |
1413 | #### 21. How can we get the Year (month, day hour, etc...) from a timestamp?
1414 |
1415 | The **EXTRACT()** function allows us to 'extract' which specific field to return from a timestamp or an interval.
1416 |
1417 | The **EXTRACT()** function returns a double precision value so I am casting to a numeric
1418 | type for readability.
1419 |
1420 | For this example I am using the **NOW()** function to return a timestamp.
1421 |
1422 | ```sql
1423 | SELECT
1424 | now() AS moment_in_time,
1425 | EXTRACT(century FROM now())::numeric AS century,
1426 | EXTRACT(decade FROM now())::numeric AS decade,
1427 | EXTRACT(YEAR FROM now())::numeric AS year,
1428 | EXTRACT(MONTH FROM now())::numeric AS month,
1429 | EXTRACT(DAY FROM now())::numeric AS day,
1430 | EXTRACT(TIMEZONE_HOUR FROM now())::numeric AS timezone;
1431 | ```
1432 |
1433 | **Results**:
1434 |
1435 | moment_in_time |century|decade|year|month|day|timezone|
1436 | -----------------------------|-------|------|----|-----|---|--------|
1437 | 2022-12-08 19:50:24.508 -0600| 21| 202|2022| 12| 8| -6|
1438 |
1439 | Back To Questions
1440 |
1441 |
1442 | #### 22. Produce a query that only returns the top 50% of the records.
1443 |
1444 | This problem can be solved using a sub-query in the WHERE statement.
1445 |
1446 | Let's use a CTE with the **GENERATE_SERIES()** function to create 10 rows to query.
1447 |
1448 | ```sql
1449 | WITH get_half AS (
1450 | SELECT
1451 | *
1452 | FROM generate_series(1, 10)
1453 | )
1454 | SELECT
1455 | generate_series AS top_half
1456 | FROM
1457 | get_half
1458 | WHERE
1459 | generate_series <= (SELECT count(*)/2 FROM get_half);
1460 | ```
1461 |
1462 | **Results**:
1463 |
1464 | top_half|
1465 | --------|
1466 | 1|
1467 | 2|
1468 | 3|
1469 | 4|
1470 | 5|
1471 |
1472 | Back To Questions
1473 |
1474 |
1475 | #### 23. How can you insert a new row into a table OR update the row if it already exists?
1476 |
1477 | In PostgreSQL we can use the **UPSERT** feature to accomplish this task. In most RDBMS, this
1478 | feature is called a **MERGE**. The term **UPSERT** is derived from a combination of an **UP**date and an in**SERT** statement.
1479 |
1480 | We would need to add the **ON CONFLICT** clause to the **INSERT** statement to utilize the UPSERT feature.
1481 |
1482 | For this exercise we will presuppose that the user_name MUST be unique and a user can only have ONE phone number on record.
1483 |
1484 | ```sql
1485 | DROP TABLE IF EXISTS user_phone_number;
1486 |
1487 | CREATE TABLE user_phone_number (
1488 | user_name TEXT UNIQUE,
1489 | user_phone varchar(50)
1490 | );
1491 |
1492 | INSERT INTO user_phone_number (user_name, user_phone)
1493 | VALUES
1494 | ('jaime', '555-555-5555'),
1495 | ('lara', '444-444-4444'),
1496 | ('kristen', '222-222-2222');
1497 |
1498 | SELECT * FROM user_phone_number;
1499 | ```
1500 | We now have a table with unique user_names and a phone number.
1501 |
1502 | **Results**:
1503 |
1504 | user_name|user_phone |
1505 | ---------|------------|
1506 | jaime |555-555-5555|
1507 | lara |444-444-4444|
1508 | kristen |222-222-2222|
1509 |
1510 | If we attempt to add another phone number to an existing user, a conflict will occur. We could use **DO NOTHING** which does nothing if the user_name already exists.
1511 |
1512 | ```sql
1513 | INSERT INTO user_phone_number (user_name, user_phone)
1514 | VALUES
1515 | ('jaime', '123-456-7890')
1516 | ON CONFLICT (user_name)
1517 | DO NOTHING;
1518 | ```
1519 |
1520 | ❗ OR ❗
1521 |
1522 | We could update the record.
1523 |
1524 | ```sql
1525 | INSERT INTO user_phone_number (user_name, user_phone)
1526 | VALUES
1527 | ('jaime', '123-456-7890')
1528 | ON CONFLICT (user_name)
1529 | DO
1530 | UPDATE SET user_phone = '123-456-7890';
1531 |
1532 | SELECT * FROM user_phone_number;
1533 | ```
1534 |
1535 | **Results**:
1536 |
1537 | user_name|user_phone |
1538 | ---------|------------|
1539 | lara |444-444-4444|
1540 | kristen |222-222-2222|
1541 | jaime |123-456-7890|
1542 |
1543 | However, if we do not wish to overwrite the previous record, we could append/concatnate the new phone number to the existing value instead of using the previous statement.
1544 |
1545 | ```sql
1546 | INSERT INTO user_phone_number (user_name, user_phone)
1547 | VALUES
1548 | ('jaime', '123-456-7890')
1549 | ON CONFLICT (user_name)
1550 | DO
1551 | UPDATE SET user_phone = EXCLUDED.user_phone || ';' || user_phone_number.user_phone;
1552 |
1553 | SELECT * FROM user_phone_number;
1554 | ```
1555 |
1556 | **Results**:
1557 |
1558 | user_name|user_phone |
1559 | ---------|-------------------------|
1560 | lara |444-444-4444 |
1561 | kristen |222-222-2222 |
1562 | jaime |123-456-7890;555-555-5555|
1563 |
1564 | Back To Questions
1565 |
1566 |
1567 | #### 24. What is the use of the COALESCE() function?
1568 |
1569 | The **COALESCE()** function has the same functionality as **IFNULL** in standard SQL. It is basically a function that accepts an unlimited number of arguments and returns the first argument that is NOT null.
1570 |
1571 | Once it has found the first non-null argument, all other arguments are NOT evaluated. It will return a null value if all arguments are null.
1572 |
1573 | ```sql
1574 | SELECT COALESCE(NULL, 'jaime', 'shaker');
1575 | ```
1576 |
1577 | **Results**:
1578 |
1579 | coalesce|
1580 | --------|
1581 | jaime |
1582 |
1583 | Back To Questions
1584 |
1585 |
1586 | #### 25. Is the COALESCE() function the same as the NULLIF() function?
1587 |
1588 | No. The **COALESCE()** function can accept an unlimited number of arguments and returns the first non-null argument. Although You can mimic a **NULLIF()** function, they are different. Let's add a **' '** to our previous query to display what **COALESCE()** returns.
1589 |
1590 | ```sql
1591 | SELECT COALESCE(NULL, '', 'jaime', 'shaker');
1592 | ```
1593 |
1594 | **Results**:
1595 |
1596 | coalesce|
1597 | --------|
1598 | |
1599 |
1600 | This results in an empty value because empty (' ') and NULL are not the same. The **NULLIF()** function returns NULL if argument #1 is equal to Argument #2, else it returns Argument #1.
1601 |
1602 | ```sql
1603 | SELECT NULLIF('jaime', 'shaker');
1604 | ```
1605 |
1606 | **Results**:
1607 |
1608 | nullif|
1609 | ------|
1610 | jaime |
1611 |
1612 | However, if the arguments equal each other...
1613 |
1614 | ```sql
1615 | SELECT NULLIF('shaker', 'shaker');
1616 | ```
1617 |
1618 | **Results**: (Returns **NULL**)
1619 |
1620 | nullif|
1621 | ------|
1622 | |
1623 |
1624 | We can display how they can work together with a table that has both empty fields and NULL fields.
1625 |
1626 | ```sql
1627 | DROP TABLE IF EXISTS convert_nulls;
1628 |
1629 | CREATE TABLE convert_nulls (
1630 | user_name TEXT,
1631 | city TEXT,
1632 | state TEXT
1633 | );
1634 |
1635 |
1636 | INSERT INTO convert_nulls (user_name, city, state)
1637 | VALUES
1638 | ('jaime', 'orland park', 'IL'),
1639 | ('pat', '', 'IL'),
1640 | ('chris', NULL, 'IL');
1641 |
1642 | SELECT * FROM convert_nulls;
1643 | ```
1644 |
1645 | **Results**:
1646 |
1647 | user_name|city |state|
1648 | ---------|-----------|-----|
1649 | jaime |orland park|IL |
1650 | pat | |IL |
1651 | chris | |IL |
1652 |
1653 | Let's use the **NULLIF()** function to convert empty (' ') values to NULL and the **COALESCE()** function to convert NULLs to 'unknown'.
1654 |
1655 | ```sql
1656 | SELECT
1657 | user_name,
1658 | /*
1659 | 1. NULLIF converts all '' to null because they match.
1660 | 2. COALESCE returns the first non-null argument which in this case is 'unknown if the city value is null.
1661 | */
1662 | COALESCE(NULLIF(city, ''), 'unknown') AS city,
1663 | state
1664 | FROM
1665 | convert_nulls;
1666 | ```
1667 |
1668 | **Results**:
1669 |
1670 | user_name|city |state|
1671 | ---------|-----------|-----|
1672 | jaime |orland park|IL |
1673 | pat |unknown |IL |
1674 | chris |unknown |IL |
1675 |
1676 | Back To Questions
1677 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | ## Common SQL interview Questions and Answers
2 |
3 | **Author**: Jaime M. Shaker
4 | **Email**: jaime.m.shaker@gmail.com
5 | **Website**: https://www.shaker.dev
6 | **LinkedIn**: https://www.linkedin.com/in/jaime-shaker/
7 |
8 | :exclamation: If you find this repository helpful, please consider giving it a :star:. Thanks! :exclamation:
9 |
10 |
11 | ❗ **Note** ❗
12 |
13 | ### Introduction:
14 |
15 | This repository contains entry-level SQL interview questions that appear in many interview preperation resources found online.
16 |
17 | All solutions were coded using PostgreSQL.
18 |
19 | 1. How do you find duplicates in a table?
20 | 2. How do you delete multiple entries from a table?
21 | 3. What is the difference between union and union all?
22 | 4. What is the difference between rank,row_number and dense_rank?
23 | 5. Find records in a table which are not present in another table.
24 | 6. Find second highest salary employees in each department.
25 | 7. Find employees with greater salaries than their manager's salary.
26 | 8. What is the difference between an inner and left join?
27 | 9. Update a table and swap gender values.
28 | 10. Number of records in output with different kinds of join.
29 | 11. What is the difference between the DELETE, TRUNCATE and DROP statements?
30 | 12. What is the difference between the NOW() and CURRENT_DATE functions?
31 | 13. What is the difference between the ‘IN’ and ‘BETWEEN’ condition operators?
32 | 14. What is the difference between the WHERE and the HAVING clause?
33 | 15. From a table of names, write a query that only returns EVEN number rows.
34 | 16. How can we copy the contents of one table to a new table?
35 | 17. In string pattern matching, what is the difference between LIKE and ILIKE?
36 | 18. What are Aggregate and Scalar functions in an RDBMS and can you provide an example of their use?
37 | 19. How can you calculate the MEDIAN of a numerical field?
38 | 20. Display two different methods to concatnate strings in PostgreSQL.
39 | 21. How can we get the Year (month, day hour, etc...) from a timestamp?
40 | 22. Produce a query that only returns the top 50% of the records.
41 | 23. How can you insert a new row into a table OR update the row if it already exists?
42 | 24. What is the use of the COALESCE() function?
43 | 25. Is the COALESCE() function the same as the NULLIF() function?
44 |
--------------------------------------------------------------------------------
/docker-compose.yaml:
--------------------------------------------------------------------------------
1 | version: '3.8'
2 | services:
3 | postgres:
4 | image: postgres
5 | container_name: sql_interview_questions
6 | restart: unless-stopped
7 | #- .env
8 | environment:
9 | POSTGRES_DB: sql_interview_questions
10 | POSTGRES_USER: postgres
11 | POSTGRES_PASSWORD: postgres
12 | PGDATA: /var/lib/postgresql/data/pgdata
13 | ports:
14 | - "5432:5432"
15 | volumes:
16 | -
17 | type: bind
18 | source: ./db
19 | target: /var/lib/postgresql/data
20 | -
21 | type: bind
22 | source: ./source_data
23 | target: /var/lib/postgresql/source_data
24 | networks:
25 | - reference
26 | networks:
27 | reference:
--------------------------------------------------------------------------------
/source_data/cte_vs_subquery.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Differences between a Common Table Expression (CTE) and a subquery.
3 |
4 | ** What is a subquery?
5 |
6 | A subquery is a query that is define inside of another query.
7 | Let's create a table and give an example of a subquery.
8 |
9 | I am using postgres v13. Here is a db fiddle of the table.
10 |
11 | https://www.db-fiddle.com/f/hkgEEdGCJBbaEvZTGtzY1M/0
12 |
13 | */
14 |
15 | DROP TABLE IF EXISTS grapplers;
16 | CREATE TABLE grapplers (
17 | grappler_id int GENERATED ALWAYS AS IDENTITY,
18 | first_name varchar(100) UNIQUE NOT NULL,
19 | team varchar(100) NOT NULL,
20 | belt_rank varchar(20) NOT NULL,
21 | wins int NOT NULL,
22 | losses int NOT NULL,
23 | PRIMARY KEY (grappler_id)
24 | );
25 |
26 | INSERT INTO grapplers (
27 | first_name,
28 | team,
29 | belt_rank,
30 | wins,
31 | losses
32 | )
33 | VALUES
34 | ('chris', 'gracie barra', 'blue', 1, 3),
35 | ('rick', 'carlson gracie team', 'white', 4, 1),
36 | ('ronald', 'checkmat', 'brown', 5, 7),
37 | ('david', 'gracie barra', 'white', 3, 3),
38 | ('fred', 'checkmat', 'blue', 5, 2),
39 | ('abe', 'atos jiu-jitsu', 'blue', 10, 1),
40 | ('zach', 'atos jiu-jitsu', 'white', 0, 3),
41 | ('michael', 'checkmat', 'white', 6, 0),
42 | ('aldo', 'checkmat', 'purple', 2, 3),
43 | ('william', 'carlson gracie team', 'purple', 7, 3),
44 | ('john', 'gracie barra', 'blue', 4, 1),
45 | ('duane', 'carlson gracie team', 'blue', 1, 1),
46 | ('james', 'atos jiu-jitsu', 'purple', 5, 4),
47 | ('jaime', 'gracie barra', 'purple', 8, 2),
48 | ('samuel', 'carlson gracie team', 'brown', 9, 0),
49 | ('henry', 'atos jiu-jitsu', 'brown', 2, 5);
50 |
51 | -- Lets take a look at the table
52 |
53 | SELECT * FROM grapplers;
54 |
55 | grappler_id|first_name|team |belt_rank|wins|losses|
56 | -----------+----------+-------------------+---------+----+------+
57 | 1|chris |gracie barra |blue | 1| 3|
58 | 2|rick |carlson gracie team|white | 4| 1|
59 | 3|ronald |checkmat |brown | 5| 7|
60 | 4|david |gracie barra |white | 3| 3|
61 | 5|fred |checkmat |blue | 5| 2|
62 | 6|abe |atos jiu-jitsu |blue | 10| 1|
63 | 7|zach |atos jiu-jitsu |white | 0| 3|
64 | 8|michael |checkmat |white | 6| 0|
65 | 9|aldo |checkmat |purple | 2| 3|
66 | 10|william |carlson gracie team|purple | 7| 3|
67 | 11|john |gracie barra |blue | 4| 1|
68 | 12|duane |carlson gracie team|blue | 1| 1|
69 | 13|james |atos jiu-jitsu |purple | 5| 4|
70 | 14|jaime |gracie barra |purple | 8| 2|
71 | 15|samuel |carlson gracie team|brown | 9| 0|
72 | 16|henry |atos jiu-jitsu |brown | 2| 5|
73 |
74 |
75 | -- What is the AVG wins per team?
76 |
77 | SELECT
78 | team AS BJJ_Team,
79 | round(avg(wins), 2) AS avg_team_wins
80 | FROM
81 | grapplers
82 | GROUP BY -- AGGREGATE FUNCTIONS (AVG, SUM, COUNT...) require TO GROUP BY field names.
83 | team
84 | ORDER BY
85 | avg_team_wins DESC;
86 |
87 | bjj_team |avg_team_wins|
88 | -------------------+-------------+
89 | carlson gracie team| 5.25|
90 | checkmat | 4.50|
91 | atos jiu-jitsu | 4.25|
92 | gracie barra | 4.00|
93 |
94 | -- What if I only want to see teams where the avg_team_wins is >= 4.5?
95 |
96 | SELECT
97 | team AS BJJ_Team,
98 | round(avg(wins), 2) AS avg_team_wins
99 | FROM
100 | grapplers
101 | WHERE
102 | round(avg(wins), 2) > 4.5
103 | GROUP BY
104 | team
105 | ORDER BY
106 | avg_team_wins DESC;
107 |
108 | -- This will result in an error because aggregate functions are not allowed in a where clause.
109 |
110 | SQL Error [42803]: ERROR: aggregate functions are not allowed in WHERE
111 |
112 | -- We can add a HAVING clause because aggregate functions are allowed in it.
113 |
114 | SELECT
115 | team AS BJJ_Team,
116 | round(avg(wins), 2) AS avg_team_wins
117 | FROM
118 | grapplers
119 | GROUP BY
120 | team
121 | HAVING
122 | round(avg(wins), 2) >= 4.5
123 | ORDER BY
124 | avg_team_wins DESC;
125 |
126 |
127 | bjj_team |avg_team_wins|
128 | -------------------+-------------+
129 | carlson gracie team| 5.25|
130 | checkmat | 4.50|
131 |
132 | /*
133 | What is the difference between the WHERE and the HAVING clause?
134 | Both of these clauses are used for filtering results, but this question is easier to understand if you understand that
135 | there is a difference between 'The order of execution' and 'The order of writing' an SQL query.
136 |
137 | The order of execution is as follows:
138 |
139 | 1. FROM/JOIN
140 | 2. WHERE
141 | 3. GROUP BY
142 | 4. HAVING
143 | 5. SELECT
144 | 6. Distinct
145 | 7. ORDER BY
146 | 8. LIMIT / OFFSET
147 |
148 | **WHERE** is used to filter individual rows BEFORE groupings are made. Which is why aggregate functions CANNOT be used in a where clause
149 | because the GROUP does NOT exist when the WHERE clause if filtering.
150 |
151 | **HAVING** is used for filtering values from a GROUP which would allow you to use aggregate functions within its conditions.
152 | */
153 |
154 | -- Let's use a subquery to get the same results.
155 |
156 | SELECT
157 | BJJ_Team,
158 | avg_team_wins
159 | FROM
160 | (SELECT
161 | team AS BJJ_Team,
162 | round(avg(wins), 2) AS avg_team_wins
163 | FROM
164 | grapplers
165 | GROUP BY
166 | team) AS inner_query
167 | WHERE
168 | avg_team_wins >= 4.5;
169 |
170 | bjj_team |avg_team_wins|
171 | -------------------+-------------+
172 | carlson gracie team| 5.25|
173 | checkmat | 4.50|
174 |
175 | -- The inner_query did the aggregation and the outer query allows us to filter it.
176 | -- Let's use a CTE to get the same results.
177 |
178 | -- A CTE will allow us to move the inner_query and define it seperately.
179 | -- This makes the query easier to read and it's less of a performance hit on the server.
180 | -- With a small query, probably not a big deal. But this allows you simplify code.
181 |
182 | WITH cte_get_avg_wins AS (
183 | SELECT
184 | team AS BJJ_Team,
185 | round(avg(wins), 2) AS avg_team_wins
186 | FROM
187 | grapplers
188 | GROUP BY
189 | team
190 | )
191 | SELECT
192 | BJJ_Team,
193 | avg_team_wins
194 | FROM
195 | cte_get_avg_wins
196 | WHERE
197 | avg_team_wins >= 4.5;
198 |
199 | bjj_team |avg_team_wins|
200 | -------------------+-------------+
201 | carlson gracie team| 5.25|
202 | checkmat | 4.50|
203 |
204 | -- Let's say we wanted to rank grapplers by their belt rank. We can use the rank() or dense_rank()
205 | -- window function.
206 |
207 | SELECT
208 | first_name,
209 | team AS BJJ_Team,
210 | belt_rank,
211 | wins,
212 | DENSE_RANK() OVER (PARTITION BY belt_rank ORDER BY wins DESC) AS belt_rankings
213 | FROM
214 | grapplers;
215 |
216 | first_name|bjj_team |belt_rank|wins|belt_rankings|
217 | ----------+-------------------+---------+----+-------------+
218 | abe |atos jiu-jitsu |blue | 10| 1|
219 | fred |checkmat |blue | 5| 2|
220 | john |gracie barra |blue | 4| 3|
221 | chris |gracie barra |blue | 1| 4|
222 | duane |carlson gracie team|blue | 1| 4|
223 | samuel |carlson gracie team|brown | 9| 1|
224 | ronald |checkmat |brown | 5| 2|
225 | henry |atos jiu-jitsu |brown | 2| 3|
226 | jaime |gracie barra |purple | 8| 1|
227 | william |carlson gracie team|purple | 7| 2|
228 | james |atos jiu-jitsu |purple | 5| 3|
229 | aldo |checkmat |purple | 2| 4|
230 | michael |checkmat |white | 6| 1|
231 | rick |carlson gracie team|white | 4| 2|
232 | david |gracie barra |white | 3| 3|
233 | zach |atos jiu-jitsu |white | 0| 4|
234 |
235 | -- What if we only wanted the #2 ranked grappler?
236 |
237 | SELECT
238 | first_name,
239 | team AS BJJ_Team,
240 | belt_rank,
241 | wins,
242 | DENSE_RANK() OVER (PARTITION BY belt_rank ORDER BY wins DESC) AS belt_rankings
243 | FROM
244 | grapplers
245 | WHERE
246 | belt_rankings = 2;
247 |
248 | -- This will cause an error because the belt_rankings column does not exist (yet)
249 | -- when the WHERE clause is executed.
250 |
251 | SQL Error [42703]: ERROR: column "belt_rankings" does not exist
252 |
253 | -- Let's use a CTE
254 |
255 | WITH cte_get_belt_rankings AS (
256 | SELECT
257 | first_name,
258 | team AS BJJ_Team,
259 | belt_rank,
260 | wins,
261 | DENSE_RANK() OVER (PARTITION BY belt_rank ORDER BY wins DESC) AS belt_rankings
262 | FROM
263 | grapplers
264 | )
265 | SELECT
266 | first_name,
267 | BJJ_Team,
268 | belt_rank,
269 | belt_rankings
270 | FROM
271 | cte_get_belt_rankings
272 | WHERE
273 | belt_rankings = 2;
274 |
275 | first_name|bjj_team |belt_rank|belt_rankings|
276 | ----------+-------------------+---------+-------------+
277 | fred |checkmat |blue | 2|
278 | ronald |checkmat |brown | 2|
279 | william |carlson gracie team|purple | 2|
280 | rick |carlson gracie team|white | 2|
281 |
282 |
283 |
284 |
285 |
286 |
287 |
288 |
289 |
290 |
291 |
292 |
--------------------------------------------------------------------------------
/source_data/monthly_report.sql:
--------------------------------------------------------------------------------
1 | /*
2 | Simple Monthly Reports
3 | Author: Jaime M. Shaker
4 | Email: jaime.m.shaker@gmail.com or jaime@shaker.dev
5 | Website: https://www.shaker.dev
6 | LinkedIn: https://www.linkedin.com/in/jaime-shaker/
7 |
8 | File Name: monthly_reports.sql
9 | Description: A simple script to display the flexability of SQL/PL functions.
10 |
11 | */
12 |
13 | -- Create a table that contains of the monthly sales
14 | DROP TABLE IF EXISTS monthly_sales;
15 | CREATE TABLE monthly_sales (
16 | sales_id int GENERATED ALWAYS AS IDENTITY,
17 | product_name varchar(20),
18 | price int,
19 | transaction_time timestamp
20 | );
21 | -- Insert monthly sales data
22 | INSERT INTO monthly_sales (
23 | product_name,
24 | price,
25 | transaction_time
26 | )
27 | VALUES
28 | ('shirt', 10, '2021-01-14 06:59:43.206'),
29 | ('pants', 20, '2021-01-20 11:50:22.301'),
30 | ('shirt', 10, '2021-01-05 08:05:10.428'),
31 | ('dress', 30, '2021-02-14 09:39:56.195'),
32 | ('pants', 20, '2021-02-22 07:00:19.667'),
33 | ('dress', 30, '2021-03-13 11:56:23.786'),
34 | ('hat', 15, '2021-03-20 04:36:54.123');
35 |
36 | -- Test the new table
37 | SELECT
38 | *
39 | FROM
40 | monthly_sales;
41 | -- Results
42 | /*
43 | sales_id|product_name|price|transaction_time |
44 | --------+------------+-----+-----------------------+
45 | 1|shirt | 10|2021-01-14 06:59:43.206|
46 | 2|pants | 20|2021-01-20 11:50:22.301|
47 | 3|shirt | 10|2021-01-05 08:05:10.428|
48 | 4|dress | 30|2021-02-14 09:39:56.195|
49 | 5|pants | 20|2021-02-22 07:00:19.667|
50 | 6|dress | 30|2021-03-13 11:56:23.786|
51 | 7|hat | 15|2021-03-20 04:36:54.123|
52 | */
53 |
54 | -- Select data given a specific month. Using the months number (Jan=1, Feb=2, Mar=3...)
55 | SELECT
56 | *
57 | FROM
58 | monthly_sales
59 | WHERE
60 | EXTRACT('month' FROM transaction_time) = 1;
61 |
62 | -- Results
63 | /*
64 | sales_id|product_name|price|transaction_time |
65 | --------+------------+-----+-----------------------+
66 | 1|shirt | 10|2021-01-14 06:59:43.206|
67 | 2|pants | 20|2021-01-20 11:50:22.301|
68 | 3|shirt | 10|2021-01-05 08:05:10.428|
69 | */
70 |
71 | -- Create a function that returns a table with data
72 | -- from a parameter.
73 |
74 | DROP FUNCTION get_monthly_sales;
75 | CREATE OR REPLACE FUNCTION get_monthly_sales (
76 | -- This is the months number
77 | numerical_month int
78 | )
79 | -- These are the values returned by our query
80 | RETURNS TABLE (
81 | transaction_month TEXT,
82 | number_of_transactions int,
83 | total_sales int
84 | )
85 | -- Specify language used.
86 | LANGUAGE plpgsql
87 | AS
88 | $$
89 | DECLARE
90 | -- Declare a variable that we pass the parameter value to
91 | num_month int := numerical_month;
92 | BEGIN
93 | RETURN query
94 | -- Start the actual query
95 | SELECT
96 | -- Convert the int into text and pass it to_date(), then pass it
97 | -- to to_char() to get the actual month name.
98 | to_char(to_date(num_month::TEXT, 'MM'), 'Month'),
99 | -- The number of transactions
100 | count(*)::int,
101 | -- The total from all sales
102 | sum(price)::int
103 | FROM
104 | -- Our newly created table above
105 | monthly_sales
106 | WHERE
107 | -- Extract the month from the timestamp and compare it
108 | -- to our parameter value.
109 | EXTRACT('month' FROM transaction_time) = num_month;
110 | END;
111 | $$
112 |
113 | -- Pass the numerical Month value to get only that months results.
114 | SELECT
115 | transaction_month,
116 | number_of_transactions,
117 | total_sales
118 | FROM get_monthly_sales(1);
119 |
120 | /*
121 |
122 | transaction_month|number_of_transactions|total_sales|
123 | -----------------+----------------------+-----------+
124 | January | 3| 40|
125 |
126 | */
127 |
128 | SELECT
129 | transaction_month,
130 | number_of_transactions,
131 | total_sales
132 | FROM get_monthly_sales(2);
133 |
134 | /*
135 |
136 | transaction_month|number_of_transactions|total_sales|
137 | -----------------+----------------------+-----------+
138 | February | 2| 50|
139 |
140 | */
141 |
142 | SELECT
143 | transaction_month,
144 | number_of_transactions,
145 | total_sales
146 | FROM get_monthly_sales(3);
147 |
148 | /*
149 |
150 | transaction_month|number_of_transactions|total_sales|
151 | -----------------+----------------------+-----------+
152 | March | 2| 45|
153 |
154 | */
155 |
156 |
157 | -- I hope that helps!
158 |
159 |
160 |
161 |
162 |
163 |
--------------------------------------------------------------------------------
/source_data/sql_query.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/iweld/sql_interview_questions/6f4e3192b09b4ed64201a8bd4f76a292f1891431/source_data/sql_query.sql
--------------------------------------------------------------------------------
/source_data/sql_sales_project/build_table.sql:
--------------------------------------------------------------------------------
1 |
2 | CREATE SCHEMA IF NOT EXISTS sales_project;
3 |
4 | DROP TABLE IF EXISTS sales_project.sales_data;
5 | CREATE TABLE sales_project.sales_data (
6 | ORDERNUMBER int,
7 | QUANTITYORDERED int,
8 | PRICEEACH numeric,
9 | ORDERLINENUMBER int,
10 | SALES numeric,
11 | ORDERDATE TEXT,
12 | STATUS text,
13 | QTR_ID int,
14 | MONTH_ID int,
15 | YEAR_ID int,
16 | PRODUCTLINE text,
17 | MSRP int,
18 | PRODUCTCODE text,
19 | CUSTOMERNAME text,
20 | PHONE text,
21 | ADDRESSLINE1 text,
22 | ADDRESSLINE2 text,
23 | CITY text,
24 | STATE text,
25 | POSTALCODE text,
26 | COUNTRY text,
27 | TERRITORY text,
28 | CONTACTLASTNAME text,
29 | CONTACTFIRSTNAME text,
30 | DEALSIZE text
31 | );
32 |
33 | COPY sales_project.sales_data (
34 | ORDERNUMBER,
35 | QUANTITYORDERED,
36 | PRICEEACH,
37 | ORDERLINENUMBER,
38 | SALES,
39 | ORDERDATE,
40 | STATUS,
41 | QTR_ID,
42 | MONTH_ID,
43 | YEAR_ID,
44 | PRODUCTLINE,
45 | MSRP,
46 | PRODUCTCODE,
47 | CUSTOMERNAME,
48 | PHONE,
49 | ADDRESSLINE1,
50 | ADDRESSLINE2,
51 | CITY,
52 | STATE,
53 | POSTALCODE,
54 | COUNTRY,
55 | TERRITORY,
56 | CONTACTLASTNAME,
57 | CONTACTFIRSTNAME,
58 | DEALSIZE
59 | )
60 | FROM '/var/lib/postgresql/source_data/sql_sales_project/sales_data.csv'
61 | WITH DELIMITER ',' HEADER CSV;
62 |
63 | -- Let's fix the date to the proper date format
64 | UPDATE sales_project.sales_data
65 | SET orderdate = split_part(orderdate, ' ', 1);
66 |
67 |
68 | UPDATE sales_project.sales_data
69 | SET orderdate = split_part(orderdate, '/', 3) || '-' || split_part(orderdate, '/', 1) || '-' || split_part(orderdate, '/', 2);
70 |
71 | -- Change the column to the proper data type
72 |
73 | ALTER TABLE sales_project.sales_data
74 | ALTER COLUMN orderdate TYPE date
75 | USING orderdate::date;
76 |
77 | SELECT *
78 | FROM
79 | sales_project.sales_data
80 | LIMIT 5;
81 |
82 | /*
83 |
84 | ordernumber|quantityordered|priceeach|orderlinenumber|sales |orderdate |status |qtr_id|month_id|year_id|productline|msrp |productcode|customername |phone |addressline1 |addressline2|city |state |postalcode|country|territory|contactlastname|contactfirstname|dealsize|
85 | -----------+---------------+---------+---------------+-------+----------+-------+------+--------+-------+-----------+------+-----------+------------------+----------+-----------------------+------------+--------+------+----------+-------+---------+---------------+----------------+--------+
86 | 10146| 47| 67.14| 2|3155.58|2003-09-03|Shipped| 3| 9| 2003|Motorcycles| 62|S18_3782 |Gift Ideas Corp. |2035554407|2440 Pompton St. |[NULL] |Glendale|CT |97561 |USA |NA |Lewis |Dan |Medium |
87 | 10237| 27| 100| 5|3113.64|2004-04-05|Shipped| 2| 4| 2004|Motorcycles| 102|S32_4485 |Vitachrome Inc. |2125551500|2678 Kingston Rd. |Suite 101 |NYC |NY |10022 |USA |NA |Frick |Michael |Medium |
88 | 10414| 27| 90.37| 8|2439.99|2005-05-06|On Hold| 2| 5| 2005|Ships | 99|S700_3962 |Gifts4AllAges.com |6175559555|8616 Spinnaker Dr. |[NULL] |Boston |MA |51003 |USA |NA |Yoshido |Juri |Small |
89 | 10107| 30| 95.7| 2| 2871|2003-02-24|Shipped| 1| 2| 2003|Motorcycles| 95|S10_1678 |Land of Toys Inc. |2125557818|897 Long Airport Avenue|[NULL] |NYC |NY |10022 |USA |NA |Yu |Kwai |Small |
90 | 10121| 34| 81.35| 5| 2765.9|2003-05-07|Shipped| 2| 5| 2003|Motorcycles| 95|S10_1678 |Reims Collectables|26.47.1555|59 rue de l'Abbaye |[NULL] |Reims |[NULL]|51100 |France |EMEA |Henriot |Paul |Small |
91 |
92 | */
93 |
94 |
95 |
96 |
97 |
98 |
99 |
100 |
101 |
102 |
103 |
104 |
105 |
106 |
107 |
108 |
109 |
110 |
111 |
112 |
113 |
114 |
--------------------------------------------------------------------------------
/source_data/sql_sales_project/sales_project.md:
--------------------------------------------------------------------------------
1 | This file is written in the markdown language. Markdown is similar to HTML, but a little easier in my opinion. You can learn more about markdown at this link
2 |
3 | https://www.markdowntutorial.com/
4 |
5 | https://www.markdownguide.org/
6 |
7 | However, if you follow along with my source code, if should not be too difficult to comprehend.
8 |
9 | I am using PostgreSQL within a docker container to run the .sql scripts. You can follow this walkthrough and it will guide you on how to create a PostgreSQL container within Docker. Very useful information and not difficult.
10 |
11 | https://github.com/iweld/SQL_Coding_Challenge/blob/main/walkthrough/WALKTHROUGH_1_DOCKER.md
12 |
13 | I use DBeaver to access the PostgreSQL server and run my queries.
14 |
15 | https://dbeaver.io/
16 |
17 | It is **FREE** and can be used with MANY different types of Databases. Using DBeaver, I can have the query output display as text
18 |
19 | ```sql
20 | country_count|
21 | -------------+
22 | 19|
23 | ```
24 |
25 | Using Markdown, I can convert it into tabular format
26 |
27 | country_count|
28 | -------------|
29 | 19|
30 |
31 | To write the markdown source code, I use VSCode. It is also free and one of the most dominant IDE's out there.
32 |
33 | https://code.visualstudio.com/
34 |
35 | I also use a VSCode Markdown extension called "Markdown Preview Enhanced" which allows me to see the rendered markdown in real time.
36 |
37 | 
38 |
39 | So I will normally have a my_queries.sql file to show the actual queries and I will have a separate my_queries.md file to display the page in a cleaner format.
40 |
41 | When you want to show actual code in mark down, you have to enclose your code like so...
42 |
43 | ````markdown
44 | ```sql
45 | select *
46 | from some_table;
47 | ```
48 | ````
49 |
50 | This will allow your SQL code (or any code for that matter) to render with syntax highlighting like so...
51 |
52 | ```sql
53 | select *
54 | from some_table;
55 | ```
56 |
57 | I will use the first couple of queries from the sql file to give an example.
58 |
59 | **1.** Show a sample of the data.
60 |
61 | ```sql
62 | SELECT *
63 | FROM
64 | sales_project.sales_data
65 | LIMIT 5;
66 | ```
67 |
68 | ordernumber|quantityordered|priceeach|orderlinenumber|sales |orderdate |status |qtr_id|month_id|year_id|productline|msrp |productcode|customername |phone |addressline1 |addressline2|city |state |postalcode|country|territory|contactlastname|contactfirstname|dealsize|
69 | -----------|---------------|---------|---------------|-------|----------|-------|------|--------|-------|-----------|------|-----------|------------------|----------|-----------------------|------------|--------|------|----------|-------|---------|---------------|----------------|--------|
70 | 10146| 47| 67.14| 2|3155.58|2003-09-03|Shipped| 3| 9| 2003|Motorcycles| 62|S18_3782 |Gift Ideas Corp. |2035554407|2440 Pompton St. |[NULL] |Glendale|CT |97561 |USA |NA |Lewis |Dan |Medium |
71 | 10237| 27| 100| 5|3113.64|2004-04-05|Shipped| 2| 4| 2004|Motorcycles| 102|S32_4485 |Vitachrome Inc. |2125551500|2678 Kingston Rd. |Suite 101 |NYC |NY |10022 |USA |NA |Frick |Michael |Medium |
72 | 10414| 27| 90.37| 8|2439.99|2005-05-06|On Hold| 2| 5| 2005|Ships | 99|S700_3962 |Gifts4AllAges.com |6175559555|8616 Spinnaker Dr. |[NULL] |Boston |MA |51003 |USA |NA |Yoshido |Juri |Small |
73 | 10107| 30| 95.7| 2| 2871|2003-02-24|Shipped| 1| 2| 2003|Motorcycles| 95|S10_1678 |Land of Toys Inc. |2125557818|897 Long Airport Avenue|[NULL] |NYC |NY |10022 |USA |NA |Yu |Kwai |Small |
74 | 10121| 34| 81.35| 5| 2765.9|2003-05-07|Shipped| 2| 5| 2003|Motorcycles| 95|S10_1678 |Reims Collectables|26.47.1555|59 rue de l'Abbaye |[NULL] |Reims |[NULL]|51100 |France |EMEA |Henriot |Paul |Small |
75 |
76 | **2.** NUMBER OF COUNTRIES IN WHICH WERE TAKING PLACE
77 |
78 | ```sql
79 | SELECT
80 | COUNT(DISTINCT(COUNTRY)) AS country_count
81 | FROM
82 | sales_project.sales_data;
83 | ```
84 |
85 | country_count|
86 | -------------|
87 | 19|
88 |
89 | **3.** DIFFERENT TYPES OF ORDER STATUSES AND THEIR COUNT
90 |
91 | ```sql
92 | SELECT DISTINCT
93 | STATUS AS types_of_statuses,
94 | count(*) AS status_count
95 | FROM
96 | sales_project.sales_data
97 | GROUP BY
98 | status;
99 | ```
100 |
101 | types_of_statuses|status_count|
102 | -----------------|------------|
103 | Cancelled | 60|
104 | Disputed | 14|
105 | In Process | 41|
106 | On Hold | 44|
107 | Resolved | 47|
108 | Shipped | 2617|
109 |
110 | As you can see, I have to copy the SQL code **AND** results and paste it onto the markdown file. This is some extra work, but I think it looks WAY better and it's a great way to showcase your technical abilities.
--------------------------------------------------------------------------------
/source_data/sql_sales_project/sales_project.sql:
--------------------------------------------------------------------------------
1 | -- Show a Sample of the data.
2 |
3 | SELECT *
4 | FROM
5 | sales_project.sales_data
6 | LIMIT 5;
7 |
8 | /*
9 |
10 | ordernumber|quantityordered|priceeach|orderlinenumber|sales |orderdate |status |qtr_id|month_id|year_id|productline|msrp |productcode|customername |phone |addressline1 |addressline2|city |state |postalcode|country|territory|contactlastname|contactfirstname|dealsize|
11 | -----------+---------------+---------+---------------+-------+----------+-------+------+--------+-------+-----------+------+-----------+------------------+----------+-----------------------+------------+--------+------+----------+-------+---------+---------------+----------------+--------+
12 | 10146| 47| 67.14| 2|3155.58|2003-09-03|Shipped| 3| 9| 2003|Motorcycles| 62|S18_3782 |Gift Ideas Corp. |2035554407|2440 Pompton St. |[NULL] |Glendale|CT |97561 |USA |NA |Lewis |Dan |Medium |
13 | 10237| 27| 100| 5|3113.64|2004-04-05|Shipped| 2| 4| 2004|Motorcycles| 102|S32_4485 |Vitachrome Inc. |2125551500|2678 Kingston Rd. |Suite 101 |NYC |NY |10022 |USA |NA |Frick |Michael |Medium |
14 | 10414| 27| 90.37| 8|2439.99|2005-05-06|On Hold| 2| 5| 2005|Ships | 99|S700_3962 |Gifts4AllAges.com |6175559555|8616 Spinnaker Dr. |[NULL] |Boston |MA |51003 |USA |NA |Yoshido |Juri |Small |
15 | 10107| 30| 95.7| 2| 2871|2003-02-24|Shipped| 1| 2| 2003|Motorcycles| 95|S10_1678 |Land of Toys Inc. |2125557818|897 Long Airport Avenue|[NULL] |NYC |NY |10022 |USA |NA |Yu |Kwai |Small |
16 | 10121| 34| 81.35| 5| 2765.9|2003-05-07|Shipped| 2| 5| 2003|Motorcycles| 95|S10_1678 |Reims Collectables|26.47.1555|59 rue de l'Abbaye |[NULL] |Reims |[NULL]|51100 |France |EMEA |Henriot |Paul |Small |
17 |
18 | */
19 |
20 | --NUMBER OF COUNTRIES IN WHICH WERE TAKING PLACE
21 | SELECT
22 | COUNT(DISTINCT(COUNTRY)) AS country_count
23 | FROM
24 | sales_project.sales_data;
25 |
26 | /*
27 |
28 | country_count|
29 | -------------+
30 | 19|
31 |
32 | */
33 | --IT WAS FOUND OUT THAT THE COMPANY IS SENDING ORDER IN 19 DIFFERENT COUNTRIES
34 |
35 |
36 | --DIFFERENT TYPES OF ORDER STATUSES AND THEIR COUNT
37 | SELECT DISTINCT
38 | STATUS AS types_of_statuses,
39 | count(*) AS status_count
40 | FROM
41 | sales_project.sales_data
42 | GROUP BY
43 | status;
44 |
45 | /*
46 |
47 | types_of_statuses|status_count|
48 | -----------------+------------+
49 | Cancelled | 60|
50 | Disputed | 14|
51 | In Process | 41|
52 | On Hold | 44|
53 | Resolved | 47|
54 | Shipped | 2617|
55 |
56 | */
57 |
58 |
59 | --DIFFERENT TYPES OF PRODUCTS
60 | SELECT DISTINCT
61 | PRODUCTLINE,
62 | count(*) AS product_count
63 | FROM
64 | sales_project.sales_data
65 | GROUP BY
66 | productline;
67 |
68 | /*
69 |
70 | productline |product_count|
71 | ----------------+-------------+
72 | Classic Cars | 967|
73 | Motorcycles | 331|
74 | Planes | 306|
75 | Ships | 234|
76 | Trains | 77|
77 | Trucks and Buses| 301|
78 | Vintage Cars | 607|
79 |
80 | */
81 |
82 |
83 | --NUMBER OF DISTINCT CUSTOMERS
84 | SELECT
85 | count(DISTINCT CUSTOMERNAME) AS number_of_customers
86 | FROM
87 | sales_project.sales_data;
88 |
89 | /*
90 |
91 | number_of_customers|
92 | -------------------+
93 | 92|
94 |
95 | */
96 |
97 |
98 | --DATA EXPLORATORY ANALYSIS
99 |
100 | --1. FINDING OUT THE PRODUCT OF HIGHEST SALES
101 |
102 | SELECT
103 | PRODUCTLINE,
104 | SUM(SALES) AS TOTAL_SALES
105 | FROM
106 | sales_project.sales_data
107 | GROUP BY
108 | PRODUCTLINE
109 | ORDER BY
110 | total_sales DESC;
111 |
112 | /*
113 |
114 | productline |total_sales|
115 | ----------------+-----------+
116 | Classic Cars | 3919615.66|
117 | Vintage Cars | 1903150.84|
118 | Motorcycles | 1166388.34|
119 | Trucks and Buses| 1127789.84|
120 | Planes | 975003.57|
121 | Ships | 714437.13|
122 | Trains | 226243.47|
123 |
124 | */
125 |
126 | --It was found out that Classical Cars has the most highest sales and Trains have the lowest sales.
127 |
128 | --2. FINDING OUT THE BEST YEAR OF SALES
129 |
130 | SELECT
131 | YEAR_ID,
132 | SUM(SALES) AS REVENUE
133 | FROM
134 | sales_project.sales_data
135 | GROUP BY
136 | YEAR_ID
137 | ORDER BY
138 | REVENUE DESC;
139 |
140 | /*
141 |
142 | year_id|revenue |
143 | -------+----------+
144 | 2004|4724162.60|
145 | 2003|3516979.54|
146 | 2005|1791486.71|
147 |
148 | */
149 |
150 | --It was found out that year 2004 has the highest sales and 2005 has the lowest sales.
151 |
152 | --3. FURTHER ANALYSIS WAS DONE IN ORDER TO FIND OUT WHY 2005 HAVE LEAST SALES
153 |
154 | SELECT
155 | year_id,
156 | count(DISTINCT MONTH_ID) AS total_months_recorded
157 | FROM
158 | sales_project.sales_data
159 | GROUP BY
160 | year_id;
161 |
162 | /*
163 |
164 | year_id|total_month|
165 | -------+-----------+
166 | 2003| 12|
167 | 2004| 12|
168 | 2005| 5|
169 |
170 | */
171 |
172 | --IT WAS FOUND OUT THAT 2005 HAD THE LEAST SALES BECAUSE SALES TOOK PLACE FOR ONLY 5 MONTHS
173 |
174 | --4. WHICH MONTH HAS THE BEST SALES
175 |
176 | WITH get_ranks AS (
177 | SELECT
178 | year_id,
179 | MONTH_ID,
180 | SUM(SALES) AS REVENUE,
181 | COUNT(ORDERLINENUMBER) AS FREQUENCY,
182 | DENSE_RANK() OVER (
183 | PARTITION BY year_id
184 | ORDER BY sum(sales) DESC
185 | ) AS rankings
186 | FROM
187 | sales_project.sales_data
188 | GROUP BY
189 | year_id,
190 | MONTH_ID
191 | )
192 | SELECT
193 | year_id,
194 | month_id,
195 | revenue,
196 | frequency
197 | FROM
198 | get_ranks
199 | WHERE
200 | rankings = 1;
201 |
202 |
203 | /*
204 |
205 | year_id|month_id|revenue |frequency|
206 | -------+--------+----------+---------+
207 | 2003| 11|1029837.66| 296|
208 | 2004| 11|1089048.01| 301|
209 | 2005| 5| 457861.06| 120|
210 |
211 | */
212 |
213 | --It was found out that the year 2004 and 2003 have their highest sales in the month of November, while in the year 2005 highest sales took place in month of May
214 |
215 | --5. WHICH TOP 3 COUNTRIES HAD THE MOST SALES
216 |
217 | SELECT DISTINCT
218 | COUNTRY,
219 | SUM(SALES) AS REVENUE
220 | FROM
221 | sales_project.sales_data
222 | GROUP BY
223 | COUNTRY
224 | ORDER BY
225 | REVENUE DESC
226 | LIMIT 3;
227 |
228 | /*
229 |
230 | country|revenue |
231 | -------+----------+
232 | USA |3627982.83|
233 | Spain |1215686.92|
234 | France |1110916.52|
235 |
236 | */
237 |
238 | --It was found out that USA, SPAIN and FRANCE had the most sales.
239 |
240 | --6. WHO IS THE BEST CUSTOMER
241 |
242 | SELECT
243 | CUSTOMERNAME,
244 | SUM(QUANTITYORDERED) AS total_ordered
245 | FROM
246 | sales_project.sales_data
247 | GROUP BY
248 | CUSTOMERNAME
249 | ORDER BY
250 | total_ordered DESC
251 | LIMIT 1;
252 |
253 | /*
254 |
255 | customername |total_ordered|
256 | ---------------------+-------------+
257 | Euro Shopping Channel| 9327|
258 |
259 | */
260 |
261 | --It was found out that Euro Shopping Channel is the best customer.
262 |
263 | --7. FURTHER ANALYSIS WAS DONE TO FIND OUT THE STATUS OF THE CUSTOMERS
264 |
265 | /**************************************************
266 | *
267 | * Please note that this query is not correct. You are trying to
268 | * get an average AFTER aggregation and its giving incorrect results.
269 | * I added an avg_quatity_ordered to show how the value is contantly
270 | * changing.
271 | *
272 | */
273 | SELECT
274 | CUSTOMERNAME,
275 | round(AVG(QUANTITYORDERED), 2) AS avg_quantity_ordered,
276 | COUNT(QUANTITYORDERED) AS number_of_orders,
277 | CASE
278 | WHEN count(QUANTITYORDERED) >= AVG(QUANTITYORDERED) THEN 'Frequent Customer'
279 | ELSE 'Infrequent Customer'
280 | END CUSTOMER_STATUS
281 | FROM
282 | sales_project.sales_data
283 | GROUP BY
284 | CUSTOMERNAME
285 | ORDER BY
286 | number_of_orders DESC;
287 |
288 | /*
289 |
290 | customername |avg_quantity_ordered|number_of_orders|customer_status |
291 | ----------------------------------+--------------------+----------------+-------------------+
292 | Euro Shopping Channel | 36.01| 259|Frequent Customer |
293 | Mini Gifts Distributors Ltd. | 35.37| 180|Frequent Customer |
294 | Australian Collectors, Co. | 35.02| 55|Frequent Customer |
295 | La Rochelle Gifts | 34.57| 53|Frequent Customer |
296 | AV Stores, Co. | 34.86| 51|Frequent Customer |
297 | Land of Toys Inc. | 33.29| 49|Frequent Customer |
298 | Rovelli Gifts | 34.38| 48|Frequent Customer |
299 | Muscle Machine Inc | 36.98| 48|Frequent Customer |
300 | Souveniers And Things Co. | 34.80| 46|Frequent Customer |
301 | Anna's Decorations, Ltd | 31.93| 46|Frequent Customer |
302 | Dragon Souveniers, Ltd. | 35.44| 43|Frequent Customer |
303 | Reims Collectables | 34.95| 41|Frequent Customer |
304 | Corporate Gift Ideas Co. | 35.29| 41|Frequent Customer |
305 | Saveley & Henriot, Co. | 34.83| 41|Frequent Customer |
306 | Salzburg Collectables | 36.05| 40|Frequent Customer |
307 | The Sharp Gifts Warehouse | 41.40| 40|Infrequent Customer|
308 | L'ordine Souveniers | 32.82| 39|Frequent Customer |
309 | Scandinavian Gift Ideas | 35.76| 38|Frequent Customer |
310 | Handji Gifts& Co | 34.33| 36|Frequent Customer |
311 | Danish Wholesale Imports | 36.53| 36|Infrequent Customer|
312 | Mini Creations Ltd. | 32.57| 35|Frequent Customer |
313 | Technics Stores Inc. | 34.68| 34|Infrequent Customer|
314 | Online Diecast Creations Co. | 36.71| 34|Infrequent Customer|
315 | Baane Mini Imports | 33.81| 32|Infrequent Customer|
316 | Oulu Toy Supplies, Inc. | 34.69| 32|Infrequent Customer|
317 | Corrida Auto Replicas, Ltd | 36.34| 32|Infrequent Customer|
318 | Tokyo Collectables, Ltd | 35.94| 32|Infrequent Customer|
319 | Vida Sport, Ltd | 34.77| 31|Infrequent Customer|
320 | Diecast Classics Inc. | 35.84| 31|Infrequent Customer|
321 | Suominen Souveniers | 34.37| 30|Infrequent Customer|
322 | Toys4GrownUps.com | 35.33| 30|Infrequent Customer|
323 | Toys of Finland, Co. | 35.03| 30|Infrequent Customer|
324 | Herkku Gifts | 33.55| 29|Infrequent Customer|
325 | Signal Gift Stores | 32.03| 29|Infrequent Customer|
326 | UK Collectables, Ltd. | 36.07| 29|Infrequent Customer|
327 | Auto Canal Petit | 37.07| 27|Infrequent Customer|
328 | Heintze Collectables | 32.67| 27|Infrequent Customer|
329 | Marta's Replicas Co. | 36.15| 27|Infrequent Customer|
330 | FunGiftIdeas.com | 34.73| 26|Infrequent Customer|
331 | Mini Classics | 35.73| 26|Infrequent Customer|
332 | Gifts4AllAges.com | 35.88| 26|Infrequent Customer|
333 | Cruz & Sons Co. | 36.96| 26|Infrequent Customer|
334 | Stylish Desk Decors, Co. | 36.04| 26|Infrequent Customer|
335 | Toms Spezialitten, Ltd | 36.00| 26|Infrequent Customer|
336 | giftsbymail.co.uk | 34.42| 26|Infrequent Customer|
337 | Amica Models & Co. | 32.42| 26|Infrequent Customer|
338 | Royal Canadian Collectables, Ltd. | 33.58| 26|Infrequent Customer|
339 | Gift Depot Inc. | 36.12| 25|Infrequent Customer|
340 | Vitachrome Inc. | 31.48| 25|Infrequent Customer|
341 | Collectable Mini Designs Co. | 38.16| 25|Infrequent Customer|
342 | Petit Auto | 31.84| 25|Infrequent Customer|
343 | Marseille Mini Autos | 32.16| 25|Infrequent Customer|
344 | Collectables For Less Inc. | 33.13| 24|Infrequent Customer|
345 | Norway Gifts By Mail, Co. | 32.79| 24|Infrequent Customer|
346 | Enaco Distributors | 38.35| 23|Infrequent Customer|
347 | Motor Mint Distributors Inc. | 31.74| 23|Infrequent Customer|
348 | Australian Collectables, Ltd | 30.65| 23|Infrequent Customer|
349 | La Corne D'abondance, Co. | 36.35| 23|Infrequent Customer|
350 | Canadian Gift Exchange Network | 31.95| 22|Infrequent Customer|
351 | Blauer See Auto, Co. | 36.86| 22|Infrequent Customer|
352 | Quebec Home Shopping Network | 32.59| 22|Infrequent Customer|
353 | Mini Wheels Co. | 32.95| 21|Infrequent Customer|
354 | Tekni Collectables Inc. | 43.14| 21|Infrequent Customer|
355 | Classic Gift Ideas, Inc | 31.81| 21|Infrequent Customer|
356 | Daedalus Designs Imports | 34.95| 20|Infrequent Customer|
357 | Osaka Souveniers Co. | 34.60| 20|Infrequent Customer|
358 | Lyon Souveniers | 34.20| 20|Infrequent Customer|
359 | Alpha Cognac | 34.35| 20|Infrequent Customer|
360 | Classic Legends Inc. | 36.00| 20|Infrequent Customer|
361 | Volvo Model Replicas, Co | 34.05| 19|Infrequent Customer|
362 | Mini Caravy | 41.00| 19|Infrequent Customer|
363 | Gift Ideas Corp. | 35.05| 19|Infrequent Customer|
364 | Auto Assoc. & Cie. | 35.39| 18|Infrequent Customer|
365 | Diecast Collectables | 38.61| 18|Infrequent Customer|
366 | Super Scale Inc. | 37.41| 17|Infrequent Customer|
367 | Clover Collections, Co. | 30.63| 16|Infrequent Customer|
368 | Online Mini Collectables | 38.13| 15|Infrequent Customer|
369 | Australian Gift Network, Co | 36.33| 15|Infrequent Customer|
370 | Signal Collectibles Ltd. | 34.27| 15|Infrequent Customer|
371 | Iberia Gift Imports, Corp. | 39.27| 15|Infrequent Customer|
372 | Mini Auto Werke | 35.47| 15|Infrequent Customer|
373 | Bavarian Collectables Imports, Co.| 28.64| 14|Infrequent Customer|
374 | Men 'R' US Retailers, Ltd. | 35.71| 14|Infrequent Customer|
375 | West Coast Collectables Co. | 39.31| 13|Infrequent Customer|
376 | CAF Imports | 36.00| 13|Infrequent Customer|
377 | Double Decker Gift Stores, Ltd | 29.75| 12|Infrequent Customer|
378 | Cambridge Collectables Co. | 32.45| 11|Infrequent Customer|
379 | Microscale Inc. | 38.10| 10|Infrequent Customer|
380 | Royale Belge | 34.75| 8|Infrequent Customer|
381 | Auto-Moto Classics Inc. | 35.88| 8|Infrequent Customer|
382 | Atelier graphique | 38.57| 7|Infrequent Customer|
383 | Boards & Toys Co. | 34.00| 3|Infrequent Customer|
384 | */
385 |
386 |
--------------------------------------------------------------------------------
/source_data/sql_sales_project/vscode_screenshot.PNG:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/iweld/sql_interview_questions/6f4e3192b09b4ed64201a8bd4f76a292f1891431/source_data/sql_sales_project/vscode_screenshot.PNG
--------------------------------------------------------------------------------
/source_data/teachers_and_classes.sql:
--------------------------------------------------------------------------------
1 | --create school database
2 |
3 | DROP TABLE IF EXISTS teachers
4 | CREATE TABLE teachers (
5 | id INTEGER PRIMARY KEY,
6 | name TEXT,
7 | subject TEXT,
8 | department TEXT
9 | );
10 |
11 | INSERT INTO teachers (name, subject, department)
12 | Values
13 | ("Miranda", "Ag Chemistry", "Science"),
14 | ("Miranda", "Sustainable Ag", "Science"),
15 | ("Munn", "Ag Biology", "Science"),
16 | ("Munn", "Plant and Animal", "Science"),
17 | ("Niederfrank", "Ag Science", "Science"),
18 | ("Niederfrank", "Ag Biology", "Science"),
19 | ("Gonzalez", "Ag Biology", "Science"),
20 | ("Gonzalez", "Plant and Animal", "Science"),
21 | ("Stuhr", "Basic Fab", "CTE"),
22 | ("Stuhr", "ROP Welding", "CTE"),
23 | ("Stuhr", "Welding 1", "CTE"),
24 | ("Carpenter", "Construction", "CTE"),
25 | ("Carpenter", "ROP Construction", "CTE"),
26 | ("Carpenter", "Basic Fab", "CTE"),
27 | ("Barcellos", "ROP Floral", "CTE"),
28 | ("Barcellos", "Floral", "CTE"),
29 | ("Barcellos", "Basic Fab", "CTE");
30 |
31 | DROP TABLE IF EXISTS grade_levels;
32 | CREATE TABLE grade_levels (
33 | id INTEGER PRIMARY KEY,
34 | class_name TEXT,
35 | grade INTEGER
36 | );
37 |
38 | INSERT INTO grade_levels (class_name, grade)
39 | VALUES
40 | ("Ag Chemistry", 10),
41 | ("Ag Chemistry", 11),
42 | ("Sustainable Ag", 12),
43 | ("Ag Biology", 9),
44 | ("Plant and Animal", 10),
45 | ("Plant and Animal", 11),
46 | ("Ag Science", 9),
47 | ("Basic Fab", 9),
48 | ("Welding 1", 10),
49 | ("ROP Welding", 11),
50 | ("ROP Welding", 12),
51 | ("ROP Construction", 11),
52 | ("ROP Construction", 12),
53 | ("Construction", 10),
54 | ("ROP Floral", 11),
55 | ("ROP Floral", 12),
56 | ("Floral", 10);
57 |
58 | --what subjects does each teacher teach and what grade levels can take those classes?
59 | SELECT t.name, t.subject, g.grade
60 | FROM teachers t
61 | JOIN grade_levels g
62 | ON t.subject = g.class_name
63 | ORDER BY t.name asc;
64 |
65 | --what teachers could a 9th grader possibly get?
66 | SELECT t.name, g.grade
67 | FROM teachers t
68 | JOIN grade_levels g
69 | ON t.subject = g.class_name
70 | WHERE grade = 9
71 | GROUP BY t.name;
72 |
73 | --what grade levels does each teacher teach?
74 | SELECT t.name, g.grade
75 | FROM teachers t
76 | JOIN grade_levels g
77 | ON t.subject = g.class_name
78 | ORDER BY t.name, g.grade asc;
79 |
80 |
--------------------------------------------------------------------------------