-
Notifications
You must be signed in to change notification settings - Fork 92
/
Copy pathouter-joins.html
1440 lines (1219 loc) · 40.5 KB
/
outer-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
<!-- @(#)$Id: outer-joins.html,v 1.7 2017/11/13 20:11:36 jleffler Exp $ -->
<HTML>
<HEAD>
<TITLE> Informix Outer Joins </TITLE>
</HEAD>
<BODY BGCOLOR="#CCCCCC">
<H1 ALIGN=CENTER> Informix Outer Joins </H1>
This document contains two ancient appendixes describing Informix outer joins,
along with some commentary.
<P>
<A HREF="#version1"> Version 1.10 </A>
<BR>
<A HREF="#version4"> Version 4.0 </A>
<BR>
<A HREF="#commentary"> Commentary </A>
</P>
<P>
The Spring 1987 issue of Informix's Tech Notes had an article on Outer
Joins. The content of that article is the basis of the version 4.0
appendix with minimal changes for the altered context, such as omitting
a reference to the next article in the Tech Notes which was on query
optimization.
</P>
<HR SIZE=4>
<A NAME="version1"></A>
<H1 ALIGN=CENTER> Appendix G, Informix-4GL Reference Manual </H1>
<H1 ALIGN=CENTER> Version 1.10 </H1>
<H1 ALIGN=CENTER> COMPLEX OUTER JOINS </H1>
<SMALL> <I>
Jonathan Leffler comments:
</I> </SMALL>
<P>
This is a transcription and translation into HTML of an ancient
document, namely Appendix G (Complex Outer Joins) from the Informix-4GL
Reference Manual, Vol 2, Version 1.10 (part number 200-507-0002-0, dated
July 1988). It is referring to Informix's OUTER construct, not the ISO
9075:1992 SQL standard construct with the same name but a radically
different syntax. The ISO (ANSI) outer join notation is available IDS
7.31 and in IDS.2000 9.21. Also, the document uses the term RDSQL to
refer to the database server. The original version of this document
dates back to the days before SE and Turbo were separate products, when
you bought Informix-4GL or Informix-SQL and the database process,
sqlexec (which became the core of SE) was simply an important part of
the base product.
</P>
<SMALL> <I>
End commentary
</I> </SMALL>
<HR>
<H2> Complex Outer Joins </H2>
When more than two table participate in an outer join, there are many
ways in which to relate them. For three tables, there are five
logically distinct joins, of which four involve outer joins. These
distinct outer joins are listed later in this appendix, using the
notation to be used in SELECT statements and a graphic notation that can
be generalized for any number of tables. The detailed rules for the
graphic representation are located at the end of this section. Briefly,
the subservient tables are placed on a lower level than dominant tables.
<P>
The two-table outer join described in Chapter 2 <i>[of the I4GL
Reference Manual, Volume 1]</i> is graphically represented as follows:
</P>
<HR WIDTH=80%>
<CODE><PRE>
SELECT a, b
FROM tab1, OUTER tab2
WHERE a = b
<I>Diagram</I>
tab1 -------@ Level 1
|
tab2 Level 2
</PRE></CODE>
<HR WIDTH=80%>
<P>
In the examples that follow, the tilde (~) symbol represents any Boolean
relation between the columns of two tables.
</P>
<H3> Example 1 </H3>
<HR WIDTH=80%>
<CODE><PRE>
FROM x, y, z
WHERE ...
<I>Diagram</I>
x ---- y ---- z Level 1
</PRE></CODE>
<HR WIDTH=80%>
<P>
This is the standard inner join and all three tables are treated on the
same level. There are no restrictions on the WHERE clause. It need not
exist. Before the WHERE clause is applied, a full Cartesian product is
made among all three tables. (<B>Note</b>: A Cartesian product of two
tables appends every row of the second table to every row of the first.
A Cartesian product of three tables is the Cartesian product of the
third with the Cartesian product of the first two, and so on.)
</P>
<H3> Example 2 </H3>
<HR WIDTH=80%>
<CODE><PRE>
FROM x, y, OUTER z
WHERE (x or y) ~ z
<I>Diagram</I>
x ---- y -----@ Level 1
|
z Level 2
</PRE></CODE>
<HR WIDTH=80%>
Example 2 illustrates the simplest extension of the outer join from two
tables to three tables. <b>x</b> and <b>y</b> are joined at the same
level and are shown connected together. <b>z</b> is the subservient
table and is placed down one level. The WHERE clause must relate a
Level 1 table with a Level 2 table. Other relationships are also
permitted. Before the WHERE clause is applied, RDSQL takes the
cartesian product of <b>x</b> and <b>y</b> and then takes the outer join
of the result with z. <b>x</b>
<H3> Example 3 </H3>
<HR WIDTH=80%>
<CODE><PRE>
FROM x, OUTER y, OUTER z
WHERE x ~ y AND x ~ z
<I>Diagram</I>
x -----@------@ Level 1
| |
y z Level 2
</PRE></CODE>
<HR WIDTH=80%>
Although both <b>y</b> and <b>z</b> are at the same level, they are not
connected. Here, a relationship is required between <b>x</b> and
<b>y</b> and also between <b>x</b> and <b>z</b>. No relationship is
permitted between <b>y</b> and <b>z</b> since they are not connected at
the second level. The outer join is performed between <b>x</b> and
<b>y</b> and then the outer join between the resulting table and
<b>z</b>.
<H3> Example 4 </H3>
<HR WIDTH=80%>
<CODE><PRE>
FROM x, OUTER (y, z)
WHERE x ~ (y or z)
<I>Diagram</I>
x -----@ Level 1
|
y ---- z Level 2
</PRE></CODE>
<HR WIDTH=80%>
In Example 4, a relationship is required between <b>x</b> and either
<b>y</b> or <b>z</b> or both. In addition, there may be a relationship
between <b>y</b> and <b>z</b> since they are connected at the second
level. To perform this join, RDSQL starts at the top and works down.
For each row of <b>x</b>, RDSQL attempts to find a row of <b>y</b> that
satisfies the WHERE clause. If none is found, RDSQL substitutes NULL
values for the columns of <b>y</b> and <b>z</b>. If a row of <b>y</b>
satisfies the WHERE clause, RDSQL seeks a row of <b>z</b> that satisfies
the WHERE clause. It substitutes NULL values for both <b>y</b> and
<b>z</b> if no row in <b>z</b> is found.
<H3> Example 5 </H3>
<HR WIDTH=80%>
<CODE><PRE>
FROM x, OUTER (y, OUTER z)
WHERE x ~ y AND y ~ z
<I>Diagram</I>
x -----@ Level 1
|
y -----@ Level 2
|
z Level 3
</PRE></CODE>
<HR WIDTH=80%>
<P>
Example 5 shows a three-level outer join. There must always be a
relationship between adjacent levels. In this case, <b>x</b> must be
related to <b>y</b>, and <b>y</b> must be related to <b>z</b>. RDSQL
performs this join by picking a row from <b>x</b> and looking for a pair
from <b>y</b> and <b>z</b> that satisfies (<b>y</b>, outer <b>z</b>).
</P>
<H2> Output from Examples </H2>
<P>
If each of the tables consists of a single column with the values in the
followin table, then the previously described joins will result in the
subsequent tables.
<HR WIDTH=80%>
<CODE><PRE>
x.a y.b z.c
1 2 3
2 3 4
3 4 5
5
</PRE></CODE>
<HR WIDTH=80%>
<H3> Example 1 </H3>
<HR WIDTH=80%>
<CODE><PRE>
FROM x, y, z
WHERE x.a = z.c
</PRE></CODE>
<CODE><PRE>
a b c
3 2 3
3 3 3
3 4 3
5 2 5
5 3 5
5 4 5
</PRE></CODE>
<P>
<SMALL><I>
[JL: this example, and several of the following ones, has a Cartesian
product of table <b>y</b> with the join of tables <b>x</b> and
<b>z</b>.]
</I></SMALL>
</P>
<HR WIDTH=80%>
<H3> Example 2 </H3>
<HR WIDTH=80%>
<CODE><PRE>
FROM x, y, OUTER z
WHERE x.a = z.c
</PRE></CODE>
<CODE><PRE>
a b c
1 2 -
1 3 -
1 4 -
2 2 -
2 3 -
2 4 -
3 2 3
3 3 3
3 4 3
5 2 5
5 3 5
5 4 5
</PRE></CODE>
<HR WIDTH=80%>
<H3> Example 3 </H3>
<HR WIDTH=80%>
<CODE><PRE>
FROM x, OUTER y, OUTER z
WHERE x.a = y.b AND x.a = z.c
</PRE></CODE>
<CODE><PRE>
a b c
1 - -
2 2 -
3 3 3
5 - 5
</PRE></CODE>
<HR WIDTH=80%>
<H3> Example 4 </H3>
<HR WIDTH=80%>
<CODE><PRE>
FROM x, OUTER (y, z)
WHERE x.a = z.c
</PRE></CODE>
<CODE><PRE>
a b c
1 - -
2 - -
3 2 3
3 3 3
3 4 3
5 2 5
5 3 5
5 4 5
</PRE></CODE>
<HR WIDTH=80%>
<H3> Example 5 </H3>
<HR WIDTH=80%>
<CODE><PRE>
FROM x, OUTER (y, OUTER z)
WHERE x.a = y.b AND y.b = z.c
</PRE></CODE>
<CODE><PRE>
a b c
1 - -
2 2 -
3 3 3
5 - -
</PRE></CODE>
<HR WIDTH=80%>
<P>
The following steps are useful when considering how RDSQL performs an outer join:
<OL>
<LI>
Draw the graph corresponding to the FROM clause. Replace each keyword
OUTER with the symbol @ and put the table names to which the keyword
applies in the next lower level.
<LI>
Ensure that a condition exists in the WHERE clause relating a table on
each level through each @ to a table in the next level below.
<LI>
Form a Cartesian product of all tables connected on the same level,
applying whichever conditions of the WHERE clause apply only to that
level.
<LI>
Starting with the first level, take a row at a time from the resulting
table and attempt to satisfy the WHERE clause with the resulting table
of the next lower level, replacing the columns of the lower-level table
with NULL values if the WHERE clause cannot be satisfied.
</OL>
As an example, the following FROM clause results in the accompanying graph:
<HR WIDTH=80%>
<CODE><PRE>
FROM x, OUTER (y, OUTER (z, a, b)), outer c, d
</PRE></CODE>
<CODE><PRE>
x -----@-------------@----- d Level 1
| |
y ---- @ c Level 2
|
z ---- a ---- b Level 3
</PRE></CODE>
<HR WIDTH=80%>
A Cartesian product is made between <b>x</b> and <b>d</b> (call it
<b>txd</b>) and between <b>z</b>, <b>a</b> and <b>b</b> (call it
<b>tzab</b>), since these sets of tables are connected on the same
level. <b>y</b> and <b>c</b> are both on Level 2, but they are not
connected on that level. For each row of <b>txd</b>, RDSQL attempts to
find a row of <b>y</b> that satisfies the WHERE clause. If it succeeds,
it searches for a row of <b>tzab</b> that satisfies the WHERE clause.
In both cases, NULL values are substituted if no satisfactory row is
found. RDSQL then searches for a row of <b>c</b> that satisfies the
WHERE clause, substituting NULL values if unsuccessful.
<P>
<HR WIDTH=80%>
<CENTER>
<SMALL> <I>
This is the end of Appendix G in the 1.10 manual.
</I> </SMALL>
</CENTER>
<HR SIZE=4>
<A NAME="version4"></A>
<H1 ALIGN=CENTER> Appendix G, Informix-4GL Reference Manual </H1>
<H1 ALIGN=CENTER> Version 4.0 </H1>
<H1 ALIGN=CENTER> OUTER JOINS </H1>
<SMALL> <I>
Jonathan Leffler comments:
</I> </SMALL>
<P>
This is a transcription and translation into HTML of an ancient
document, namely Appendix G (Outer Joins) from the Informix-4GL
Reference Manual, Vol 2, Version 4.0 (part number 000-7405, dated March
1990). It is referring to Informix's OUTER construct, not the ISO
9075:1992 SQL standard construct with the same name but a radically
different syntax. The ISO (ANSI) outer join notation is understood in
IDS 7.31 and in IDS.2000 9.21. Note that the document uses the term
'4GL' to refer to the database server.
</P>
<SMALL> <I>
End commentary
</I> </SMALL>
<HR>
<H2> Outer Joins </H2>
This appendix discusses the difference between a simple join and an
outer join, and describes in detail how outer joins work. The following
SELECT statements illustrate the basic difference between the two types
of join.
<HR WIDTH=80%>
<H3> Query 1 - Using a Simple Join </H3>
<HR WIDTH=80%>
<CODE><PRE>
SELECT customer.customer_num, lname, order_num
FROM customer, orders
WHERE customer.customer_num = orders.order_num
</PRE></CODE>
<H3> Query 2 - Using an Outer Join </H3>
<CODE><PRE>
SELECT customer.customer_num, lname, order_num
FROM customer, OUTER orders
WHERE customer.customer_num = orders.customer_num
</PRE></CODE>
<HR WIDTH=80%>
Both query the same tables (<B>customer</b> and <B>orders</B>) of the
same database (<B>stores</B>) through a join on the same column
(<B>customer_num</B>). At first glance, both fetch the same data. The
query results, however, are quote different, as the following
illustration shows.
<P>
<SMALL><I>
Query Results from Stores7 Database Generated on Solaris 7 with IDS.2000 9.20.UC2.
</I></SMALL>
</P>
<HR WIDTH=80%>
<CODE><PRE>
Query 1 Results
104 Higgins 1001
101 Pauli 1002
104 Higgins 1003
106 Watson 1004
116 Parmelee 1005
112 Lawson 1006
117 Sipes 1007
110 Jaeger 1008
111 Keyes 1009
115 Grant 1010
104 Higgins 1011
117 Sipes 1012
104 Higgins 1013
106 Watson 1014
110 Jaeger 1015
119 Shorter 1016
120 Jewell 1017
121 Wallack 1018
122 O'Brian 1019
123 Hanlon 1020
124 Putnum 1021
126 Neelie 1022
127 Satifer 1023
Query 2 Results
customer_num lname order_num
101 Pauli 1002
102 Sadler
103 Currie
104 Higgins 1001
104 Higgins 1003
104 Higgins 1011
104 Higgins 1013
105 Vector
106 Watson 1004
106 Watson 1014
107 Ream
108 Quinn
109 Miller
110 Jaeger 1008
110 Jaeger 1015
111 Keyes 1009
112 Lawson 1006
113 Beatty
114 Albertson
115 Grant 1010
116 Parmelee 1005
117 Sipes 1007
117 Sipes 1012
118 Baxter
119 Shorter 1016
120 Jewell 1017
121 Wallack 1018
122 O'Brian 1019
123 Hanlon 1020
124 Putnum 1021
125 Henry
126 Neelie 1022
127 Satifer 1023
128 Lessor
</PRE></CODE>
<P>
By using a <I>simple join</i>, Query 1 fetches a list of only those
customers who have items on order, while Query 2 fetches a list of all
customers by using an <i>outer</i> join. Once you understand how
similar queries can produce such dissimilar results, you can begin to
use outer joins effectively. The obvious differences between the two
joins are as follows:
</P>
<P>
<BL>
<LI>
A <i>simple join</i> discards all rows that do not satisfy the join condition.
<LI>
An <i>outer join</i> preserves rows that would otherwise be discarded.
</BL>
</P>
<P>
The following section discusses outer joins in detail.
</P>
<H2> How Outer Joins Work </H2>
<P>
A join queries two or more tables as though they were one. It is as if
4GL creates and then acts upon a single temporary table to produce the
query results. 4GL does not actually create such a table to perform a
join, but it is helpful to conceptualize a join in these terms.
</P>
<P>
In a simple two-table join, the resulting "table" contains only those
combinations of rows from both tables that satisfy the join condition.
In an outer join, the resulting "table" contains these rows, plus all
the remaining rows from on of the tables, called the dominant (or
preserved) table. The second table is called the subservient table.
</P>
<P>
Consider two hypothetical tables, <B>employees</B> and <B>depts</B>,
which contain the following columns and rows (where dash '--' indicates
a NULL value):
</P>
<CODE><PRE>
employees
emp_num dept_num
2 105
4 103
6 103
5 --
3 102
depts
depts_num dept_loc
102 NY
103 LA
105 SF
</PRE></CODE>
<P>
Suppose, for example, that you need a list of employee numbers and
department locations for all employees, including those employees whose department locations are unknown
(represented by NULL values in the <B>employees</B> table). The following query fetches the desired results:
</P>
<HR WIDTH=80%>
<CODE><PRE>
SELECT emp_num, dept_loc
FROM employees, OUTER depts
WHERE employees.dept_num = depts.dept_num
</PRE></CODE>
<HR WIDTH=80%>
<P>
The keyword OUTER designates <b>depts</b> as the subservient table,
making <B>employees</B> the dominant table. 4GL processes the query by
the following steps:
<OL>
<LI>
4GL applies filters to the subservient table while sequentially applying
the join condition to the rows of the dominant table. Rows in the
dominant table are retrieved without considering the join, but rows from
the subservient table (outer table) are retrieved only if they satisfy
the join condition. Any dominant-table rows that do not have a matching
row from the subservient table receive a row of NULL values in place of
a subservient-table row.
</P>
<P>
The result is a "table" with the following rows:
</P>
<CODE><PRE>
emp_num dept_num dept_num dept_loc
2 105 105 SF
4 103 103 LA
6 103 103 LA
5 -- -- --
3 102 102 NY
</PRE></CODE>
<P>
Note: A <i>filter</i> is a condition expressed in a WHERE clause that
applies to columns in a single table. For example,
</P>
<CODE><PRE>
dept_loc = "SF" <i>or</i> emp_num < 105
</PRE></CODE>
<P>
Because 4GL applies such filters to the subservient table as it performs
the join, the resulting "table" may contain NULL values that were not
present in the subservient table prior to the join.
</P>
<P>
Suppose that the query include a filter on the <b>dept_loc</b> column:
</P>
<HR WIDTH=80%>
<CODE><PRE>
SELECT emp_num, dept_loc
FROM employees, OUTER depts
WHERE employees.dept_num = depts.dept_num
AND dept_loc != "LA"
</PRE></CODE>
<HR WIDTH=80%>
<P>
At step 2, the results include more rows of NULL values than the results
of the original query:
</P>
<CODE><PRE>
emp_num dept_loc
2 SF
4 --
6 --
5 --
3 NY
</PRE></CODE>
<P>
The filter removes rows from the <b>depts</b> table where
<b>dept_loc</b> is equal to "LA".
<LI>
After performing the join, 4Gl applies filters to the dominant table (if
they exist).
<LI>
4GL applies the SELECT clause to eliminate unneeded columns, and the
query returns the results:
<CODE><PRE>
emp_num dept_loc
2 SF
4 LA
6 LA
5
3 NY
</PRE></CODE>
<P>
<SMALL><I>
The original version listed the <b>emp_num</b> values in numeric order
without any sorting. IDS.2000 does not do this.
</I></SMALL>
</OL>
<P>
In a similar way to the previous example, the following query produces a
list of all customers with supplemental information for those customers
with items on orders. Where <b>orders.customer_num</b> is not equal to
<b>customer.customer_num</b>, 4GL combines a row of NULL values with the
corresponding row from the <b>customer</b> table. Because the query
does not contain filters, the results preserve every row from the
dominant table.
</P>
<H3> Query 3 </H3>
<HR WIDTH=80%>
<CODE><PRE>
SELECT customer.customer_num, company, order_num, ship_date
FROM customer, OUTER orders
WHERE customer.customer_num = orders.customer_num
</PRE></CODE>
<HR WIDTH=80%>
<H3> Query 3 Results </H3>
<CODE><PRE>
customer_num company order_num ship_date
101 All Sports Supplies 1002 26/05/1998
102 Sports Spot
103 Phil's Sports
104 Play Ball! 1001 01/06/1998
104 Play Ball! 1003 23/05/1998
104 Play Ball! 1011 03/07/1998
104 Play Ball! 1013 10/07/1998
105 Los Altos Sports
106 Watson & Son 1004 30/05/1998
106 Watson & Son 1014 03/07/1998
107 Athletic Supplies
108 Quinn's Sports
109 Sport Stuff
110 AA Athletics 1008 06/07/1998
110 AA Athletics 1015 16/07/1998
111 Sports Center 1009 21/06/1998
112 Runners & Others 1006
113 Sportstown
114 Sporting Place
115 Gold Medal Sports 1010 29/06/1998
116 Olympic City 1005 09/06/1998
117 Kids Korner 1007 05/06/1998
117 Kids Korner 1012 29/06/1998
118 Blue Ribbon Sports
119 The Triathletes Club 1016 12/07/1998
120 Century Pro Shop 1017 13/07/1998
121 City Sports 1018 13/07/1998
122 The Sporting Life 1019 16/07/1998
123 Bay Sports 1020 16/07/1998
124 Putnum's Putters 1021 25/07/1998
125 Total Fitness Sports
126 Neelie's Discount Sp 1022 30/07/1998
127 Big Blue Bike Shop 1023 30/07/1998
128 Phoenix University
</PRE></CODE>
<P>
The preceeding example queries two tables in the simplest type of outer
join. You can, in fact, use outer joins to query any number of tables,
producing more types of joins than can be discussed here. The following
types are possible when three tables are involved in a query:
</P>
<BL>
<LI>
You can outer-join the result of a simple join to a third table.
<HR WIDTH=80%>
<CODE><PRE>
SELECT <i>column-list</i>
FROM x, OUTER (y, z)
WHERE x.a = y.a
AND y.b = z.b
</PRE></CODE>
<HR WIDTH=80%>
<A HREF="#query4">Query 4</A> performs this kind of join. (See the
sections "Examples" later in this chapter.)
</LI>
<LI>
You can outer-join the result of an outer join to a third table.
<HR WIDTH=80%>
<CODE><PRE>
SELECT <i>column-list</i>
FROM x, OUTER (y, OUTER z)
WHERE x.a = y.a
AND y.b = z.b
</PRE></CODE>
<HR WIDTH=80%>
or
<HR WIDTH=80%>
<CODE><PRE>
SELECT <i>column-list</i>
FROM x, OUTER (y, OUTER z)
WHERE x.a = z.a <i>-- different join here!</i>
AND y.b = z.b
</PRE></CODE>
<HR WIDTH=80%>
<A HREF="#query5">Query 5</A> and
<A HREF="#query6">Query 6</A>
perform this kind of join. (See the sections "Examples" later in this chapter.)
</LI>
<LI>
You can outer-join two tables individually to a third tables, in which
case, join relationships are possible only between the subservient
tables and the dominant tables. <A HREF="#query7">Query 7</A> performs
this kind of join. (See the sections "Examples" later in this chapter.)
<HR WIDTH=80%>
<CODE><PRE>
SELECT <i>column-list</i>
FROM x, OUTER y, OUTER z
WHERE x.a = y.a
AND x.b = z.b
</PRE></CODE>
<HR WIDTH=80%>
When you outer-join several tables to another table, make sure that your
WHERE clause does not attempt to specify impossible join conditions.
The following query attempts a join between two subservient tables:
<HR WIDTH=80%>
<CODE><PRE>
SELECT <i>column-list</i>
FROM x, OUTER y, OUTER z
WHERE x.a = y.a
AND y.b = z.b
</PRE></CODE>
<HR WIDTH=80%>
An error results: every outer join must have a dominant table.
</LI>
</BL>
The following examples use the stores database to demonstrate common
multi-table outer joins.
<H1> Examples </H1>
<A NAME="query4"></A>
<H2> Query 4 </H2>
This query outer-joins the result of a simple join to a third table. It
produces a list of all customers with supplemental information (order
number, stock number, manufacturer code, and quantity ordered) for those
customers who ordered items manufactured by Anza.
<HR WIDTH=80%>
<CODE><PRE>
SELECT customer.customer_num, lname, orders.order_num, stock_num, manu_code, quantity
FROM customer, OUTER(orders, items)
WHERE customer.customer_num = orders.customer_num
AND orders.order_num = items.order_num
AND manu_code = 'ANZ'
</PRE></CODE>
<HR WIDTH=80%>
<P>
4GL performs the simple join between <b>orders</b> and <b>items</b>
first, yielding information on all orders for ANZA-manufactured items.
The outer join combines the <b>customer</b> table with the Anza order
information. The query results do not include orders for other items.
</P>
<H3> Query 4 Results </H3>
<CODE><PRE>
customer_num lname order_num stock_num manu_code quantity
101 Pauli
102 Sadler
103 Currie
104 Higgins 1003 9 ANZ 1
104 Higgins 1003 8 ANZ 1
104 Higgins 1003 5 ANZ 5
104 Higgins 1011 5 ANZ 5
104 Higgins 1013 5 ANZ 1
104 Higgins 1013 6 ANZ 1
104 Higgins 1013 9 ANZ 2
105 Vector
106 Watson
107 Ream
108 Quinn
109 Miller
110 Jaeger 1008 8 ANZ 1
110 Jaeger 1008 9 ANZ 5
111 Keyes
112 Lawson 1006 5 ANZ 5
112 Lawson 1006 6 ANZ 1
113 Beatty
114 Albertson
115 Grant 1010 6 ANZ 1
116 Parmelee 1005 5 ANZ 10
116 Parmelee 1005 6 ANZ 1
117 Sipes 1012 8 ANZ 1
117 Sipes 1012 9 ANZ 10
118 Baxter
119 Shorter
120 Jewell
121 Wallack
122 O'Brian
123 Hanlon
124 Putnum 1021 201 ANZ 3
124 Putnum 1021 205 ANZ 2
125 Henry
126 Neelie 1022 6 ANZ 2
127 Satifer 1023 304 ANZ 1
128 Lessor
</PRE></CODE>
<A NAME="query5"></A>
<H2> Query 5 </H2>
This query outer-joins the result of an outer join to a third table.
When you use a nested outer join, the query preserves the order numbers
that <A HREF="#query4">Query 4</A> (using a nested simple join)
eliminates. The query results include all orders, whether or not they
contain Anza-manufactured items. For other items, the condition
<HR WIDTH=80%>
<CODE> <PRE>
WHERE manu_code = 'ANZ'
</PRE> </CODE>
<HR WIDTH=80%>
eliminates stock numbers, manufacturer codes and quantities as before.
<HR WIDTH=80%>
<CODE> <PRE>
SELECT customer.customer_num, lname, orders.order_num, stock_num, manu_code, quantity
FROM customer, OUTER (orders, OUTER items)
WHERE customer.customer_num = orders.customer_num
AND orders.order_num = items.order_num
AND manu_code = 'ANZ'
</PRE> </CODE>
<HR WIDTH=80%>
<H3> Query 5 Results </H3>
<CODE> <PRE>
customer_num lname order_num stock_num manu_code quantity
101 Pauli 1002
102 Sadler
103 Currie
104 Higgins 1001
104 Higgins 1003 9 ANZ 1
104 Higgins 1003 8 ANZ 1
104 Higgins 1003 5 ANZ 5
104 Higgins 1011 5 ANZ 5
104 Higgins 1013 5 ANZ 1
104 Higgins 1013 6 ANZ 1
104 Higgins 1013 9 ANZ 2
105 Vector
106 Watson 1004
106 Watson 1014
107 Ream
108 Quinn
109 Miller
110 Jaeger 1008 8 ANZ 1
110 Jaeger 1008 9 ANZ 5
110 Jaeger 1015
111 Keyes 1009
112 Lawson 1006 5 ANZ 5
112 Lawson 1006 6 ANZ 1
113 Beatty
114 Albertson
115 Grant 1010 6 ANZ 1
116 Parmelee 1005 5 ANZ 10
116 Parmelee 1005 6 ANZ 1
117 Sipes 1007
117 Sipes 1012 8 ANZ 1
117 Sipes 1012 9 ANZ 10
118 Baxter
119 Shorter 1016
120 Jewell 1017
121 Wallack 1018
122 O'Brian 1019
123 Hanlon 1020
124 Putnum 1021 201 ANZ 3
124 Putnum 1021 205 ANZ 2
125 Henry
126 Neelie 1022 6 ANZ 2
127 Satifer 1023 304 ANZ 1
128 Lessor
</PRE> </CODE>