File notes/code/sql/HW_Capstone.sql added (mode: 100644) (index 0000000..ba0282a) |
|
1 |
|
/* code/sql/HW_Capstone.sql */ |
|
2 |
|
|
|
3 |
|
DROP SCHEMA IF EXISTS HW_CAPSTONE; |
|
4 |
|
|
|
5 |
|
CREATE SCHEMA HW_CAPSTONE; |
|
6 |
|
|
|
7 |
|
USE HW_CAPSTONE; |
|
8 |
|
|
|
9 |
|
CREATE TABLE STUDENT ( |
|
10 |
|
FName VARCHAR(50), |
|
11 |
|
Id CHAR(13) PRIMARY KEY, |
|
12 |
|
GraduationYear INT, |
|
13 |
|
GraduationSemester ENUM ("Fall", "Spring", "Summer") |
|
14 |
|
); |
|
15 |
|
|
|
16 |
|
CREATE TABLE PROGRAMMING_LANGUAGE ( |
|
17 |
|
NAME VARCHAR(50) PRIMARY KEY, |
|
18 |
|
Licence VARCHAR(50) |
|
19 |
|
); |
|
20 |
|
|
|
21 |
|
CREATE TABLE PROJECT ( |
|
22 |
|
CodeName VARCHAR(50), |
|
23 |
|
Leader CHAR(13), |
|
24 |
|
PRIMARY KEY (CodeName, Leader), |
|
25 |
|
FOREIGN KEY (Leader) REFERENCES STUDENT (Id) |
|
26 |
|
); |
|
27 |
|
|
|
28 |
|
CREATE TABLE USED_LANGUAGE ( |
|
29 |
|
ProjectCodeName VARCHAR(50), |
|
30 |
|
ProjectLeader CHAR(13), |
|
31 |
|
UsedLanguage VARCHAR(50), |
|
32 |
|
PRIMARY KEY (ProjectCodeName, ProjectLeader, UsedLanguage), |
|
33 |
|
FOREIGN KEY (ProjectCodeName, ProjectLeader) REFERENCES |
|
34 |
|
PROJECT (CodeName, Leader), |
|
35 |
|
FOREIGN KEY (UsedLanguage) REFERENCES PROGRAMMING_LANGUAGE (NAME) |
|
36 |
|
); |
|
37 |
|
|
|
38 |
|
|
|
39 |
|
/* |
|
40 |
|
*/ |
|
41 |
|
INSERT INTO STUDENT |
|
42 |
|
VALUES ( |
|
43 |
|
"Mary", |
|
44 |
|
"0123456789100", |
|
45 |
|
2025, |
|
46 |
|
"Summer"), |
|
47 |
|
( |
|
48 |
|
"Steve", |
|
49 |
|
"0000000000000", |
|
50 |
|
2025, |
|
51 |
|
"Fall"), |
|
52 |
|
( |
|
53 |
|
"Claude", |
|
54 |
|
"9999999999999", |
|
55 |
|
2024, |
|
56 |
|
"Fall"), |
|
57 |
|
( |
|
58 |
|
"Meghan", |
|
59 |
|
"0987654321098", |
|
60 |
|
2023, |
|
61 |
|
"Spring"); |
|
62 |
|
|
|
63 |
|
INSERT INTO PROGRAMMING_LANGUAGE |
|
64 |
|
VALUES ( |
|
65 |
|
"Rust", |
|
66 |
|
"MIT"), |
|
67 |
|
( |
|
68 |
|
".NET Core", |
|
69 |
|
"MIT"), |
|
70 |
|
( |
|
71 |
|
"Racket", |
|
72 |
|
"LGPL"), |
|
73 |
|
( |
|
74 |
|
"Python", |
|
75 |
|
"PSF"); |
|
76 |
|
|
|
77 |
|
-- Taken from |
|
78 |
|
-- https://en.wikipedia.org/wiki/Comparison_of_open-source_pr |
|
79 |
|
-- ogramming_language_licensing |
|
80 |
|
|
|
81 |
|
INSERT INTO PROJECT |
|
82 |
|
VALUES ( |
|
83 |
|
"Brick Break", |
|
84 |
|
"0123456789100"), |
|
85 |
|
( |
|
86 |
|
"Brick Break", |
|
87 |
|
"0000000000000"), |
|
88 |
|
( |
|
89 |
|
"Grade Calculator", |
|
90 |
|
"0123456789100"), |
|
91 |
|
( |
|
92 |
|
"Undecided", |
|
93 |
|
"9999999999999"); |
|
94 |
|
|
|
95 |
|
INSERT INTO USED_LANGUAGE |
|
96 |
|
VALUES ( |
|
97 |
|
"Brick Break", |
|
98 |
|
"0123456789100", |
|
99 |
|
"Rust"), |
|
100 |
|
( |
|
101 |
|
"Brick Break", |
|
102 |
|
"0000000000000", |
|
103 |
|
".NET Core"), |
|
104 |
|
( |
|
105 |
|
"Brick Break", |
|
106 |
|
"0000000000000", |
|
107 |
|
"Python"), |
|
108 |
|
( |
|
109 |
|
"Grade Calculator", |
|
110 |
|
"0123456789100", |
|
111 |
|
"Racket"); |
File notes/code/sql/HW_CapstoneSol.sql renamed from notes/code/sql/HW_Captone.sql (similarity 74%) (mode: 100644) (index 84121f6..90524f2) |
1 |
|
/* code/sql/HW_CaptoneSol.sql */ |
|
2 |
|
/* |
|
3 |
|
* |
|
4 |
|
* Look for "FILL HERE" |
|
5 |
|
* |
|
6 |
|
*/ |
|
7 |
|
/* |
|
8 |
|
* |
|
9 |
|
* DO **NOT** EDIT THE CODE BELOW |
|
10 |
|
* |
|
11 |
|
*/ |
|
12 |
1 |
DROP SCHEMA IF EXISTS HW_CAPSTONE; |
DROP SCHEMA IF EXISTS HW_CAPSTONE; |
13 |
2 |
|
|
14 |
3 |
CREATE SCHEMA HW_CAPSTONE; |
CREATE SCHEMA HW_CAPSTONE; |
|
... |
... |
VALUES ( |
131 |
117 |
/* |
/* |
132 |
118 |
* You can start editing starting here. |
* You can start editing starting here. |
133 |
119 |
*/ |
*/ |
|
120 |
|
|
|
121 |
|
-- start snippet solution |
|
122 |
|
/* |
|
123 |
|
code/sql/HW_CapstoneSol.sql |
|
124 |
|
*/ |
|
125 |
|
|
134 |
126 |
/* |
/* |
135 |
127 |
|
|
136 |
128 |
I. Short Questions (6 pts) |
I. Short Questions (6 pts) |
|
... |
... |
Answer the following short questions based on the model implemented above. |
139 |
131 |
You can simply answer "True" or "False", or justify your reasoning (e.g. with code). |
You can simply answer "True" or "False", or justify your reasoning (e.g. with code). |
140 |
132 |
*/ |
*/ |
141 |
133 |
-- 1. Can a project uses multiple programming languages? |
-- 1. Can a project uses multiple programming languages? |
|
134 |
|
-- Yes. |
142 |
135 |
-- 2. Can a student be the leader of multiple projects? |
-- 2. Can a student be the leader of multiple projects? |
|
136 |
|
-- Yes. |
143 |
137 |
-- 3. Can multiple projects have the same code name? |
-- 3. Can multiple projects have the same code name? |
|
138 |
|
-- Yes. |
144 |
139 |
-- 4. Could Claude simply enter NULL for the value of |
-- 4. Could Claude simply enter NULL for the value of |
145 |
140 |
-- his |
-- his |
146 |
141 |
-- project's code name, since he's undecided? |
-- project's code name, since he's undecided? |
|
142 |
|
-- No. |
147 |
143 |
-- 5. Can a project be created without project leader? |
-- 5. Can a project be created without project leader? |
|
144 |
|
-- No. |
148 |
145 |
-- 6. Can we know who is working on a project without |
-- 6. Can we know who is working on a project without |
149 |
146 |
-- being |
-- being |
150 |
147 |
-- its leader? |
-- its leader? |
|
148 |
|
-- No. |
151 |
149 |
/* |
/* |
152 |
150 |
|
|
153 |
151 |
II. Relational Model (6 pts.) |
II. Relational Model (6 pts.) |
|
... |
... |
The first question is answered as an example. |
174 |
166 |
SELECT Name |
SELECT Name |
175 |
167 |
FROM PROGRAMMING_LANGUAGE; |
FROM PROGRAMMING_LANGUAGE; |
176 |
168 |
|
|
|
169 |
|
-- 1. Write a command that insert a new student in the |
177 |
170 |
-- STUDENT table. |
-- STUDENT table. |
178 |
171 |
-- (You should invent the values). |
-- (You should invent the values). |
|
172 |
|
INSERT INTO STUDENT |
|
173 |
|
VALUES ( |
|
174 |
|
"Bob", |
|
175 |
|
"0987654321234", |
|
176 |
|
NULL, |
|
177 |
|
NULL); |
|
178 |
|
|
|
179 |
|
-- 2. Write a command that updates the code name of the |
179 |
180 |
-- project ("Undecided", "9999999999999") to "VR in ER". |
-- project ("Undecided", "9999999999999") to "VR in ER". |
|
181 |
|
UPDATE |
|
182 |
|
PROJECT |
|
183 |
|
SET CodeName = "VR in ER" |
|
184 |
|
WHERE CodeName = "Undecided" |
|
185 |
|
AND Leader = "9999999999999"; |
|
186 |
|
|
|
187 |
|
-- 3. Write a command that updates the graduation year of the |
|
188 |
|
-- student whose id is "0987654321098" to 2024, and the |
180 |
189 |
-- semester to "Fall". |
-- semester to "Fall". |
|
190 |
|
UPDATE |
|
191 |
|
STUDENT |
|
192 |
|
SET GraduationYear = 2024, |
|
193 |
|
GraduationSemester = "Fall" |
|
194 |
|
WHERE id = "0987654321098"; |
|
195 |
|
|
|
196 |
|
-- 4. Write a command that changes the STUDENT table to make |
181 |
197 |
-- it impossible to enter NULL for the first name of a |
-- it impossible to enter NULL for the first name of a |
182 |
198 |
-- student, without changing the primary key. |
-- student, without changing the primary key. |
|
199 |
|
ALTER TABLE STUDENT MODIFY FName VARCHAR(50) NOT NULL; |
|
200 |
|
|
|
201 |
|
-- 5. Write a command that changes the datatype of |
183 |
202 |
-- GraduationYear to SMALLINT. |
-- GraduationYear to SMALLINT. |
|
203 |
|
ALTER TABLE STUDENT MODIFY GraduationYear SMALLINT; |
|
204 |
|
|
|
205 |
|
-- 6. Write a command that adds an attribute "ReleaseDate" to |
|
206 |
|
-- the PROJECT table. |
|
207 |
|
ALTER TABLE PROJECT |
|
208 |
|
ADD COLUMN ReleaseDate DATE; |
|
209 |
|
|
|
210 |
|
-- 6.bis If you managed to write the previous command |
184 |
211 |
-- correctly, write a command that sets the release date |
-- correctly, write a command that sets the release date |
185 |
212 |
-- of |
-- of |
186 |
213 |
-- the project ("Brick Break", "0123456789100") to the |
-- the project ("Brick Break", "0123456789100") to the |
187 |
214 |
-- 26th |
-- 26th |
188 |
215 |
-- of November 2022. |
-- of November 2022. |
|
216 |
|
UPDATE |
|
217 |
|
PROJECT |
|
218 |
|
SET ReleaseDate = DATE "20221126" |
|
219 |
|
WHERE CodeName = "Brick Break" |
|
220 |
|
AND Leader = "0123456789100"; |
|
221 |
|
|
|
222 |
|
-- 7. Write a command that makes it impossible for a student |
189 |
223 |
-- to be the leader in more than one project |
-- to be the leader in more than one project |
190 |
224 |
-- (This command should return an error) |
-- (This command should return an error) |
|
225 |
|
-- ALTER TABLE PROJECT ADD UNIQUE (Leader); |
File notes/lectures_notes.md changed (mode: 100644) (index 1602067..bbdc8de) |
... |
... |
marks the (usual) separation between two lectures. |
105 |
105 |
To give you a sense of what you will be asked during the exams, or simply to practise, please find below the exams given previous semesters, in reverse chronological order. |
To give you a sense of what you will be asked during the exams, or simply to practise, please find below the exams given previous semesters, in reverse chronological order. |
106 |
106 |
The quizzes are not indicated, but were generally a mix of up to five exercises and one problem from the relevant chapter(s). |
The quizzes are not indicated, but were generally a mix of up to five exercises and one problem from the relevant chapter(s). |
107 |
107 |
|
|
|
108 |
|
### Fall 2020 {-} |
|
109 |
|
|
|
110 |
|
- Project #1: [%D %n (%T)](#problem:project1bis) |
|
111 |
|
|
108 |
112 |
### Spring 2020 {-} |
### Spring 2020 {-} |
109 |
113 |
|
|
110 |
114 |
Due to the Covid-19 pandemic, only one exam took place, and the final exam was taken remotely on D2L. |
Due to the Covid-19 pandemic, only one exam took place, and the final exam was taken remotely on D2L. |
|
... |
... |
Problem (A simple database for authors of textbooks) +.#project1 |
4063 |
4067 |
|
|
4064 |
4068 |
--- |
--- |
4065 |
4069 |
|
|
|
4070 |
|
--- |
|
4071 |
|
|
|
4072 |
|
Problem (A simple database for capstone projects) +.#project1bis |
|
4073 |
|
~ |
|
4074 |
|
|
|
4075 |
|
Consider the following code: |
|
4076 |
|
|
|
4077 |
|
|
|
4078 |
|
```{.sqlmysql .numberLines include=code/sql/HW_Capstone.sql} |
|
4079 |
|
``` |
|
4080 |
|
The meaning of the USED_LANGUAGE table is that a tuple $< N, L, U>$ represents the fact that the project whose code name is $N$ and whose leader is $L$ uses the programming language $U$. |
|
4081 |
|
|
|
4082 |
|
@problem:project1bis -- Question -.# |
|
4083 |
|
|
|
4084 |
|
: Answer the following short questions based on the model implemented above. |
|
4085 |
|
You can simply answer "True" or "False", or justify your reasoning (e.g. with code). |
|
4086 |
|
|
|
4087 |
|
#. Can a project uses multiple programming languages? |
|
4088 |
|
#. Can a student be the leader of multiple projects? |
|
4089 |
|
#. Can multiple projects have the same code name? |
|
4090 |
|
#. Could Claude simply enter NULL for the value of his project's code name, since he's undecided? |
|
4091 |
|
#. Can a project be created without project leader? |
|
4092 |
|
#. Can we know who is working on a project without being its leader? |
|
4093 |
|
|
|
4094 |
|
@problem:project1bis -- Question -.# |
|
4095 |
|
|
|
4096 |
|
~ Draw the relational model corresponding to this code. |
|
4097 |
|
|
|
4098 |
|
@problem:project1bis -- Question -.# |
|
4099 |
|
|
|
4100 |
|
: Write the following commands. |
|
4101 |
|
|
|
4102 |
|
#. Write a command that insert a new student in the STUDENT table. |
|
4103 |
|
#. Write a command that updates the code name of the project ("Undecided", "9999999999999") to "VR in ER". |
|
4104 |
|
#. Write a command that updates the graduation year of the student whose id is "0987654321098" to 2024, and the semester to "Fall". |
|
4105 |
|
#. Write a command that changes the STUDENT table to make it impossible to enter NULL for the first name of a student, without changing the primary key. |
|
4106 |
|
#. Write a command that changes the datatype of GraduationYear to SMALLINT. |
|
4107 |
|
#. Write a command that adds an attribute "ReleaseDate" to the PROJECT table. |
|
4108 |
|
#. If you managed to write the previous command correctly, write a command that sets the release date of the project ("Brick Break", "0123456789100") to the 26th of November 2022. |
|
4109 |
|
#. Write a command that makes it impossible for a student to be the leader in more than one project |
|
4110 |
|
|
|
4111 |
|
--- |
|
4112 |
|
|
4066 |
4113 |
Problem (A database for residencies) +.#residency |
Problem (A database for residencies) +.#residency |
4067 |
4114 |
~ |
~ |
4068 |
4115 |
|
|
|
... |
... |
Solution to [%D %n (%T)](#problem:project1) |
4733 |
4780 |
|
|
4734 |
4781 |
--- |
--- |
4735 |
4782 |
|
|
|
4783 |
|
Solution to [%D %n (%T)](#problem:project1bis) |
|
4784 |
|
~ |
|
4785 |
|
The answers can be found in the following snippet: |
|
4786 |
|
|
|
4787 |
|
```{.sqlmysql .numberLines include=code/sql/HW_CapstoneSol.sql snippet=solution} |
|
4788 |
|
``` |
|
4789 |
|
|
|
4790 |
|
--- |
|
4791 |
|
|
4736 |
4792 |
Solution to [%D %n (%T)](#problem:residency) |
Solution to [%D %n (%T)](#problem:residency) |
4737 |
4793 |
~ |
~ |
4738 |
4794 |
The file [code/sql/HW_ResidencySol.sql](https://rocketgit.com/user/caubert/CSCI_3410/source/tree/branch/master/blob/notes/code/sql/HW_ResidencySol.sql) contains the solution to the code part of this problem. |
The file [code/sql/HW_ResidencySol.sql](https://rocketgit.com/user/caubert/CSCI_3410/source/tree/branch/master/blob/notes/code/sql/HW_ResidencySol.sql) contains the solution to the code part of this problem. |