forked from datacarpentry/sql-ecology-lesson
-
Notifications
You must be signed in to change notification settings - Fork 0
/
03-sql-joins.html
1164 lines (1126 loc) · 67.2 KB
/
03-sql-joins.html
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
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
<!DOCTYPE html>
<!-- START: inst/pkgdown/templates/layout.html --><!-- Generated by pkgdown: do not edit by hand --><html lang="en"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8"><meta charset="utf-8"><title>Data Management with SQL for Ecologists: Combining Data With Joins</title><meta name="viewport" content="width=device-width, initial-scale=1"><link rel="stylesheet" type="text/css" href="assets/styles.css"><script src="assets/scripts.js" type="text/javascript"></script><!-- mathjax --><script type="text/x-mathjax-config">
MathJax.Hub.Config({
config: ["MMLorHTML.js"],
jax: ["input/TeX","input/MathML","output/HTML-CSS","output/NativeMML", "output/PreviewHTML"],
extensions: ["tex2jax.js","mml2jax.js","MathMenu.js","MathZoom.js", "fast-preview.js", "AssistiveMML.js", "a11y/accessibility-menu.js"],
TeX: {
extensions: ["AMSmath.js","AMSsymbols.js","noErrors.js","noUndefined.js"]
},
tex2jax: {
inlineMath: [['\\(', '\\)']],
displayMath: [ ['$$','$$'], ['\\[', '\\]'] ],
processEscapes: true
}
});
</script><script src="https://cdnjs.cloudflare.com/ajax/libs/mathjax/2.7.5/MathJax.js" integrity="sha256-nvJJv9wWKEm88qvoQl9ekL2J+k/RWIsaSScxxlsrv8k=" crossorigin="anonymous"></script><!-- Responsive Favicon for The Carpentries --><link rel="apple-touch-icon" sizes="180x180" href="apple-touch-icon.png"><link rel="icon" type="image/png" sizes="32x32" href="favicon-32x32.png"><link rel="icon" type="image/png" sizes="16x16" href="favicon-16x16.png"><link rel="manifest" href="site.webmanifest"><link rel="mask-icon" href="safari-pinned-tab.svg" color="#5bbad5"><meta name="msapplication-TileColor" content="#da532c"><meta name="theme-color" content="#ffffff"></head><body>
<header id="top" class="navbar navbar-expand-md navbar-light bg-white top-nav data"><a class="visually-hidden-focusable skip-link" href="#main-content">Skip to main content</a>
<div class="container-fluid top-nav-container">
<div class="col-md-6">
<div class="large-logo">
<img alt="Data Carpentry" src="assets/images/data-logo.svg"></div>
</div>
<div class="selector-container">
<div class="dropdown">
<button class="btn btn-secondary dropdown-toggle bordered-button" type="button" id="dropdownMenu1" data-bs-toggle="dropdown" aria-expanded="false">
<i aria-hidden="true" class="icon" data-feather="eye"></i> Learner View <i data-feather="chevron-down"></i>
</button>
<ul class="dropdown-menu" aria-labelledby="dropdownMenu1"><li><button class="dropdown-item" type="button" onclick="window.location.href='instructor/03-sql-joins.html';">Instructor View</button></li>
</ul></div>
</div>
</div>
<hr></header><nav class="navbar navbar-expand-xl navbar-light bg-white bottom-nav data" aria-label="Main Navigation"><div class="container-fluid nav-container">
<button class="navbar-toggler" type="button" data-bs-toggle="collapse" data-bs-target="#navbarSupportedContent" aria-controls="navbarSupportedContent" aria-expanded="false" aria-label="Toggle navigation">
<span class="navbar-toggler-icon"></span>
<span class="menu-title">Menu</span>
</button>
<div class="nav-logo">
<img class="small-logo" alt="Data Carpentry" src="assets/images/data-logo-sm.svg"></div>
<div class="lesson-title-md">
Data Management with SQL for Ecologists
</div>
<div class="search-icon-sm">
<!-- TODO: do not show until we have search
<i role="img" aria-label="search button" data-feather="search"></i>
-->
</div>
<div class="desktop-nav">
<ul class="navbar-nav me-auto mb-2 mb-lg-0"><li class="nav-item">
<span class="lesson-title">
Data Management with SQL for Ecologists
</span>
</li>
<li class="nav-item">
<a class="nav-link" href="key-points.html">Key Points</a>
</li>
<li class="nav-item">
<a class="nav-link" href="reference.html#glossary">Glossary</a>
</li>
<li class="nav-item">
<a class="nav-link" href="profiles.html">Learner Profiles</a>
</li>
<li class="nav-item dropdown">
<button class="nav-link dropdown-toggle" id="navbarDropdown" data-bs-toggle="dropdown" aria-expanded="false">
More <i data-feather="chevron-down"></i>
</button>
<ul class="dropdown-menu" aria-labelledby="navbarDropdown"><li><a class="dropdown-item" href="discuss.html">Discussion</a></li><li><a class="dropdown-item" href="reference.html">Reference</a></li>
</ul></li>
</ul></div>
<form class="d-flex col-md-2 search-form">
<fieldset disabled><input class="form-control me-2 searchbox" type="search" placeholder="Search" aria-label="Search"><button class="btn btn-outline-success tablet-search-button" type="submit">
<i class="search-icon" data-feather="search" role="img" aria-label="search button"></i>
</button>
</fieldset></form>
</div><!--/div.container-fluid -->
</nav><div class="col-md-12 mobile-title">
Data Management with SQL for Ecologists
</div>
<aside class="col-md-12 lesson-progress"><div style="width: 86%" class="percentage">
86%
</div>
<div class="progress data">
<div class="progress-bar data" role="progressbar" style="width: 86%" aria-valuenow="86" aria-label="Lesson Progress" aria-valuemin="0" aria-valuemax="100">
</div>
</div>
</aside><div class="container">
<div class="row">
<!-- START: inst/pkgdown/templates/navbar.html -->
<div id="sidebar-col" class="col-lg-4">
<div id="sidebar" class="sidebar">
<nav aria-labelledby="flush-headingEleven"><button role="button" aria-label="close menu" alt="close menu" aria-expanded="true" aria-controls="sidebar" class="collapse-toggle">
<i class="search-icon" data-feather="x" role="img"></i>
</button>
<div class="sidebar-inner">
<div class="row mobile-row">
<div class="col">
<div class="sidenav-view-selector">
<div class="accordion accordion-flush" id="accordionFlush9">
<div class="accordion-item">
<h2 class="accordion-header" id="flush-headingNine">
<button class="accordion-button collapsed" id="instructor" type="button" data-bs-toggle="collapse" data-bs-target="#flush-collapseNine" aria-expanded="false" aria-controls="flush-collapseNine">
<i id="eye" aria-hidden="true" class="icon" data-feather="eye"></i> Learner View
</button>
</h2>
<div id="flush-collapseNine" class="accordion-collapse collapse" aria-labelledby="flush-headingNine" data-bs-parent="#accordionFlush2">
<div class="accordion-body">
<a href="instructor/03-sql-joins.html">Instructor View</a>
</div>
</div>
</div><!--/div.accordion-item-->
</div><!--/div.accordion-flush-->
</div><!--div.sidenav-view-selector -->
</div><!--/div.col -->
<hr></div><!--/div.mobile-row -->
<div class="accordion accordion-flush" id="accordionFlush11">
<div class="accordion-item">
<button id="chapters" class="accordion-button show" type="button" data-bs-toggle="collapse" data-bs-target="#flush-collapseEleven" aria-expanded="false" aria-controls="flush-collapseEleven">
<h2 class="accordion-header chapters" id="flush-headingEleven">
EPISODES
</h2>
</button>
<div id="flush-collapseEleven" class="accordion-collapse show collapse" aria-labelledby="flush-headingEleven" data-bs-parent="#accordionFlush11">
<div class="accordion-body">
<div class="accordion accordion-flush" id="accordionFlush1">
<div class="accordion-item">
<div class="accordion-header" id="flush-heading1">
<a href="index.html">Summary and Setup</a>
</div><!--/div.accordion-header-->
</div><!--/div.accordion-item-->
</div><!--/div.accordion-flush-->
<div class="accordion accordion-flush" id="accordionFlush2">
<div class="accordion-item">
<div class="accordion-header" id="flush-heading2">
<a href="00-sql-introduction.html">1. Introducing Databases and SQL</a>
</div><!--/div.accordion-header-->
</div><!--/div.accordion-item-->
</div><!--/div.accordion-flush-->
<div class="accordion accordion-flush" id="accordionFlush3">
<div class="accordion-item">
<div class="accordion-header" id="flush-heading3">
<a href="01-sql-basic-queries.html">2. Accessing Data With Queries</a>
</div><!--/div.accordion-header-->
</div><!--/div.accordion-item-->
</div><!--/div.accordion-flush-->
<div class="accordion accordion-flush" id="accordionFlush4">
<div class="accordion-item">
<div class="accordion-header" id="flush-heading4">
<a href="02-sql-aggregation.html">3. Aggregating and Grouping Data</a>
</div><!--/div.accordion-header-->
</div><!--/div.accordion-item-->
</div><!--/div.accordion-flush-->
<div class="accordion accordion-flush" id="accordionFlushcurrent">
<div class="accordion-item">
<div class="accordion-header" id="flush-headingcurrent">
<button class="accordion-button" type="button" data-bs-toggle="collapse" data-bs-target="#flush-collapsecurrent" aria-expanded="true" aria-controls="flush-collapsecurrent">
<span class="visually-hidden">Current Chapter</span>
<span class="current-chapter">
4. Combining Data With Joins
</span>
</button>
</div><!--/div.accordion-header-->
<div id="flush-collapsecurrent" class="accordion-collapse collapse show" aria-labelledby="flush-headingcurrent" data-bs-parent="#accordionFlushcurrent">
<div class="accordion-body">
<ul><li><a href="#joins">Joins</a></li>
<li><a href="#functions-coalesce-and-nullif-and-more">Functions <code>COALESCE</code> and <code>NULLIF</code> and
more</a></li>
</ul></div><!--/div.accordion-body-->
</div><!--/div.accordion-collapse-->
</div><!--/div.accordion-item-->
</div><!--/div.accordion-flush-->
</div>
</div>
</div>
<hr class="half-width"><div class="accordion accordion-flush resources" id="accordionFlush12">
<div class="accordion-item">
<h2 class="accordion-header" id="flush-headingTwelve">
<button class="accordion-button collapsed" id="resources" type="button" data-bs-toggle="collapse" data-bs-target="#flush-collapseTwelve" aria-expanded="false" aria-controls="flush-collapseTwelve">
RESOURCES
</button>
</h2>
<div id="flush-collapseTwelve" class="accordion-collapse collapse" aria-labelledby="flush-headingTwelve" data-bs-parent="#accordionFlush12">
<div class="accordion-body">
<ul><li>
<a href="key-points.html">Key Points</a>
</li>
<li>
<a href="reference.html#glossary">Glossary</a>
</li>
<li>
<a href="profiles.html">Learner Profiles</a>
</li>
<li><a href="discuss.html">Discussion</a></li><li><a href="reference.html">Reference</a></li>
</ul></div>
</div>
</div>
</div>
<hr class="half-width resources"><a href="aio.html">See all in one page</a>
<hr class="d-none d-sm-block d-md-none"><div class="d-grid gap-1">
</div>
</div><!-- /div.accordion -->
</div><!-- /div.sidebar-inner -->
</nav></div><!-- /div.sidebar -->
</div><!-- /div.sidebar-col -->
<!-- END: inst/pkgdown/templates/navbar.html-->
<!-- START: inst/pkgdown/templates/content-instructor.html -->
<div class="col-xl-8 col-lg-12 primary-content">
<nav class="lesson-content mx-md-4" aria-label="Previous and Next Chapter"><!-- content for small screens --><div class="d-block d-sm-block d-md-none">
<a class="chapter-link" href="02-sql-aggregation.html"><i aria-hidden="true" class="small-arrow" data-feather="arrow-left"></i>Previous</a>
<a class="chapter-link float-end" href="index.html">Next<i aria-hidden="true" class="small-arrow" data-feather="arrow-right"></i></a>
</div>
<!-- content for large screens -->
<div class="d-none d-sm-none d-md-block">
<a class="chapter-link" href="02-sql-aggregation.html" rel="prev">
<i aria-hidden="true" class="small-arrow" data-feather="arrow-left"></i>
Previous: Aggregating and
</a>
<a class="chapter-link float-end" href="index.html" rel="next">
Home
<i aria-hidden="true" class="small-arrow" data-feather="arrow-right"></i>
</a>
</div>
<hr></nav><main id="main-content" class="main-content"><div class="container lesson-content">
<h1>Combining Data With Joins</h1>
<p> Last updated on 2023-06-30 |
<a href="https://github.com/datacarpentry/sql-ecology-lesson/edit/main/episodes/03-sql-joins.md" class="external-link">Edit this page <i aria-hidden="true" data-feather="edit"></i></a></p>
<div class="text-end">
<button role="button" aria-pressed="false" tabindex="0" id="expand-code" class="pull-right"> Expand All Solutions <i aria-hidden="true" data-feather="plus"></i></button>
</div>
<div class="overview card">
<h2 class="card-header">Overview</h2>
<div class="row g-0">
<div class="col-md-4">
<div class="card-body">
<div class="inner">
<h3 class="card-title">Questions</h3>
<ul><li>How do I bring data together from separate tables?</li>
</ul></div>
</div>
</div>
<div class="col-md-8">
<div class="card-body">
<div class="inner bordered">
<h3 class="card-title">Objectives</h3>
<ul><li>Employ joins to combine data from two tables.</li>
<li>Apply functions to manipulate individual values.</li>
<li>Employ aliases to assign new names to tables and columns in a
query.</li>
</ul></div>
</div>
</div>
</div>
</div>
<section id="joins"><h2 class="section-heading">Joins<a class="anchor" aria-label="anchor" href="#joins"></a>
</h2>
<hr class="half-width"><p>To combine data from two tables we use an SQL <code>JOIN</code>
clause, which comes after the <code>FROM</code> clause.</p>
<p>Database tables are used to organize and group data by common
characteristics or principles.<br>
Often, we need to combine elements from separate tables into a single
tables or queries for analysis and visualization. A JOIN is a means for
combining columns from multiple tables by using values common to
each.</p>
<p>The JOIN keyword combined with ON is used to combine fields from
separate tables.</p>
<p>A <code>JOIN</code> clause on its own will result in a cross product,
where each row in the first table is paired with each row in the second
table. Usually this is not what is desired when combining two tables
with data that is related in some way.</p>
<p>For that, we need to tell the computer which columns provide the link
between the two tables using the word <code>ON</code>. What we want is
to join the data with the same species id.</p>
<div class="codewrapper sourceCode" id="cb1">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb1-1"><a href="#cb1-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> <span class="op">*</span></span>
<span id="cb1-2"><a href="#cb1-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys</span>
<span id="cb1-3"><a href="#cb1-3" aria-hidden="true" tabindex="-1"></a><span class="kw">JOIN</span> species</span>
<span id="cb1-4"><a href="#cb1-4" aria-hidden="true" tabindex="-1"></a><span class="kw">ON</span> surveys.species_id <span class="op">=</span> species.species_id;</span></code></pre>
</div>
<p><code>ON</code> is like <code>WHERE</code>. It filters things out
according to a test condition. We use the <code>table.colname</code>
format to tell the manager what column in which table we are referring
to.</p>
<p>The output from using the <code>JOIN</code> clause will have columns
from the first table plus the columns from the second table. For the
above statement, the output will be a table that has the following
column names:</p>
<table style="width:100%;" class="table"><colgroup><col width="5%"><col width="45%"><col width="1%"><col width="5%"><col width="4%"><col width="5%"><col width="1%"><col width="8%"><col width="3%"><col width="5%"><col width="5%"><col width="4%"><col width="3%"></colgroup><thead><tr class="header"><th>record_id</th>
<th>month</th>
<th>day</th>
<th>year</th>
<th>plot_id</th>
<th>species_id</th>
<th>sex</th>
<th>hindfoot_length</th>
<th>weight</th>
<th>species_id</th>
<th>genus</th>
<th>species</th>
<th>taxa</th>
</tr></thead><tbody><tr class="odd"><td>…</td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
</tr><tr class="even"><td>96</td>
<td>8</td>
<td>20</td>
<td>1997</td>
<td>12</td>
<td><strong>DM</strong></td>
<td>M</td>
<td>36</td>
<td>41</td>
<td><strong>DM</strong></td>
<td>Dipodomys</td>
<td>merriami</td>
<td>Rodent</td>
</tr><tr class="odd"><td>…</td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
</tr></tbody></table><p>Alternatively, we can use the word <code>USING</code>, as a
short-hand. <code>USING</code> only works on columns which share the
same name. In this case we are telling the manager that we want to
combine <code>surveys</code> with <code>species</code> and that the
common column is <code>species_id</code>.</p>
<div class="codewrapper sourceCode" id="cb2">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb2-1"><a href="#cb2-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> <span class="op">*</span></span>
<span id="cb2-2"><a href="#cb2-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys</span>
<span id="cb2-3"><a href="#cb2-3" aria-hidden="true" tabindex="-1"></a><span class="kw">JOIN</span> species</span>
<span id="cb2-4"><a href="#cb2-4" aria-hidden="true" tabindex="-1"></a><span class="kw">USING</span> (species_id);</span></code></pre>
</div>
<p>The output will only have one <strong>species_id</strong> column</p>
<table class="table"><colgroup><col width="5%"><col width="46%"><col width="1%"><col width="5%"><col width="4%"><col width="5%"><col width="1%"><col width="8%"><col width="3%"><col width="5%"><col width="5%"><col width="4%"></colgroup><thead><tr class="header"><th>record_id</th>
<th>month</th>
<th>day</th>
<th>year</th>
<th>plot_id</th>
<th>species_id</th>
<th>sex</th>
<th>hindfoot_length</th>
<th>weight</th>
<th>genus</th>
<th>species</th>
<th>taxa</th>
</tr></thead><tbody><tr class="odd"><td>…</td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
</tr><tr class="even"><td>96</td>
<td>8</td>
<td>20</td>
<td>1997</td>
<td>12</td>
<td>DM</td>
<td>M</td>
<td>36</td>
<td>41</td>
<td>Dipodomys</td>
<td>merriami</td>
<td>Rodent</td>
</tr><tr class="odd"><td>…</td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
<td></td>
</tr></tbody></table><p>We often won’t want all of the fields from both tables, so anywhere
we would have used a field name in a non-join query, we can use
<code>table.colname</code>.</p>
<p>For example, what if we wanted information on when individuals of
each species were captured, but instead of their species ID we wanted
their actual species names.</p>
<div class="codewrapper sourceCode" id="cb3">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb3-1"><a href="#cb3-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> surveys.<span class="dt">year</span>, surveys.<span class="dt">month</span>, surveys.<span class="dt">day</span>, species.genus, species.species</span>
<span id="cb3-2"><a href="#cb3-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys</span>
<span id="cb3-3"><a href="#cb3-3" aria-hidden="true" tabindex="-1"></a><span class="kw">JOIN</span> species</span>
<span id="cb3-4"><a href="#cb3-4" aria-hidden="true" tabindex="-1"></a><span class="kw">ON</span> surveys.species_id <span class="op">=</span> species.species_id;</span></code></pre>
</div>
<table class="table"><colgroup><col width="8%"><col width="73%"><col width="2%"><col width="8%"><col width="7%"></colgroup><thead><tr class="header"><th>year</th>
<th>month</th>
<th>day</th>
<th>genus</th>
<th>species</th>
</tr></thead><tbody><tr class="odd"><td>…</td>
<td></td>
<td></td>
<td></td>
<td></td>
</tr><tr class="even"><td>1977</td>
<td>7</td>
<td>16</td>
<td>Neotoma</td>
<td>albigula</td>
</tr><tr class="odd"><td>1977</td>
<td>7</td>
<td>16</td>
<td>Dipodomys</td>
<td>merriami</td>
</tr><tr class="even"><td>…</td>
<td></td>
<td></td>
<td></td>
<td></td>
</tr></tbody></table><p>Many databases, including SQLite, also support a join through the
<code>WHERE</code> clause of a query.<br>
For example, you may see the query above written without an explicit
JOIN.</p>
<div class="codewrapper sourceCode" id="cb4">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb4-1"><a href="#cb4-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> surveys.<span class="dt">year</span>, surveys.<span class="dt">month</span>, surveys.<span class="dt">day</span>, species.genus, species.species</span>
<span id="cb4-2"><a href="#cb4-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys, species</span>
<span id="cb4-3"><a href="#cb4-3" aria-hidden="true" tabindex="-1"></a><span class="kw">WHERE</span> surveys.species_id <span class="op">=</span> species.species_id;</span></code></pre>
</div>
<p>For the remainder of this lesson, we’ll stick with the explicit use
of the <code>JOIN</code> keyword for joining tables in SQL.</p>
<div id="challenge" class="callout challenge">
<div class="callout-square">
<i class="callout-icon" data-feather="zap"></i>
</div>
<div id="challenge" class="callout-inner">
<h3 class="callout-title">Challenge:<a class="anchor" aria-label="anchor" href="#challenge"></a>
</h3>
<div class="callout-content">
<ul><li>Write a query that returns the genus, the species name, and the
weight of every individual captured at the site</li>
</ul></div>
</div>
</div>
<div id="accordionSolution1" class="accordion challenge-accordion accordion-flush">
<div class="accordion-item">
<button class="accordion-button solution-button collapsed" type="button" data-bs-toggle="collapse" data-bs-target="#collapseSolution1" aria-expanded="false" aria-controls="collapseSolution1">
<h4 class="accordion-header" id="headingSolution1">
Show me the solution
</h4>
</button>
<div id="collapseSolution1" class="accordion-collapse collapse" aria-labelledby="headingSolution1" data-bs-parent="#accordionSolution1">
<div class="accordion-body">
<div class="codewrapper sourceCode" id="cb5">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb5-1"><a href="#cb5-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> species.genus, species.species, surveys.weight</span>
<span id="cb5-2"><a href="#cb5-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys</span>
<span id="cb5-3"><a href="#cb5-3" aria-hidden="true" tabindex="-1"></a><span class="kw">JOIN</span> species</span>
<span id="cb5-4"><a href="#cb5-4" aria-hidden="true" tabindex="-1"></a><span class="kw">ON</span> surveys.species_id <span class="op">=</span> species.species_id;</span></code></pre>
</div>
</div>
</div>
</div>
</div>
<div class="section level3">
<h3 id="different-join-types">Different join types<a class="anchor" aria-label="anchor" href="#different-join-types"></a></h3>
<p>We can count the number of records returned by our original join
query.</p>
<div class="codewrapper sourceCode" id="cb6">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb6-1"><a href="#cb6-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> <span class="fu">COUNT</span>(<span class="op">*</span>)</span>
<span id="cb6-2"><a href="#cb6-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys</span>
<span id="cb6-3"><a href="#cb6-3" aria-hidden="true" tabindex="-1"></a><span class="kw">JOIN</span> species</span>
<span id="cb6-4"><a href="#cb6-4" aria-hidden="true" tabindex="-1"></a><span class="kw">USING</span> (species_id);</span></code></pre>
</div>
<p>Notice that this number is smaller than the number of records present
in the survey data.</p>
<div class="codewrapper sourceCode" id="cb7">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb7-1"><a href="#cb7-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> <span class="fu">COUNT</span>(<span class="op">*</span>) <span class="kw">FROM</span> surveys;</span></code></pre>
</div>
<p>This is because, by default, SQL only returns records where the
joining value is present in the joined columns of both tables (i.e. it
takes the <em>intersection</em> of the two join columns). This joining
behaviour is known as an <code>INNER JOIN</code>. In fact the
<code>JOIN</code> keyword is simply shorthand for
<code>INNER JOIN</code> and the two terms can be used interchangeably as
they will produce the same result.</p>
<p>We can also tell the computer that we wish to keep all the records in
the first table by using a <code>LEFT OUTER JOIN</code> clause, or
<code>LEFT JOIN</code> for short. The difference between the two JOINs
can be visualized like so:</p>
<figure><img src="fig/sql-joins.png" alt="Diagrams representing INNER JOIN and LEFT JOIN each include two overlapping circles labeled A (left) and B (right). For INNER JOIN, the intersection of the two circles is filled in. The associated query is SELECT * FROM A JOIN B ON A.Key = B.Key. For LEFT JOIN, circle A, including its intersection with circle B, is filled in. The associated query is SELECT * FROM A LEFT JOIN B ON A.Key = B.Key." class="figure mx-auto d-block"><figcaption>Diagrams representing INNER JOIN and LEFT JOIN in
SQLite</figcaption></figure><div id="challenge-1" class="callout challenge">
<div class="callout-square">
<i class="callout-icon" data-feather="zap"></i>
</div>
<div id="challenge-1" class="callout-inner">
<h3 class="callout-title">Challenge:<a class="anchor" aria-label="anchor" href="#challenge-1"></a>
</h3>
<div class="callout-content">
<ul><li>Re-write the original query to keep all the entries present in the
<code>surveys</code> table. How many records are returned by this
query?</li>
</ul></div>
</div>
</div>
<div id="accordionSolution2" class="accordion challenge-accordion accordion-flush">
<div class="accordion-item">
<button class="accordion-button solution-button collapsed" type="button" data-bs-toggle="collapse" data-bs-target="#collapseSolution2" aria-expanded="false" aria-controls="collapseSolution2">
<h4 class="accordion-header" id="headingSolution2">
Show me the solution
</h4>
</button>
<div id="collapseSolution2" class="accordion-collapse collapse" aria-labelledby="headingSolution2" data-bs-parent="#accordionSolution2">
<div class="accordion-body">
<div class="codewrapper sourceCode" id="cb8">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb8-1"><a href="#cb8-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> <span class="op">*</span> <span class="kw">FROM</span> surveys</span>
<span id="cb8-2"><a href="#cb8-2" aria-hidden="true" tabindex="-1"></a><span class="kw">LEFT</span> <span class="kw">JOIN</span> species</span>
<span id="cb8-3"><a href="#cb8-3" aria-hidden="true" tabindex="-1"></a><span class="kw">USING</span> (species_id);</span></code></pre>
</div>
</div>
</div>
</div>
</div>
<div id="challenge-2" class="callout challenge">
<div class="callout-square">
<i class="callout-icon" data-feather="zap"></i>
</div>
<div id="challenge-2" class="callout-inner">
<h3 class="callout-title">Challenge:<a class="anchor" aria-label="anchor" href="#challenge-2"></a>
</h3>
<div class="callout-content">
<ul><li>Count the number of records in the <code>surveys</code> table that
have a <code>NULL</code> value in the <code>species_id</code>
column.</li>
</ul></div>
</div>
</div>
<div id="accordionSolution3" class="accordion challenge-accordion accordion-flush">
<div class="accordion-item">
<button class="accordion-button solution-button collapsed" type="button" data-bs-toggle="collapse" data-bs-target="#collapseSolution3" aria-expanded="false" aria-controls="collapseSolution3">
<h4 class="accordion-header" id="headingSolution3">
Show me the solution
</h4>
</button>
<div id="collapseSolution3" class="accordion-collapse collapse" aria-labelledby="headingSolution3" data-bs-parent="#accordionSolution3">
<div class="accordion-body">
<div class="codewrapper sourceCode" id="cb9">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb9-1"><a href="#cb9-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> <span class="fu">COUNT</span>(<span class="op">*</span>)</span>
<span id="cb9-2"><a href="#cb9-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys</span>
<span id="cb9-3"><a href="#cb9-3" aria-hidden="true" tabindex="-1"></a><span class="kw">WHERE</span> species_id <span class="kw">IS</span> <span class="kw">NULL</span>;</span></code></pre>
</div>
</div>
</div>
</div>
</div>
<p>Remember: In SQL a <code>NULL</code> value in one table can never be
joined to a <code>NULL</code> value in a second table because
<code>NULL</code> is not equal to anything, not even itself.</p>
</div>
<div class="section level3">
<h3 id="combining-joins-with-sorting-and-aggregation">Combining joins with sorting and aggregation<a class="anchor" aria-label="anchor" href="#combining-joins-with-sorting-and-aggregation"></a></h3>
<p>Joins can be combined with sorting, filtering, and aggregation. So,
if we wanted average mass of the individuals on each different type of
treatment, we could do something like</p>
<div class="codewrapper sourceCode" id="cb10">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb10-1"><a href="#cb10-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> plots.plot_type, <span class="fu">AVG</span>(surveys.weight)</span>
<span id="cb10-2"><a href="#cb10-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys</span>
<span id="cb10-3"><a href="#cb10-3" aria-hidden="true" tabindex="-1"></a><span class="kw">JOIN</span> plots</span>
<span id="cb10-4"><a href="#cb10-4" aria-hidden="true" tabindex="-1"></a><span class="kw">ON</span> surveys.plot_id <span class="op">=</span> plots.plot_id</span>
<span id="cb10-5"><a href="#cb10-5" aria-hidden="true" tabindex="-1"></a><span class="kw">GROUP</span> <span class="kw">BY</span> plots.plot_type;</span></code></pre>
</div>
<div id="challenge-3" class="callout challenge">
<div class="callout-square">
<i class="callout-icon" data-feather="zap"></i>
</div>
<div id="challenge-3" class="callout-inner">
<h3 class="callout-title">Challenge:<a class="anchor" aria-label="anchor" href="#challenge-3"></a>
</h3>
<div class="callout-content">
<ul><li>Write a query that returns the number of animals caught of each
genus in each plot. Order the results by plot number (ascending) and by
descending number of individuals in each plot.</li>
</ul></div>
</div>
</div>
<div id="accordionSolution4" class="accordion challenge-accordion accordion-flush">
<div class="accordion-item">
<button class="accordion-button solution-button collapsed" type="button" data-bs-toggle="collapse" data-bs-target="#collapseSolution4" aria-expanded="false" aria-controls="collapseSolution4">
<h4 class="accordion-header" id="headingSolution4">
Show me the solution
</h4>
</button>
<div id="collapseSolution4" class="accordion-collapse collapse" aria-labelledby="headingSolution4" data-bs-parent="#accordionSolution4">
<div class="accordion-body">
<div class="codewrapper sourceCode" id="cb11">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb11-1"><a href="#cb11-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> surveys.plot_id, species.genus, <span class="fu">COUNT</span>(<span class="op">*</span>) <span class="kw">AS</span> number_indiv</span>
<span id="cb11-2"><a href="#cb11-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys</span>
<span id="cb11-3"><a href="#cb11-3" aria-hidden="true" tabindex="-1"></a><span class="kw">JOIN</span> species</span>
<span id="cb11-4"><a href="#cb11-4" aria-hidden="true" tabindex="-1"></a><span class="kw">ON</span> surveys.species_id <span class="op">=</span> species.species_id</span>
<span id="cb11-5"><a href="#cb11-5" aria-hidden="true" tabindex="-1"></a><span class="kw">GROUP</span> <span class="kw">BY</span> species.genus, surveys.plot_id</span>
<span id="cb11-6"><a href="#cb11-6" aria-hidden="true" tabindex="-1"></a><span class="kw">ORDER</span> <span class="kw">BY</span> surveys.plot_id <span class="kw">ASC</span>, number_indiv <span class="kw">DESC</span>;</span></code></pre>
</div>
</div>
</div>
</div>
</div>
<div id="challenge-4" class="callout challenge">
<div class="callout-square">
<i class="callout-icon" data-feather="zap"></i>
</div>
<div id="challenge-4" class="callout-inner">
<h3 class="callout-title">Challenge:<a class="anchor" aria-label="anchor" href="#challenge-4"></a>
</h3>
<div class="callout-content">
<ul><li>Write a query that finds the average weight of each rodent species
(i.e., only include species with Rodent in the taxa field).</li>
</ul></div>
</div>
</div>
<div id="accordionSolution5" class="accordion challenge-accordion accordion-flush">
<div class="accordion-item">
<button class="accordion-button solution-button collapsed" type="button" data-bs-toggle="collapse" data-bs-target="#collapseSolution5" aria-expanded="false" aria-controls="collapseSolution5">
<h4 class="accordion-header" id="headingSolution5">
Show me the solution
</h4>
</button>
<div id="collapseSolution5" class="accordion-collapse collapse" aria-labelledby="headingSolution5" data-bs-parent="#accordionSolution5">
<div class="accordion-body">
<div class="codewrapper sourceCode" id="cb12">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb12-1"><a href="#cb12-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> surveys.species_id, <span class="fu">AVG</span>(surveys.weight)</span>
<span id="cb12-2"><a href="#cb12-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys</span>
<span id="cb12-3"><a href="#cb12-3" aria-hidden="true" tabindex="-1"></a><span class="kw">JOIN</span> species</span>
<span id="cb12-4"><a href="#cb12-4" aria-hidden="true" tabindex="-1"></a><span class="kw">ON</span> surveys.species_id <span class="op">=</span> species.species_id</span>
<span id="cb12-5"><a href="#cb12-5" aria-hidden="true" tabindex="-1"></a><span class="kw">WHERE</span> species.taxa <span class="op">=</span> <span class="st">'Rodent'</span></span>
<span id="cb12-6"><a href="#cb12-6" aria-hidden="true" tabindex="-1"></a><span class="kw">GROUP</span> <span class="kw">BY</span> surveys.species_id;</span></code></pre>
</div>
</div>
</div>
</div>
</div>
</div>
</section><section id="functions-coalesce-and-nullif-and-more"><h2 class="section-heading">Functions <code>COALESCE</code> and <code>NULLIF</code> and
more<a class="anchor" aria-label="anchor" href="#functions-coalesce-and-nullif-and-more"></a>
</h2>
<hr class="half-width"><p>SQL includes numerous functions for manipulating data. You’ve already
seen some of these being used for aggregation (<code>SUM</code> and
<code>COUNT</code>) but there are functions that operate on individual
values as well. Probably the most important of these are
<code>COALESCE</code> and <code>NULLIF</code>. <code>COALESCE</code>
allows us to specify a value to use in place of <code>NULL</code>.</p>
<p>We can represent unknown sexes with <code>'U'</code> instead of
<code>NULL</code>:</p>
<div class="codewrapper sourceCode" id="cb13">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb13-1"><a href="#cb13-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> species_id, sex, <span class="fu">COALESCE</span>(sex, <span class="st">'U'</span>)</span>
<span id="cb13-2"><a href="#cb13-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys;</span></code></pre>
</div>
<p>The lone “sex” column is only included in the query above to
illustrate where <code>COALESCE</code> has changed values; this isn’t a
usage requirement.</p>
<div id="challenge-5" class="callout challenge">
<div class="callout-square">
<i class="callout-icon" data-feather="zap"></i>
</div>
<div id="challenge-5" class="callout-inner">
<h3 class="callout-title">Challenge:<a class="anchor" aria-label="anchor" href="#challenge-5"></a>
</h3>
<div class="callout-content">
<ul><li>Write a query that returns 30 instead of <code>NULL</code> for
values in the <code>hindfoot_length</code> column.</li>
</ul></div>
</div>
</div>
<div id="accordionSolution6" class="accordion challenge-accordion accordion-flush">
<div class="accordion-item">
<button class="accordion-button solution-button collapsed" type="button" data-bs-toggle="collapse" data-bs-target="#collapseSolution6" aria-expanded="false" aria-controls="collapseSolution6">
<h4 class="accordion-header" id="headingSolution6">
Show me the solution
</h4>
</button>
<div id="collapseSolution6" class="accordion-collapse collapse" aria-labelledby="headingSolution6" data-bs-parent="#accordionSolution6">
<div class="accordion-body">
<div class="codewrapper sourceCode" id="cb14">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb14-1"><a href="#cb14-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> hindfoot_length, <span class="fu">COALESCE</span>(hindfoot_length, <span class="dv">30</span>)</span>
<span id="cb14-2"><a href="#cb14-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys;</span></code></pre>
</div>
</div>
</div>
</div>
</div>
<div id="challenge-6" class="callout challenge">
<div class="callout-square">
<i class="callout-icon" data-feather="zap"></i>
</div>
<div id="challenge-6" class="callout-inner">
<h3 class="callout-title">Challenge:<a class="anchor" aria-label="anchor" href="#challenge-6"></a>
</h3>
<div class="callout-content">
<ul><li>Write a query that calculates the average hind-foot length of each
species, assuming that unknown lengths are 30 (as above).</li>
</ul></div>
</div>
</div>
<div id="accordionSolution7" class="accordion challenge-accordion accordion-flush">
<div class="accordion-item">
<button class="accordion-button solution-button collapsed" type="button" data-bs-toggle="collapse" data-bs-target="#collapseSolution7" aria-expanded="false" aria-controls="collapseSolution7">
<h4 class="accordion-header" id="headingSolution7">
Show me the solution
</h4>
</button>
<div id="collapseSolution7" class="accordion-collapse collapse" aria-labelledby="headingSolution7" data-bs-parent="#accordionSolution7">
<div class="accordion-body">
<div class="codewrapper sourceCode" id="cb15">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb15-1"><a href="#cb15-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> species_id, <span class="fu">AVG</span>(<span class="fu">COALESCE</span>(hindfoot_length, <span class="dv">30</span>))</span>
<span id="cb15-2"><a href="#cb15-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys</span>
<span id="cb15-3"><a href="#cb15-3" aria-hidden="true" tabindex="-1"></a><span class="kw">GROUP</span> <span class="kw">BY</span> species_id;</span></code></pre>
</div>
</div>
</div>
</div>
</div>
<p><code>COALESCE</code> can be particularly useful in
<code>JOIN</code>. When joining the <code>species</code> and
<code>surveys</code> tables earlier, some results were excluded because
the <code>species_id</code> was <code>NULL</code> in the surveys table.
We can use <code>COALESCE</code> to include them again, re-writing the
<code>NULL</code> to a valid joining value:</p>
<div class="codewrapper sourceCode" id="cb16">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb16-1"><a href="#cb16-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> surveys.<span class="dt">year</span>, surveys.<span class="dt">month</span>, surveys.<span class="dt">day</span>, species.genus, species.species</span>
<span id="cb16-2"><a href="#cb16-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys</span>
<span id="cb16-3"><a href="#cb16-3" aria-hidden="true" tabindex="-1"></a><span class="kw">JOIN</span> species</span>
<span id="cb16-4"><a href="#cb16-4" aria-hidden="true" tabindex="-1"></a><span class="kw">ON</span> <span class="fu">COALESCE</span>(surveys.species_id, <span class="st">'AB'</span>) <span class="op">=</span> species.species_id;</span></code></pre>
</div>
<div id="challenge-7" class="callout challenge">
<div class="callout-square">
<i class="callout-icon" data-feather="zap"></i>
</div>
<div id="challenge-7" class="callout-inner">
<h3 class="callout-title">Challenge:<a class="anchor" aria-label="anchor" href="#challenge-7"></a>
</h3>
<div class="callout-content">
<ul><li>Write a query that returns the number of animals caught of each
genus in each plot, assuming that unknown species are all of the genus
“Rodent”.</li>
</ul></div>
</div>
</div>
<div id="accordionSolution8" class="accordion challenge-accordion accordion-flush">
<div class="accordion-item">
<button class="accordion-button solution-button collapsed" type="button" data-bs-toggle="collapse" data-bs-target="#collapseSolution8" aria-expanded="false" aria-controls="collapseSolution8">
<h4 class="accordion-header" id="headingSolution8">
Show me the solution
</h4>
</button>
<div id="collapseSolution8" class="accordion-collapse collapse" aria-labelledby="headingSolution8" data-bs-parent="#accordionSolution8">
<div class="accordion-body">
<div class="codewrapper sourceCode" id="cb17">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb17-1"><a href="#cb17-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> plot_id, <span class="fu">COALESCE</span>(genus, <span class="st">'Rodent'</span>) <span class="kw">AS</span> genus2, <span class="fu">COUNT</span>(<span class="op">*</span>)</span>
<span id="cb17-2"><a href="#cb17-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys </span>
<span id="cb17-3"><a href="#cb17-3" aria-hidden="true" tabindex="-1"></a><span class="kw">LEFT</span> <span class="kw">JOIN</span> species</span>
<span id="cb17-4"><a href="#cb17-4" aria-hidden="true" tabindex="-1"></a><span class="kw">ON</span> surveys.species_id<span class="op">=</span>species.species_id</span>
<span id="cb17-5"><a href="#cb17-5" aria-hidden="true" tabindex="-1"></a><span class="kw">GROUP</span> <span class="kw">BY</span> plot_id, genus2;</span></code></pre>
</div>
</div>
</div>
</div>
</div>
<p>The inverse of <code>COALESCE</code> is <code>NULLIF</code>. This
returns <code>NULL</code> if the first argument is equal to the second
argument. If the two are not equal, the first argument is returned. This
is useful for “nulling out” specific values.</p>
<p>We can “null out” plot 7:</p>
<div class="codewrapper sourceCode" id="cb18">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb18-1"><a href="#cb18-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> species_id, plot_id, <span class="fu">NULLIF</span>(plot_id, <span class="dv">7</span>)</span>
<span id="cb18-2"><a href="#cb18-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys;</span></code></pre>
</div>
<p>Some more functions which are common to SQL databases are listed in
the table below:</p>
<table class="table"><colgroup><col width="10%"><col width="89%"></colgroup><thead><tr class="header"><th>Function</th>
<th>Description</th>
</tr></thead><tbody><tr class="odd"><td><code>ABS(n)</code></td>
<td>Returns the absolute (positive) value of the numeric expression
<em>n</em>
</td>
</tr><tr class="even"><td><code>COALESCE(x1, ..., xN)</code></td>
<td>Returns the first of its parameters that is not NULL</td>
</tr><tr class="odd"><td><code>LENGTH(s)</code></td>
<td>Returns the length of the string expression <em>s</em>
</td>
</tr><tr class="even"><td><code>LOWER(s)</code></td>
<td>Returns the string expression <em>s</em> converted to lowercase</td>
</tr><tr class="odd"><td><code>NULLIF(x, y)</code></td>
<td>Returns NULL if <em>x</em> is equal to <em>y</em>, otherwise returns
<em>x</em>
</td>
</tr><tr class="even"><td>
<code>ROUND(n)</code> or <code>ROUND(n, x)</code>
</td>
<td>Returns the numeric expression <em>n</em> rounded to <em>x</em>
digits after the decimal point (0 by default)</td>
</tr><tr class="odd"><td><code>TRIM(s)</code></td>
<td>Returns the string expression <em>s</em> without leading and
trailing whitespace characters</td>
</tr><tr class="even"><td><code>UPPER(s)</code></td>
<td>Returns the string expression <em>s</em> converted to uppercase</td>
</tr></tbody></table><p>Finally, some useful functions which are particular to SQLite are
listed in the table below:</p>
<table class="table"><colgroup><col width="10%"><col width="89%"></colgroup><thead><tr class="header"><th>Function</th>
<th>Description</th>
</tr></thead><tbody><tr class="odd"><td><code>RANDOM()</code></td>
<td>Returns a random integer between -9223372036854775808 and
+9223372036854775807.</td>
</tr><tr class="even"><td><code>REPLACE(s, f, r)</code></td>
<td>Returns the string expression <em>s</em> in which every occurrence
of <em>f</em> has been replaced with <em>r</em>
</td>
</tr><tr class="odd"><td>
<code>SUBSTR(s, x, y)</code> or <code>SUBSTR(s, x)</code>
</td>
<td>Returns the portion of the string expression <em>s</em> starting at
the character position <em>x</em> (leftmost position is 1), <em>y</em>
characters long (or to the end of <em>s</em> if <em>y</em> is
omitted)</td>
</tr></tbody></table><div id="challenge-8" class="callout challenge">
<div class="callout-square">
<i class="callout-icon" data-feather="zap"></i>
</div>
<div id="challenge-8" class="callout-inner">
<h3 class="callout-title">Challenge:<a class="anchor" aria-label="anchor" href="#challenge-8"></a>
</h3>
<div class="callout-content">
<p>Write a query that returns genus names (no repeats), sorted from
longest genus name down to shortest.</p>
</div>
</div>
</div>
<div id="accordionSolution9" class="accordion challenge-accordion accordion-flush">
<div class="accordion-item">
<button class="accordion-button solution-button collapsed" type="button" data-bs-toggle="collapse" data-bs-target="#collapseSolution9" aria-expanded="false" aria-controls="collapseSolution9">
<h4 class="accordion-header" id="headingSolution9">
Show me the solution
</h4>
</button>
<div id="collapseSolution9" class="accordion-collapse collapse" aria-labelledby="headingSolution9" data-bs-parent="#accordionSolution9">
<div class="accordion-body">
<div class="codewrapper sourceCode" id="cb19">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb19-1"><a href="#cb19-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> <span class="kw">DISTINCT</span> genus</span>
<span id="cb19-2"><a href="#cb19-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> species</span>
<span id="cb19-3"><a href="#cb19-3" aria-hidden="true" tabindex="-1"></a><span class="kw">ORDER</span> <span class="kw">BY</span> <span class="fu">LENGTH</span>(genus) <span class="kw">DESC</span>;</span></code></pre>
</div>
</div>
</div>
</div>
</div>
<p>As we saw before, aliases make things clearer, and are especially
useful when joining tables.</p>
<div class="codewrapper sourceCode" id="cb20">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb20-1"><a href="#cb20-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> surv.<span class="dt">year</span> <span class="kw">AS</span> yr, surv.<span class="dt">month</span> <span class="kw">AS</span> mo, surv.<span class="dt">day</span> <span class="kw">AS</span> <span class="dt">day</span>, sp.genus <span class="kw">AS</span> gen, sp.species <span class="kw">AS</span> sp</span>
<span id="cb20-2"><a href="#cb20-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys <span class="kw">AS</span> surv</span>
<span id="cb20-3"><a href="#cb20-3" aria-hidden="true" tabindex="-1"></a><span class="kw">JOIN</span> species <span class="kw">AS</span> sp</span>
<span id="cb20-4"><a href="#cb20-4" aria-hidden="true" tabindex="-1"></a><span class="kw">ON</span> surv.species_id <span class="op">=</span> sp.species_id;</span></code></pre>
</div>
<p>To practice we have some optional challenges for you.</p>
<div id="challenge-optional" class="callout challenge">
<div class="callout-square">
<i class="callout-icon" data-feather="zap"></i>
</div>
<div id="challenge-optional" class="callout-inner">
<h3 class="callout-title">Challenge (optional):<a class="anchor" aria-label="anchor" href="#challenge-optional"></a>
</h3>
<div class="callout-content">
<p>SQL queries help us <em>ask</em> specific <em>questions</em> which we
want to answer about our data. The real skill with SQL is to know how to
translate our scientific questions into a sensible SQL query (and
subsequently visualize and interpret our results).</p>
<p>Have a look at the following questions; these questions are written
in plain English. Can you translate them to <em>SQL queries</em> and
give a suitable answer?</p>
<ol style="list-style-type: decimal"><li><p>How many plots from each type are there?</p></li>
<li><p>How many specimens are of each sex are there for each year,
including those whose sex is unknown?</p></li>
<li><p>How many specimens of each species were captured in each type of
plot, excluding specimens of unknown species?</p></li>
<li><p>What is the average weight of each taxa?</p></li>
<li><p>What are the minimum, maximum and average weight for each species
of Rodent?</p></li>
<li><p>What is the average hindfoot length for male and female rodent of
each species? Is there a Male / Female difference?</p></li>
<li><p>What is the average weight of each rodent species over the course
of the years? Is there any noticeable trend for any of the
species?</p></li>
</ol></div>
</div>
</div>
<div id="accordionSolution10" class="accordion challenge-accordion accordion-flush">
<div class="accordion-item">
<button class="accordion-button solution-button collapsed" type="button" data-bs-toggle="collapse" data-bs-target="#collapseSolution10" aria-expanded="false" aria-controls="collapseSolution10">
<h4 class="accordion-header" id="headingSolution10">
Proposed solutions:
</h4>
</button>
<div id="collapseSolution10" class="accordion-collapse collapse" aria-labelledby="headingSolution10" data-bs-parent="#accordionSolution10">
<div class="accordion-body">
<ol style="list-style-type: decimal"><li>Solution:</li>
</ol><div class="codewrapper sourceCode" id="cb21">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb21-1"><a href="#cb21-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> plot_type, <span class="fu">COUNT</span>(<span class="op">*</span>) <span class="kw">AS</span> num_plots</span>
<span id="cb21-2"><a href="#cb21-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> plots</span>
<span id="cb21-3"><a href="#cb21-3" aria-hidden="true" tabindex="-1"></a><span class="kw">GROUP</span> <span class="kw">BY</span> plot_type;</span></code></pre>
</div>
<ol start="2" style="list-style-type: decimal"><li>Solution:</li>
</ol><div class="codewrapper sourceCode" id="cb22">
<h3 class="code-label">SQL<i aria-hidden="true" data-feather="chevron-left"></i><i aria-hidden="true" data-feather="chevron-right"></i>
</h3>
<pre class="sourceCode sql" tabindex="0"><code class="sourceCode sql"><span id="cb22-1"><a href="#cb22-1" aria-hidden="true" tabindex="-1"></a><span class="kw">SELECT</span> <span class="dt">year</span>, sex, <span class="fu">COUNT</span>(<span class="op">*</span>) <span class="kw">AS</span> num_animal</span>
<span id="cb22-2"><a href="#cb22-2" aria-hidden="true" tabindex="-1"></a><span class="kw">FROM</span> surveys</span>
<span id="cb22-3"><a href="#cb22-3" aria-hidden="true" tabindex="-1"></a><span class="kw">GROUP</span> <span class="kw">BY</span> sex, <span class="dt">year</span>;</span></code></pre>
</div>