-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathsql-workshop.Rmd
368 lines (261 loc) · 12 KB
/
sql-workshop.Rmd
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
---
title: "sql-workshop"
author: "Charles Lang"
date: "10/16/2019"
output: html_document
---
## Connect to AMW MySQL Database
```{r}
#install.packages("DBI", "RMySQL")
library(DBI)
library(RMySQL)
db_user <- 'admin'
db_password <- 'testsql!'
db_name <- 'oudb'
db_host <- 'sqltest.clh43re5lq5h.us-east-1.rds.amazonaws.com'
db_port <- 3306
mydb <- dbConnect(MySQL(), user = db_user, password = db_password, dbname = db_name, host = db_host, port = db_port)
summary(mydb)
```
## Load OU Data
```{r}
#Student demographic data
studentInfo <- read.csv("studentInfo.csv", header = TRUE)
#Student assessment data
studentAssessment <- read.csv("studentAssessment.csv", header = TRUE)
#Course data
courses <- read.csv("courses.csv", header = TRUE)
studentRegistration <- read.csv("studentRegistration.csv", header = TRUE)
```
## Write data to the DB using the DBI package
```{r}
#List the tables in the DB
dbListTables(mydb)
#Write a new table to the DB
dbWriteTable(mydb, "studentInfo", studentInfo)
dbWriteTable(mydb, "studentAssessment", studentAssessment)
dbWriteTable(mydb, "courses", courses)
dbWriteTable(mydb, "studentRegistration", studentRegistration)
#List tables to see that table was added
dbListTables(mydb)
#Read a particular table
dbReadTable(mydb, 'studentInfo')
#EXERCISE 1
#Make two toy data sets with at least three variables and at least 30 rows each in them. Have a mix of numeric and character variables. Transfer these dataframes to your SQL database using the DBI commands. Name the tables whatever you like.
```
## Getting into SQL - READING
```{r}
#Query a portion of the database (always returns dataframe)
dbGetQuery(mydb, "SELECT * FROM studentInfo LIMIT 10;")
dbGetQuery(mydb, "SELECT * FROM studentInfo ORDER BY id_student LIMIT 10;")
dbGetQuery(mydb, "SELECT id_student, gender FROM studentInfo ORDER BY id_student DESC LIMIT 10;") #Order listed will be reflected in order in table
dbGetQuery(mydb, "SELECT id_student AS 'Student ID', gender FROM studentInfo LIMIT 10;") #SQL Standard says quotes for literal strings and double quotes for everything else but that conflicts with R
#Count the number of rows
dbGetQuery(mydb, "SELECT COUNT(*) FROM studentAssessment;")
#Using a WHERE statement on all columns
dbGetQuery(mydb, "SELECT COUNT(*) FROM studentAssessment WHERE score > 50;")
#Using a WHERE statement on a single column (will not include missing data)
dbGetQuery(mydb, "SELECT COUNT(score) FROM studentAssessment WHERE score > 50;")
#Using an AND statement
dbGetQuery(mydb, "SELECT COUNT(*) FROM studentAssessment WHERE score > 50 AND id_assessment = '1752';")
#EXERCISE 2
#Read one of your toy data tables, make sure the output is ordered in descending order, you rename one of the variables and the output is limited to the first 20 rows.
#Read the other table according to a condition of one of the variables.
```
## Getting into SQL - UPDATING
```{r}
#Count rows
dbGetQuery(mydb, "SELECT COUNT(*) FROM studentAssessment;")
#Add a row
dbGetQuery(mydb, "INSERT INTO studentAssessment (id_assessment, id_student, date_submitted, is_banked, score) VALUES ('00001', '1', '20', '0', '50');")
#Count rows again
dbGetQuery(mydb, "SELECT COUNT(*) FROM studentAssessment;")
#View inserted row
dbGetQuery(mydb, "SELECT * FROM studentAssessment ORDER BY id_student LIMIT 10;")
#Add a row with missing values
dbGetQuery(mydb, "INSERT INTO studentAssessment (id_assessment, id_student, date_submitted) VALUES ('00001', '1', '20');")
#View inserted row
dbGetQuery(mydb, "SELECT * FROM studentAssessment ORDER BY id_student LIMIT 10;")
#Update a row
dbGetQuery(mydb, "UPDATE studentAssessment SET score = '20' WHERE id_student = 1;")
dbGetQuery(mydb, "SELECT id_student, score FROM studentAssessment ORDER BY id_student LIMIT 10;")
#Update a row with NULL
dbGetQuery(mydb, "UPDATE studentAssessment SET score = 'NULL' WHERE id_student = 6516;")
#Delete a row (destructive)
dbGetQuery(mydb, "DELETE FROM studentAssessment WHERE id_student = 1;")
dbGetQuery(mydb, "SELECT * FROM studentAssessment ORDER BY id_student LIMIT 10;")
#EXERCISE 3
#Insert a new row in one of your toy data tables leaving one variable empty. Change one value in your other table. Display your new tables. Delete the row you edited and the row you inserted.
```
## Add/Deleting Table
```{r}
#Creating a new table in SQL
dbGetQuery(mydb,"CREATE TABLE test (
score INTEGER,
student TEXT
);")
dbListTables(mydb)
#Inserting data into the table
dbGetQuery(mydb, "INSERT INTO test VALUES ( 10, 'Amy' );")
dbGetQuery(mydb, "INSERT INTO test VALUES ( 11, 'Jen' );")
dbGetQuery(mydb, "INSERT INTO test VALUES ( 9, 'Frank' );")
dbGetQuery(mydb, "SELECT * FROM test;")
#Inserting a NULL row
dbGetQuery(mydb, "INSERT INTO test DEFAULT VALUES;")
dbGetQuery(mydb,"INSERT INTO test (score, student) SELECT score, id_student FROM studentAssessment;")
#Delete a table
dbGetQuery(mydb, "DROP TABLE test;")
dbGetQuery(mydb, "SELECT * FROM test;") #This should produce an error
#Delete a table if it exists
dbGetQuery(mydb, "DROP TABLE IF EXISTS test;")
#EXERCISE 4
#Create a table that is exactly the same as your first toy data table but this time use SQL commands. Display your new table. Then delete the original table.
```
# NULL Value
```{r}
#NULL is a state (similar to R), represents the lack of a value. But is not compatible with R backend so this code doesn't work as part of dbGetQuery()
#This doesn't work because NULL is not a value
SELECT * FROM test WHERE score = NULL;
#Instead use
SELECT * FROM test WHERE score is NULL;
```
# Constraints
```{r}
#Create table where student column *cannot* be NULL
dbGetQuery(mydb,"CREATE TABLE test2 (
score INTEGER,
student TEXT NOT NULL
);")
dbGetQuery(mydb, "DROP TABLE IF EXISTS test2;")
dbGetQuery(mydb,"CREATE TABLE test2 (
score INTEGER DEFAULT 0,
student TEXT
);")
dbGetQuery(mydb,"INSERT INTO test2 (score, student) VALUES ('1', 'A');")
dbGetQuery(mydb,"INSERT INTO test2 (student) VALUES ('B');")
dbGetQuery(mydb, "SELECT * FROM test2;")
dbGetQuery(mydb, "DROP TABLE IF EXISTS test2;")
dbGetQuery(mydb,"CREATE TABLE test2 (
score INTEGER UNIQUE,
student TEXT
);")
dbGetQuery(mydb,"INSERT INTO test2 (score, student) VALUES ('1', 'A');")
#Error because of unique
dbGetQuery(mydb,"INSERT INTO test2 (score, student) VALUES ('1', 'A');")
#NULL is exempt
dbGetQuery(mydb,"INSERT INTO test2 (score, student) VALUES (NULL, 'A');")
dbGetQuery(mydb,"INSERT INTO test2 (score, student) VALUES (NULL, 'A');")
#EXERCISE 5
#Recreate one of your toy data tables with the constraint that for one of the integer variablesthe default value will be zero. Test your table by inserting some empty values. Display your new tables. Then delete your table.
```
# Adding a column with a default value
```{r}
#Add a column with default value 1
dbGetQuery(mydb, "ALTER TABLE studentAssessment ADD email INTEGER DEFAULT 1 ")
dbGetQuery(mydb, "SELECT * FROM studentAssessment LIMIT 10;")
#Delete a column
dbGetQuery(mydb, "ALTER TABLE studentAssessment DROP COLUMN email;")
#EXERCISE 6
#Add a column to one of your toy data tables with a default value of 3. Display your new table. Delete this column.
```
# ID Columns
```{r}
dbGetQuery(mydb,"CREATE TABLE test2 (
id INTEGER AUTO_INCREMENT PRIMARY KEY, #Not standard syntax
score INTEGER,
student TEXT
);")
dbGetQuery(mydb,"INSERT INTO test2 (score, student) VALUES (1, 'A');")
dbGetQuery(mydb,"INSERT INTO test2 (score, student) VALUES (5, 'B');")
dbGetQuery(mydb, "SELECT * FROM test2;")
dbGetQuery(mydb, "DROP TABLE IF EXISTS test2;")
#EXERCISE 7
#Create a new table with four variables and a primary key that is a sequential id value.
```
## Filtering (WHERE)
```{r}
dbGetQuery(mydb, "SELECT id_student, date_submitted FROM studentAssessment WHERE date_submitted > 550 ORDER BY date_submitted DESC;")
#OR Statement
dbGetQuery(mydb, "SELECT id_student, date_submitted FROM studentAssessment WHERE date_submitted > 550 OR date_submitted < 2 ORDER BY date_submitted DESC;")
#AND Statement
dbGetQuery(mydb, "SELECT id_student, date_submitted FROM studentAssessment WHERE date_submitted > 550 AND id_student = 325750 ORDER BY date_submitted DESC;")
#LIKE
dbGetQuery(mydb, "SELECT id_student, gender, region FROM studentInfo WHERE region LIKE '%Region%';")
#Begin with 'Region'
dbGetQuery(mydb, "SELECT id_student, gender, region FROM studentInfo WHERE region LIKE 'Region%';")
#End with 'Region'
dbGetQuery(mydb, "SELECT id_student, gender, region FROM studentInfo WHERE region LIKE '%Region';")
#'c' is the second letter
dbGetQuery(mydb, "SELECT id_student, gender, region FROM studentInfo WHERE region LIKE '_c%';")
#IN
dbGetQuery(mydb, "SELECT id_student, gender, region FROM studentInfo WHERE region IN ('Wales','Ireland');")
#EXERCISE 8
#Query one of your original toy data tables, for two different conditions.
```
## Removing Duplicates
```{r}
dbGetQuery(mydb, "SELECT DISTINCT region FROM studentInfo;")
dbGetQuery(mydb, "SELECT DISTINCT region, gender FROM studentInfo;")
#EXERCISE 9
#Insert a duplicate row into one of your toy data tables. Then query the table without including duplicates.
```
## Conditional Expressions (non-standard)
```{r}
dbGetQuery(mydb, "CREATE TABLE booltest (a INTEGER, b INTEGER);")
dbGetQuery(mydb, "INSERT INTO booltest VALUES (1, 0);")
dbGetQuery(mydb, "SELECT * FROM booltest;")
dbGetQuery(mydb,"SELECT
CASE WHEN a THEN 'true' ELSE 'false' END as boolA,
CASE WHEN b THEN 'true' ELSE 'false' END as boolB
FROM booltest")
dbGetQuery(mydb,"SELECT
CASE a WHEN 1 THEN 'true' ELSE 'false' END as boolA,
CASE b WHEN 1 THEN 'true' ELSE 'false' END as boolB
FROM booltest")
```
#Relationships (JOIN) - *Slide*
```{r}
#This will take a while because of the architecture we are using
dbGetQuery(mydb,"SELECT id_student, gender, region, date_registration
FROM studentInfo
JOIN studentRegistration
ON studentInfo.id_student = studentRegistration.id_student
;")
dbGetQuery(mydb, "CREATE TABLE left_table (id INTEGER, description TEXT);")
dbGetQuery(mydb, "CREATE TABLE right_table (id INTEGER, description TEXT);")
dbGetQuery(mydb, "INSERT INTO left_table VALUES ( 1, 'left 01');")
dbGetQuery(mydb, "INSERT INTO left_table VALUES ( 2, 'left 02');")
dbGetQuery(mydb, "INSERT INTO left_table VALUES ( 3, 'left 03');")
dbGetQuery(mydb, "INSERT INTO left_table VALUES ( 4, 'left 04');")
dbGetQuery(mydb, "INSERT INTO left_table VALUES ( 5, 'left 05');")
dbGetQuery(mydb, "INSERT INTO left_table VALUES ( 6, 'left 06');")
dbGetQuery(mydb, "INSERT INTO left_table VALUES ( 7, 'left 07');")
dbGetQuery(mydb, "INSERT INTO left_table VALUES ( 8, 'left 08');")
dbGetQuery(mydb, "INSERT INTO left_table VALUES ( 9, 'left 09');")
dbGetQuery(mydb, "INSERT INTO right_table VALUES ( 6, 'left 06');")
dbGetQuery(mydb, "INSERT INTO right_table VALUES ( 7, 'left 07');")
dbGetQuery(mydb, "INSERT INTO right_table VALUES ( 8, 'left 08');")
dbGetQuery(mydb, "INSERT INTO right_table VALUES ( 9, 'left 09');")
dbGetQuery(mydb, "INSERT INTO right_table VALUES ( 10, 'left 10');")
dbGetQuery(mydb, "INSERT INTO right_table VALUES ( 11, 'left 11');")
dbGetQuery(mydb, "INSERT INTO right_table VALUES ( 12, 'left 12');")
dbGetQuery(mydb, "INSERT INTO right_table VALUES ( 13, 'left 13');")
dbGetQuery(mydb, "INSERT INTO right_table VALUES ( 14, 'left 14');")
dbGetQuery(mydb, "SELECT * FROM left_table;")
dbGetQuery(mydb, "SELECT * FROM right_table;")
dbGetQuery(mydb,"SELECT l.description AS left_table, r.description AS right_table
FROM left_table AS l
JOIN right_table AS r ON l.id = r.id")
dbGetQuery(mydb,"SELECT l.description AS left_table, r.description AS right_table
FROM left_table AS l
RIGHT JOIN right_table AS r ON l.id = r.id")
dbGetQuery(mydb,"SELECT l.description AS left_table, r.description AS right_table
FROM left_table AS l
LEFT JOIN right_table AS r ON l.id = r.id")
#Union
dbGetQuery(mydb, "SELECT * FROM left_table
UNION
SELECT * FROM right_table;")
#EXERCISE 10
# Create an a common id variable in your two toy data tables. Then do join those tables so that your query returns all the values from one table and only those that match from the other.
```