├── index.html
├── sample_sql
├── CMS_01_Title_and_Category_of_Entries.sql
├── CMS_02_Display_an_Entry.sql
├── CMS_03_Count_Entries_by_Category.sql
├── CMS_04_Entries_Sorted_Latest_First.sql
├── CMS_05_Categories_INNER_JOIN_Entries.sql
├── CMS_06_Categories_LEFT_OUTER_JOIN_Entries.sql
├── CMS_07_Categories_RIGHT_OUTER_JOIN_Entries.sql
├── CMS_08_Categories_FULL_OUTER_JOIN_Entries.sql
├── CMS_09_Left_outer_join_UNION_right_outer_join.sql
├── CMS_10_CREATE_VIEW.sql
├── CMS_11_Derived_tables.sql
├── CMS_12_Date_comparisons.sql
├── CMS_13_Correlated_subquery.sql
├── CMS_14_Content_and_Comment_tables.sql
├── CMS_15_Add_FK_to_entries.sql
├── CMS_16_Supercategories.sql
├── CMS_17_Entrykeywords.sql
├── Cart_01_Comparison_operators.sql
├── Cart_02_LIKE_and_BETWEEN.sql
├── Cart_03_ORDER_BY_price.sql
├── Cart_04_ANDs_and_ORs.sql
├── Cart_05_WHERE_1=1_and_WHERE_1=0.sql
├── Cart_06_IN_subquery.sql
├── Cart_07_NOT_EXISTS_and_NOT_IN.sql
├── Cart_08_LEFT_OUTER_JOIN_with_IS_NULL.sql
├── Cart_09_Detail_rows.sql
├── Cart_10_Group_rows.sql
├── Cart_11_GROUP_BY_with_WHERE.sql
├── Cart_12_GROUP_BY_with_HAVING.sql
├── Cart_13_ORDER_BY_qty_DESC.sql
├── Cart_14_ORDER_BY_total.sql
├── Cart_15_ORDER_BY_with_NULLs_last.sql
├── Cart_16_Details_and_Totals.sql
├── Cart_17_Vendors.sql
├── Forums_01_Setup.sql
├── Forums_02_Aggregate_functions.sql
├── Forums_03_COUNT.sql
├── Forums_04_Scalar_functions.sql
├── Forums_05_Foreign_keys.sql
├── Teams_01_CREATE_ALTER_DROP.sql
├── Teams_02_INSERT.sql
├── Teams_03_DELETE_INSERT.sql
├── Teams_04_UPDATE.sql
├── Teams_05_DELETE.sql
├── Teams_06_FROM_teans.sql
├── Teams_07_Games.sql
├── test_01_illustrated.sql
├── test_02_DECIMAL.sql
├── test_03_FLOAT.sql
└── test_04_SUM_times.sql
└── shared
├── archive.css
├── book-cover.png
└── sitepoint-logo.gif
/index.html:
--------------------------------------------------------------------------------
1 |
2 |
3 |
4 | Simply SQL
5 |
6 |
7 |
8 |
9 |
10 |
11 |
12 |
13 |
14 | Simply SQL
15 | Code Archive
16 |
17 |
Sample Applications & Examples
18 |
90 |
91 |
92 | Links
93 |
99 |
100 |
101 |
--------------------------------------------------------------------------------
/sample_sql/CMS_01_Title_and_Category_of_Entries.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 2: SELECT Overview */
2 |
3 | /* Title and Category of Entries */
4 |
5 | CREATE TABLE entries
6 | (
7 | id INTEGER NOT NULL PRIMARY KEY
8 | , title VARCHAR(99) NOT NULL
9 | /* Note: use DATETIME if your database system does not support TIMESTAMP */
10 | , created TIMESTAMP NOT NULL
11 | , updated TIMESTAMP NULL
12 | , category VARCHAR(37) NULL
13 | , content TEXT NULL
14 | );
15 |
16 | INSERT INTO entries
17 | ( id , title , created , updated , category )
18 | VALUES
19 | (423 , 'What If I Get Sick and Die?' , '2008-12-30' , '2009-03-11' , 'angst')
20 | ;
21 | INSERT INTO entries
22 | ( id , title , created , updated , category )
23 | VALUES
24 | (524 , 'Uncle Karl and the Gasoline' , '2009-02-28' , NULL , 'humor')
25 | ;
26 | INSERT INTO entries
27 | ( id , title , created , updated , category )
28 | VALUES
29 | (537 , 'Be Nice to Everybody' , '2009-03-02' , NULL , 'advice')
30 | ;
31 | INSERT INTO entries
32 | ( id , title , created , updated , category )
33 | VALUES
34 | (573 , 'Hello Statue' , '2009-03-17' , NULL , 'humor')
35 | ;
36 | INSERT INTO entries
37 | ( id , title , created , updated , category )
38 | VALUES
39 | (598 , 'The Size of Our Galaxy' , '2009-04-03' , NULL , 'science')
40 | ;
41 |
42 | SELECT
43 | title
44 | , category
45 | FROM
46 | entries
47 | ;
48 | /* Results should look like this --
49 | title category
50 | What If I Get Sick and Die? angst
51 | Uncle Karl and the Gasoline humor
52 | Be Nice to Everybody advice
53 | Hello Statue humor
54 | The Size of Our Galaxy science
55 | */
56 |
57 |
--------------------------------------------------------------------------------
/sample_sql/CMS_02_Display_an_Entry.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 2: SELECT Overview */
2 |
3 | /* Display an Entry */
4 |
5 | /* We must first provide the contents for the sample entry.
6 | This is done by updating the existing row. Notice the
7 | WHERE clause at the end of the UPDATE statement. */
8 |
9 | UPDATE
10 | entries
11 | SET
12 | content = 'When I was about nine or ten, my Uncle Karl, who
13 | would''ve been in his late teens or early twenties, once performed
14 | what to me seemed like a magic trick.
15 |
16 | Using a rubber hose, which he snaked down into the gas tank of my
17 | father''s car, he siphoned some gasoline into his mouth, lit a match,
18 | held it up a few inches in front of his face, and then, with explosive
19 | force, sprayed the gasoline out towards the lit match.
20 |
21 | Of course, a huge fireball erupted, much to the delight of the kids
22 | watching. I don''t recall if he did it more than once.
23 |
24 | The funny part of this story? We lived to tell it.
25 |
26 | Karl was like that.'
27 | WHERE
28 | id = 524
29 | ;
30 |
31 | SELECT
32 | title
33 | , created
34 | , content
35 | FROM
36 | entries
37 | WHERE
38 | id = 524
39 | ;
40 | /* Results should look like this --
41 | title created content
42 | Uncle Karl and the Gasoline 2009-02-28 When I was about nine or ten, my Uncle Karl, who
43 | would've been in his late teens or early twenties, once performed
44 | what to me seemed like a magic trick.
45 |
46 | Using a rubber hose, which he snaked down into the gas tank of my
47 | father's car, he siphoned some gasoline into his mouth, lit a match,
48 | held it up a few inches in front of his face, and then, with explosive
49 | force, sprayed the gasoline out towards the lit match.
50 |
51 | Of course, a huge fireball erupted, much to the delight of the kids
52 | watching. I don't recall if he did it more than once.
53 |
54 | The funny part of this story? We lived to tell it.
55 |
56 | Karl was like that.
57 | */
58 |
--------------------------------------------------------------------------------
/sample_sql/CMS_03_Count_Entries_by_Category.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 2: SELECT Overview */
2 |
3 | /* Count Entries by Category */
4 |
5 | SELECT
6 | category
7 | , COUNT(*) AS articles
8 | FROM
9 | entries
10 | GROUP BY
11 | category
12 | ;
13 | /* Results should look like this --
14 | category articles
15 | advice 1
16 | angst 1
17 | humor 2
18 | science 1
19 | */
20 |
21 | SELECT
22 | category
23 | , COUNT(*) AS articles
24 | FROM
25 | entries
26 | GROUP BY
27 | category
28 | HAVING
29 | COUNT(*) > 1
30 | ;
31 | /* Results should look like this --
32 | category articles
33 | humor 2
34 | */
35 |
--------------------------------------------------------------------------------
/sample_sql/CMS_04_Entries_Sorted_Latest_First.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 2: SELECT Overview */
2 |
3 | /* Entries Sorted Latest First */
4 |
5 | SELECT
6 | title
7 | , created
8 | FROM
9 | entries
10 | ORDER BY
11 | created DESC
12 | ;
13 | /* Results should look like this --
14 | title created
15 | The Size of Our Galaxy 2009-04-03
16 | Hello Statue 2009-03-17
17 | Be Nice to Everybody 2009-03-02
18 | Uncle Karl and the Gasoline 2009-02-28
19 | What If I Get Sick and Die? 2008-12-30
20 | */
21 |
22 | SELECT
23 | title
24 | , category
25 | , created
26 | FROM
27 | entries
28 | ORDER BY
29 | category
30 | , created DESC
31 | ;
32 | /* Results should look like this --
33 | title category created
34 | Be Nice to Everybody advice 2009-03-02
35 | What If I Get Sick and Die? angst 2008-12-30
36 | Hello Statue humor 2009-03-17
37 | Uncle Karl and the Gasoline humor 2009-02-28
38 | The Size of Our Galaxy science 2009-04-03
39 | */
40 |
--------------------------------------------------------------------------------
/sample_sql/CMS_05_Categories_INNER_JOIN_Entries.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 3: The FROM Clause */
2 |
3 | /* Categories INNER JOIN Entries */
4 |
5 | CREATE TABLE categories
6 | (
7 | category VARCHAR(9) NOT NULL PRIMARY KEY
8 | , name VARCHAR(37) NOT NULL
9 | );
10 |
11 | INSERT INTO categories
12 | VALUES
13 | ( 'blog' , 'Log on to My Blog' )
14 | , ( 'humor' , 'Humorous Anecdotes' )
15 | , ( 'angst' , 'Stories from the Id' )
16 | , ( 'advice' , 'Gentle Words of Advice' )
17 | , ( 'science' , 'Our Spectacular Universe' )
18 | ;
19 |
20 | SELECT
21 | category
22 | , name
23 | FROM
24 | categories
25 | ;
26 | /* Results should look like this --
27 | category name
28 | advice Gentle Words of Advice
29 | angst Stories from the Id
30 | blog Log On to My Blog
31 | humor Humorous Anecdotes
32 | science Our Spectacular Universe
33 | */
34 |
35 |
36 | SELECT
37 | categories.name
38 | , entries.title
39 | , entries.created
40 | FROM
41 | categories
42 | INNER JOIN entries
43 | ON entries.category = categories.category
44 | ;
45 | /* Results should look like this --
46 | name title created
47 | Gentle Words of Advice Be Nice to Everybody 2009-03-02
48 | Stories from the Id What If I Get Sick and Die? 2008-12-30
49 | Humorous Anecdotes Uncle Karl and the Gasoline 2009-02-28
50 | Humorous Anecdotes Hello Statue 2009-03-17
51 | Our Spectacular Universe The Size of Our Galaxy 2009-04-03
52 | */
--------------------------------------------------------------------------------
/sample_sql/CMS_06_Categories_LEFT_OUTER_JOIN_Entries.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 3: The FROM Clause */
2 |
3 | /* Categories LEFT OUTER JOIN Entries */
4 |
5 | SELECT
6 | categories.name
7 | , entries.title
8 | , entries.created
9 | FROM
10 | categories
11 | LEFT OUTER JOIN entries
12 | ON entries.category = categories.category
13 | ;
14 | /* Results should look like this --
15 | name title created
16 | Gentle Words of Advice Be Nice to Everybody 2009-03-02
17 | Stories from the Id What If I Get Sick and Die? 2008-12-30
18 | Log On to My Blog [NULL] [NULL]
19 | Humorous Anecdotes Uncle Karl and the Gasoline 2009-02-28
20 | Humorous Anecdotes Hello Statue 2009-03-17
21 | Our Spectacular Universe The Size of Our Galaxy 2009-04-03
22 | */
23 |
24 |
25 | /* Entries RIGHT OUTER JOIN Categories */
26 |
27 | SELECT
28 | categories.name
29 | , entries.title
30 | , entries.created
31 | FROM
32 | entries
33 | RIGHT OUTER JOIN categories
34 | ON categories.category = entries.category
35 | ;
36 | /* Results should look identical to Categories LEFT OUTER JOIN Entries --
37 | name title created
38 | Gentle Words of Advice Be Nice to Everybody 2009-03-02
39 | Stories from the Id What If I Get Sick and Die? 2008-12-30
40 | Log On to My Blog [NULL] [NULL]
41 | Humorous Anecdotes Uncle Karl and the Gasoline 2009-02-28
42 | Humorous Anecdotes Hello Statue 2009-03-17
43 | Our Spectacular Universe The Size of Our Galaxy 2009-04-03
44 | */
--------------------------------------------------------------------------------
/sample_sql/CMS_07_Categories_RIGHT_OUTER_JOIN_Entries.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 3: The FROM Clause */
2 |
3 | /* Categories RIGHT OUTER JOIN Entries */
4 |
5 | /* First, run the RIGHT OUTER JOIN on the tables as is */
6 |
7 | SELECT
8 | categories.name
9 | , entries.title
10 | , entries.created
11 | FROM
12 | categories
13 | RIGHT OUTER JOIN entries
14 | ON entries.category = categories.category
15 | ;
16 | /* Results should look like this --
17 | name title created
18 | Stories from the Id What If I Get Sick and Die? 2008-12-30
19 | Humorous Anecdotes Uncle Karl and the Gasoline 2009-02-28
20 | Gentle Words of Advice Be Nice to Everybody 2009-03-02
21 | Humorous Anecdotes Hello Statue 2009-03-17
22 | Our Spectacular Universe The Size of Our Galaxy 2009-04-03
23 |
24 | Note: sequence will likely be different than the results of the
25 | INNER JOIN. This time, because the entries table is an outer table,
26 | the database system will execute the join differently, returning the
27 | same result rows, but not necessarily in the same sequence. Note that
28 | none of the join queries up to this point has used an ORDER BY clause.
29 |
30 | Another advantage of having a simple, small sample of data is that
31 | visual checking, even when rows are presented in slightly different
32 | sequences, remains feasible.
33 |
34 | */
35 |
36 |
37 | INSERT INTO entries
38 | (id , title , created , updated , category)
39 | VALUES
40 | (605 , 'Windows Media Center Rocks' , '2009-04-29' , NULL , 'computers')
41 | ;
42 |
43 | SELECT
44 | title
45 | , created
46 | , category
47 | FROM
48 | entries
49 | ;
50 | /* Results should look like this --
51 | title created category
52 | What If I Get Sick and Die? 2008-12-30 angst
53 | Uncle Karl and the Gasoline 2009-02-28 humor
54 | Be Nice to Everybody 2009-03-02 advice
55 | Hello Statue 2009-03-17 humor
56 | The Size of Our Galaxy 2009-04-03 science
57 | Windows Media Center Rocks 2009-04-29 computers
58 | */
59 |
60 | SELECT
61 | categories.name
62 | , entries.title
63 | , entries.created
64 | FROM
65 | categories
66 | RIGHT OUTER JOIN entries
67 | ON entries.category = categories.category
68 | ;
69 | /* Results should look like this --
70 | name title created
71 | Gentle Words of Advice Be Nice to Everybody 2009-03-02
72 | Stories from the Id What If I Get Sick and Die? 2008-12-30
73 | Humorous Anecdotes Uncle Karl and the Gasoline 2009-02-28
74 | Humorous Anecdotes Hello Statue 2009-03-17
75 | Our Spectacular Universe The Size of Our Galaxy 2009-04-03
76 | Windows Media Center Rocks 2009-04-29
77 | */
78 |
79 |
--------------------------------------------------------------------------------
/sample_sql/CMS_08_Categories_FULL_OUTER_JOIN_Entries.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 3: The FROM Clause */
2 |
3 | /* Categories FULL OUTER JOIN Entries */
4 |
5 | SELECT
6 | categories.name
7 | , entries.title
8 | , entries.created
9 | FROM
10 | categories
11 | FULL OUTER JOIN entries
12 | ON entries.category = categories.category
13 | ;
14 | /* Results should look like this --
15 | name title created
16 | Gentle Words of Advice Be Nice to Everybody 2009-03-02
17 | Stories from the Id What If I Get Sick and Die? 2008-12-30
18 | Log on to My Blog
19 | Humorous Anecdotes Uncle Karl and the Gasoline 2009-02-28
20 | Humorous Anecdotes Hello Statue 2009-03-17
21 | Our Spectacular Universe The Size of Our Galaxy 2009-04-03
22 | Windows Media Center Rocks 2009-04-29
23 | */
24 |
--------------------------------------------------------------------------------
/sample_sql/CMS_09_Left_outer_join_UNION_right_outer_join.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 3: The FROM Clause */
2 |
3 | /* Left outer join UNION right outer join */
4 |
5 | SELECT
6 | categories.name
7 | , entries.title
8 | , entries.created
9 | FROM
10 | categories
11 | LEFT OUTER JOIN entries
12 | ON entries.category = categories.category
13 |
14 | UNION
15 |
16 | SELECT
17 | categories.name
18 | , entries.title
19 | , entries.created
20 | FROM
21 | categories
22 | RIGHT OUTER JOIN entries
23 | ON entries.category = categories.category
24 | ;
25 | /* Results should look identical to FULL OUTER JOIN --
26 | name title created
27 | Gentle Words of Advice Be Nice to Everybody 2009-03-02
28 | Stories from the Id What If I Get Sick and Die? 2008-12-30
29 | Log on to My Blog
30 | Humorous Anecdotes Uncle Karl and the Gasoline 2009-02-28
31 | Humorous Anecdotes Hello Statue 2009-03-17
32 | Our Spectacular Universe The Size of Our Galaxy 2009-04-03
33 | Windows Media Center Rocks 2009-04-29
34 | */
--------------------------------------------------------------------------------
/sample_sql/CMS_10_CREATE_VIEW.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 3: The FROM Clause */
2 |
3 | /* Views */
4 |
5 | CREATE VIEW entries_with_category
6 | AS
7 | SELECT
8 | entries.title
9 | , entries.created
10 | , categories.name AS category_name
11 | FROM
12 | entries
13 | INNER JOIN categories
14 | ON categories.category = entries.category
15 | ;
16 | /* CREATE VIEW will fail in MySQL prior to version 5 */
17 |
18 | /* SQL Server requires GO before running the SELECT from the view
19 | GO
20 | */
21 |
22 | SELECT
23 | title
24 | , category_name
25 | FROM
26 | entries_with_category
27 | ;
28 | /* Results should look like --
29 | title category_name
30 | What If I Get Sick and Die? Stories from the Id
31 | Uncle Karl and the Gasoline Humorous Anecdotes
32 | Be Nice to Everybody Gentle Words of Advice
33 | Hello Statue Humorous Anecdotes
34 | The Size of Our Galaxy Our Spectacular Universe
35 | */
--------------------------------------------------------------------------------
/sample_sql/CMS_11_Derived_tables.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 3: The FROM Clause */
2 |
3 | /* Derived tables */
4 |
5 | SELECT
6 | title
7 | , category_name
8 | FROM (
9 | SELECT
10 | entries.title
11 | , entries.created
12 | , categories.name AS category_name
13 | FROM
14 | entries
15 | INNER JOIN categories
16 | ON categories.category = entries.category
17 | ) AS entries_with_category
18 | ;
19 | /* Results should look like --
20 | title category_name
21 | What If I Get Sick and Die? Stories from the Id
22 | Uncle Karl and the Gasoline Humorous Anecdotes
23 | Be Nice to Everybody Gentle Words of Advice
24 | Hello Statue Humorous Anecdotes
25 | The Size of Our Galaxy Our Spectacular Universe
26 | */
--------------------------------------------------------------------------------
/sample_sql/CMS_12_Date_comparisons.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 4: The WHERE Clause */
2 |
3 | /* Date Comparisons */
4 |
5 | SELECT
6 | title
7 | , created
8 | FROM
9 | entries
10 | WHERE
11 | created <= '2009-04-03'
12 | ;
13 | /* Results should look like this --
14 | title created
15 | What If I Get Sick and Die? 2008-12-30
16 | Uncle Karl and the Gasoline 2009-02-28
17 | Be Nice to Everybody 2009-03-02
18 | Hello Statue 2009-03-17
19 | The Size of Our Galaxy 2009-04-03
20 | */
21 |
22 | /* Entries posted in last 5 days */
23 |
24 | /* There will never be results from either of the next two queries.
25 | The first date in the BETWEEN expression is later than the second.
26 | This is a semantic error, not a syntax error.
27 | */
28 | SELECT
29 | title
30 | , created
31 | FROM
32 | entries
33 | WHERE
34 | created BETWEEN CURRENT_DATE AND CURRENT_DATE - INTERVAL 5 DAY
35 | ;
36 | SELECT
37 | title
38 | , created
39 | FROM
40 | entries
41 | WHERE
42 | created BETWEEN '2009-03-20'
43 | AND '2009-03-15'
44 | ;
45 |
46 | /* There will never be results from the next query either.
47 | It's the same problem as the BETWEEN semantic error.
48 | */
49 | SELECT
50 | title
51 | , created
52 | FROM
53 | entries
54 | WHERE
55 | '2009-03-20' <= created
56 | AND created <= '2009-03-15'
57 | ;
58 |
59 | /* The correct semantics: */
60 |
61 | SELECT
62 | title
63 | , created
64 | FROM
65 | entries
66 | WHERE
67 | created BETWEEN '2009-03-15' AND '2009-03-20'
68 | ;
69 | /* Results should look like this --
70 | title created
71 | Hello Statue 2009-03-17
72 | */
73 |
74 |
75 | SELECT
76 | title
77 | , created
78 | FROM
79 | entries
80 | WHERE
81 | created BETWEEN CURRENT_DATE - INTERVAL 5 DAY AND CURRENT_DATE
82 | ;
83 | /* There will be results from the sample data only if
84 | you happen to run this query on the right date.
85 | The CMS sample data contains future dates (at the
86 | time of printing). When you run the query, perhaps
87 | one of those dates will be within the last five days.
88 | */
89 |
90 |
91 | /* Entries posted in February 2009 */
92 |
93 | SELECT
94 | title
95 | , created
96 | FROM
97 | entries
98 | WHERE
99 | created BETWEEN '2009-02-01' AND '2009-03-01'
100 | ;
101 | /* Results should look like this --
102 | title created
103 | Uncle Karl and the Gasoline 2009-02-28
104 | */
--------------------------------------------------------------------------------
/sample_sql/CMS_13_Correlated_subquery.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 4: The WHERE Clause */
2 |
3 | /* Correlated subquery */
4 |
5 | SELECT
6 | category
7 | , title
8 | , created
9 | FROM
10 | entries AS t
11 | WHERE
12 | created = (
13 | SELECT
14 | MAX(created)
15 | FROM
16 | entries
17 | WHERE
18 | category = t.category
19 | )
20 | ;
21 | /* Results should look like --
22 | category title created
23 | angst What If I Get Sick and Die? 2008-12-30
24 | advice Be Nice to Everybody 2009-03-02
25 | humor Hello Statue 2009-03-17
26 | science The Size of Our Galaxy 2009-04-03
27 | computers Windows Media Center Rocks 2009-04-29
28 | */
29 |
30 | /* Join to "max" derived table */
31 |
32 | SELECT
33 | t.category
34 | , t.title
35 | , t.created
36 | FROM
37 | entries AS t
38 | INNER JOIN (
39 | SELECT
40 | category
41 | , MAX(created) AS maxdate
42 | FROM
43 | entries
44 | GROUP BY
45 | category
46 | ) AS m
47 | ON m.category = t.category AND m.maxdate = t.created
48 | ;
49 | /* Results should look like --
50 | category title created
51 | advice Be Nice to Everybody 2009-03-02
52 | angst What If I Get Sick and Die? 2008-12-30
53 | computers Windows Media Center Rocks 2009-04-29
54 | humor Hello Statue 2009-03-17
55 | science The Size of Our Galaxy 2009-04-03
56 | */
57 |
--------------------------------------------------------------------------------
/sample_sql/CMS_14_Content_and_Comment_tables.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 5: GROUP BY Clause */
2 |
3 | /* Content and Comment tables */
4 |
5 | CREATE TABLE contents
6 | (
7 | entry_id INTEGER NOT NULL PRIMARY KEY
8 | , content TEXT NOT NULL
9 | );
10 | INSERT INTO contents
11 | ( entry_id , content )
12 | SELECT
13 | id
14 | , content
15 | FROM
16 | entries
17 | WHERE
18 | NOT ( content IS NULL )
19 | ;
20 | SELECT *
21 | FROM contents
22 | ;
23 | /* Results should look like --
24 | id content
25 | 524 When I was about nine or ten ...
26 | */
27 |
28 |
29 | ALTER TABLE entries
30 | DROP COLUMN
31 | content
32 | ;
33 | SELECT
34 | *
35 | FROM
36 | entries
37 | ;
38 | /* Results should show all sample rows,
39 | not including the content column
40 | */
41 |
42 |
43 | CREATE TABLE comments
44 | (
45 | entry_id INTEGER NOT NULL
46 | , username VARCHAR(37) NOT NULL
47 | /* Note: use DATETIME if your database system does not support TIMESTAMP */
48 | , created TIMESTAMP NOT NULL
49 | , PRIMARY KEY ( entry_id, username, created )
50 | , revised TIMESTAMP NULL
51 | , comment TEXT NOT NULL
52 | );
53 | INSERT INTO comments
54 | VALUES
55 | ( 524, 'Steve0', '2009-03-05', NULL ,'Sounds like fun. Must try that.')
56 | ;
57 | INSERT INTO comments
58 | VALUES
59 | ( 524, 'r937' , '2009-03-06', NULL ,'I tasted gasoline once. Not worth the discomfort.')
60 | ;
61 | INSERT INTO comments
62 | VALUES
63 | ( 524, 'J4s0n' , '2009-03-16','2009-03-17','You and your uncle are both idiots.')
64 | ;
65 | SELECT
66 | *
67 | FROM
68 | comments
69 | ;
70 | /* Results should look like --
71 | entry_id username created updated comment
72 | 524 J4s0n 2009-03-16 2009-03-17 You and your uncle are both idiots.
73 | 524 r937 2009-03-06 I tasted gasoline once. Not worth the discomfort.
74 | 524 Steve0 2009-03-05 Sounds like fun. Must try that.
75 | */
76 |
77 | SELECT
78 | entries.id
79 | , entries.title
80 | , entries.created
81 | , contents.content
82 | FROM
83 | entries
84 | LEFT OUTER JOIN contents
85 | ON contents.entry_id = entries.id
86 | ;
87 | /* Results should look like this --
88 | id title created content
89 | 423 What If I Get Sick and Die? 2008-12-30
90 | 524 Uncle Karl and the Gasoline 2009-02-28 When I was about ...
91 | 537 Be Nice to Everybody 2009-03-02
92 | 573 Hello Statue 2009-03-17
93 | 598 The Size of Our Galaxy 2009-04-03
94 | */
95 |
96 | SELECT
97 | entries.id
98 | , entries.title
99 | , entries.created
100 | , contents.content
101 | , COUNT(comments.entry_id) AS comment_count
102 | FROM
103 | entries
104 | LEFT OUTER JOIN contents
105 | ON contents.entry_id = entries.id
106 | LEFT OUTER JOIN comments
107 | ON comments.entry_id = entries.id
108 | GROUP BY
109 | entries.id
110 | , entries.title
111 | , entries.created
112 | , contents.content
113 | ;
114 | /* Results, if you get them, should look like this --
115 | id title created content comment_count
116 | 423 What If I Get Sick and Die? 2008-12-30 0
117 | 524 Uncle Karl and the Gasoline 2009-02-28 When I was about ... 3
118 | 537 Be Nice to Everybody 2009-03-02 0
119 | 573 Hello Statue 2009-03-17 0
120 | 598 The Size of Our Galaxy 2009-04-03 0
121 | */
122 |
123 |
124 | SELECT
125 | entries.id
126 | , entries.title
127 | , entries.created
128 | , contents.content
129 | , c.comment_count
130 | FROM
131 | entries
132 | LEFT OUTER JOIN contents
133 | ON contents.entry_id = entries.id
134 | LEFT OUTER JOIN (
135 | SELECT
136 | entry_id
137 | , COUNT(*) AS comment_count
138 | FROM
139 | comments
140 | GROUP BY
141 | entry_id
142 | ) AS c
143 | ON c.entry_id = entries.id
144 | ;
145 | /* Results should look like this --
146 | id title created content comment_count
147 | 423 What If I Get Sick and Die? 2008-12-30
148 | 524 Uncle Karl and the Gasoline 2009-02-28 When I was about ... 3
149 | 537 Be Nice to Everybody 2009-03-02
150 | 573 Hello Statue 2009-03-17
151 | 598 The Size of Our Galaxy 2009-04-03
152 |
153 | Notice that comment_count is NULL for some rows, instead of 0.
154 |
155 | */
156 |
157 | SELECT
158 | entries.id
159 | , entries.title
160 | , entries.created
161 | , contents.content
162 | , ( SELECT
163 | COUNT(entry_id)
164 | FROM
165 | comments
166 | WHERE
167 | entry_id = entries.id
168 | ) AS comment_count
169 | FROM
170 | entries
171 | LEFT OUTER JOIN contents
172 | ON contents.entry_id = entries.id
173 | ;
174 | /* Results here are the same as the original GROUP BY query,
175 | with 0 instead of NULL.
176 | */
--------------------------------------------------------------------------------
/sample_sql/CMS_15_Add_FK_to_entries.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 11: Special Structures */
2 |
3 | /* Joining a table to itself */
4 |
5 | /* Confirm that there is a missing category */
6 |
7 | SELECT
8 | entries.title
9 | , entries.category
10 | FROM
11 | entries
12 | LEFT OUTER JOIN categories
13 | ON categories.category = entries.category
14 | WHERE
15 | categories.category IS NULL
16 | ;
17 | /* Results should look like this --
18 | title category
19 | Windows Media Center Rocks computers
20 | */
21 |
22 | /* Add the missing category */
23 |
24 | INSERT INTO categories
25 | ( category, name )
26 | VALUES
27 | ( 'computers' , 'Information Technology' )
28 | ;
29 |
30 | /* If necessary (it is for MySQL), index the FK column first */
31 |
32 | ALTER TABLE entries
33 | ADD INDEX category_ix (category)
34 | ;
35 |
36 | /* Add the foreign key */
37 |
38 | ALTER TABLE entries
39 | ADD CONSTRAINT
40 | category_fk
41 | FOREIGN KEY (category)
42 | REFERENCES categories (category)
43 | ON DELETE CASCADE
44 | ON UPDATE CASCADE
45 | ;
46 |
--------------------------------------------------------------------------------
/sample_sql/CMS_16_Supercategories.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 11: Special Structures */
2 |
3 | /* Joining a table to itself */
4 |
5 | /* Create the reflexive parent ("supercategory") relationship */
6 |
7 | ALTER TABLE categories
8 | ADD COLUMN parent VARCHAR(9) NULL
9 | ;
10 |
11 | /* If necessary (it is for MySQL), index the FK column first */
12 |
13 | ALTER TABLE categories
14 | ADD INDEX parent_ix (parent)
15 | ;
16 |
17 | /* Add the foreign key */
18 |
19 | ALTER TABLE categories
20 | ADD CONSTRAINT
21 | parent_fk
22 | FOREIGN KEY (parent)
23 | REFERENCES categories (category)
24 | ;
25 |
26 | /* Dump the categories table to show that the parent
27 | column still needs to be populated
28 | */
29 | SELECT
30 | category
31 | , name
32 | , parent
33 | FROM
34 | categories
35 | ;
36 | /* Results should look like this --
37 | category name parent
38 | advice Gentle Words of Advice
39 | angst Stories from the Id
40 | blog Log on to My Blog
41 | computers Information Technology
42 | humor Humorous Anecdotes
43 | science Our Spectacular Universe
44 | */
45 |
46 | /* Categorize the categories */
47 |
48 | INSERT INTO categories
49 | ( category, name )
50 | VALUES
51 | ( 'general' , 'Articles and Resources' )
52 | , ( 'personal' , 'Personal Stories and Ideas' )
53 | ;
54 | UPDATE
55 | categories
56 | SET
57 | parent = 'general'
58 | WHERE
59 | category in ( 'computers', 'science' )
60 | ;
61 | UPDATE
62 | categories
63 | SET
64 | parent = 'personal'
65 | WHERE
66 | category in ( 'advice', 'angst', 'blog', 'humor' )
67 | ;
68 | SELECT
69 | category
70 | , name
71 | , parent
72 | FROM
73 | categories
74 | ORDER BY
75 | parent
76 | , category
77 | ;
78 | /* Results should look like this --
79 | category name parent
80 | general Articles and Resources
81 | personal Personal Stories and Ideas
82 | computers Information Technology general
83 | science Our Spectacular Universe general
84 | advice Gentle Words of Advice personal
85 | angst Stories from the Id personal
86 | blog Log on to My Blog personal
87 | humor Humorous Anecdotes personal
88 | */
89 |
90 | /* Join the table to itself */
91 |
92 | SELECT
93 | cat.name AS supercategory
94 | , sub.name AS category
95 | FROM
96 | categories AS cat
97 | INNER JOIN categories AS sub
98 | ON sub.parent = cat.name
99 | ORDER BY
100 | cat.name
101 | , sub.name
102 | ;
103 | /* Results should look like this --
104 | supercategory category
105 | Articles and Resources Information Technology
106 | Articles and Resources Our Spectacular Universe
107 | Personal Stories and Ideas Gentle Words of Advice
108 | Personal Stories and Ideas Humorous Anecdotes
109 | Personal Stories and Ideas Log on to My Blog
110 | Personal Stories and Ideas Stories from the Id
111 | */
112 |
113 | /* Extend the join to the entries table */
114 |
115 | SELECT
116 | cat.name AS supercategory
117 | , sub.name AS category
118 | , entries.title
119 | FROM
120 | categories AS cat
121 | INNER JOIN categories AS sub
122 | ON sub.parent = cat.category
123 | LEFT OUTER JOIN entries
124 | ON entries.category = sub.category
125 | ORDER BY
126 | cat.name
127 | , sub.name
128 | , entries.title
129 | ;
130 | /* Results should look like this --
131 | supercategory category title
132 | Articles and Resources Information Technology Windows Media Center Rocks
133 | Articles and Resources Our Spectacular Universe The Size of Our Galaxy
134 | Personal Stories and Ideas Gentle Words of Advice Be Nice to Everybody
135 | Personal Stories and Ideas Humorous Anecdotes Hello Statue
136 | Personal Stories and Ideas Humorous Anecdotes Uncle Karl and the Gasoline
137 | Personal Stories and Ideas Log on to My Blog
138 | Personal Stories and Ideas Stories from the Id What If I Get Sick and Die?
139 | */
--------------------------------------------------------------------------------
/sample_sql/CMS_17_Entrykeywords.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 11: Special Structures */
2 |
3 | /* Keywords */
4 |
5 | /* Create the entrykeywords table */
6 |
7 | CREATE TABLE entrykeywords
8 | (
9 | entry_id INTEGER NOT NULL
10 | , keyword VARCHAR(99) NOT NULL
11 | , PRIMARY KEY ( entry_id, keyword )
12 | , CONSTRAINT entry_fk
13 | FOREIGN KEY (entry_id)
14 | REFERENCES entries (id)
15 | );
16 |
17 | /* To populate the entrykeywords table, let's first run
18 | a quick query to confirm the entry id values, which
19 | we'll need when assigning keywords. Note how the
20 | subsequent INSERT statement has been "constructed"
21 | by text-editing the results of this query.
22 | */
23 | SELECT
24 | title
25 | , id
26 | FROM
27 | entries
28 | ;
29 | /* Results should look like this --
30 | title id
31 | What If I Get Sick and Die? 423
32 | Uncle Karl and the Gasoline 524
33 | Be Nice to Everybody 537
34 | Hello Statue 573
35 | The Size of Our Galaxy 598
36 | Windows Media Center Rocks 605
37 | */
38 |
39 | INSERT INTO entrykeywords
40 | ( entry_id, keyword )
41 | VALUES
42 | /* What If I Get Sick and Die? */
43 | /* Uncle Karl and the Gasoline */ (524,'family'),(524,'reckless')
44 | /* Be Nice to Everybody */ , (537,'my three rules'),(537,'family')
45 | /* Hello Statue */
46 | /* The Size of Our Galaxy */ , (598,'astronomy')
47 | /* Windows Media Center Rocks */ , (605,'windows'),(605,'television')
48 | ;
49 |
50 | /* Confirm */
51 |
52 | SELECT
53 | entry_id
54 | , keyword
55 | FROM
56 | entrykeywords
57 | ;
58 | /* Results should look like this --
59 | entry_id keyword
60 | 524 family
61 | 524 reckless
62 | 537 family
63 | 537 my three rules
64 | 598 astronomy
65 | 605 television
66 | 605 windows
67 | */
68 |
69 | SELECT
70 | entries.title
71 | , GROUP_CONCAT(entrykeywords.keyword) AS keywords
72 | FROM
73 | entries
74 | LEFT OUTER JOIN entrykeywords
75 | ON entrykeywords.entry_id = entries.id
76 | GROUP BY
77 | entries.title
78 | ;
79 | /* Results should look like this --
80 | title keywords
81 | Be Nice to Everybody family,my three rules
82 | Hello Statue
83 | The Size of Our Galaxy astronomy
84 | Uncle Karl and the Gasoline family,reckless
85 | What If I Get Sick and Die?
86 | Windows Media Center Rocks television,windows
87 | */
88 |
89 | /* Finally, gather the keywords, in preparation for
90 | creating the keywords table.
91 | */
92 | SELECT DISTINCT
93 | keyword
94 | FROM
95 | entrykeywords
96 | ;
97 | /* Results should look like this --
98 | keyword
99 | family
100 | reckless
101 | my three rules
102 | astronomy
103 | television
104 | windows
105 | */
--------------------------------------------------------------------------------
/sample_sql/Cart_01_Comparison_operators.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 4: The WHERE Clause */
2 |
3 | /* WHERE price equals value */
4 |
5 | /* First, let's create and populate the items table */
6 |
7 | CREATE TABLE items
8 | (
9 | id INTEGER NOT NULL PRIMARY KEY
10 | , name VARCHAR(21) NOT NULL
11 | , type VARCHAR(7) NOT NULL
12 | , price DECIMAL(5,2) NULL
13 | );
14 |
15 | INSERT INTO items VALUES (5021,'thingie' ,'widgets', 9.37 );
16 | INSERT INTO items VALUES (5022,'gadget' ,'doodads', 19.37 );
17 | INSERT INTO items VALUES (5023,'dingus' ,'gizmos' , 29.37 );
18 | INSERT INTO items VALUES (5041,'gewgaw' ,'widgets', 5.00 );
19 | INSERT INTO items VALUES (5042,'knickknack' ,'doodads', 10.00 );
20 | INSERT INTO items VALUES (5043,'whatnot' ,'gizmos' , 15.00 );
21 | INSERT INTO items VALUES (5061,'bric-a-brac' ,'widgets', 2.00 );
22 | INSERT INTO items VALUES (5062,'folderol' ,'doodads', 4.00 );
23 | INSERT INTO items VALUES (5063,'jigger' ,'gizmos' , 6.00 );
24 | INSERT INTO items VALUES (5901,'doohickey' ,'widgets', 12.00 );
25 | INSERT INTO items VALUES (5902,'gimmick' ,'doodads', 9.37 );
26 | INSERT INTO items VALUES (5903,'dingbat' ,'gizmos' , 9.37 );
27 | INSERT INTO items VALUES (5911,'thingamajig' ,'widgets', NULL );
28 | INSERT INTO items VALUES (5912,'thingamabob' ,'doodads', NULL );
29 | INSERT INTO items VALUES (5913,'thingum' ,'gizmos' , NULL );
30 | INSERT INTO items VALUES (5931,'contraption' ,'widgets', 49.95 );
31 | INSERT INTO items VALUES (5932,'whatchamacallit','doodads', 59.95 );
32 | INSERT INTO items VALUES (5937,'whatsis' ,'gizmos' , NULL );
33 |
34 | SELECT
35 | name
36 | , type
37 | , price
38 | FROM
39 | items
40 | ;
41 | /* Results should look like this --
42 | name type price
43 | thingie widgets 9.37
44 | gadget doodads 19.37
45 | dingus gizmos 29.37
46 | gewgaw widgets 5.00
47 | knickknack doodads 10.00
48 | whatnot gizmos 15.00
49 | bric-a-brac widgets 2.00
50 | folderol doodads 4.00
51 | jigger gizmos 6.00
52 | doohickey widgets 12.00
53 | gimmick doodads 9.37
54 | dingbat gizmos 9.37
55 | thingamajig widgets
56 | thingamabob doodads
57 | thingum gizmos
58 | contraption widgets 49.95
59 | whatchamacallit doodads 59.95
60 | whatsis gizmos
61 | */
62 |
63 | SELECT
64 | name
65 | , type
66 | FROM
67 | items
68 | WHERE
69 | price = 9.37
70 | ;
71 | /* Results should look like this --
72 | name type
73 | thingie widgets
74 | gimmick doodads
75 | dingbat gizmos
76 | */
77 |
78 | SELECT
79 | name
80 | , price
81 | FROM
82 | items
83 | WHERE
84 | price < 10.00
85 | ;
86 | /* Results should look like this --
87 | name price
88 | thingie 9.37
89 | gewgaw 5.00
90 | bric-a-brac 2.00
91 | folderol 4.00
92 | jigger 6.00
93 | gimmick 9.37
94 | dingbat 9.37
95 | */
96 |
97 | SELECT
98 | name
99 | , type
100 | FROM
101 | items
102 | WHERE
103 | name < 'C'
104 | ;
105 | /* Results should look like this --
106 | name type
107 | bric-a-brac widgets
108 | */
--------------------------------------------------------------------------------
/sample_sql/Cart_02_LIKE_and_BETWEEN.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 4: The WHERE Clause */
2 |
3 | /* WHERE name LIKE pattern */
4 |
5 | SELECT
6 | name
7 | , type
8 | FROM
9 | items
10 | WHERE
11 | name LIKE 'thing%'
12 | ;
13 | /* Results should look like this --
14 | name type
15 | thingie widgets
16 | thingamajig widgets
17 | thingamabob doodads
18 | thingum gizmos
19 | */
20 |
21 |
22 | /* WHERE price BETWEEN values */
23 |
24 | SELECT
25 | name
26 | , price
27 | FROM
28 | items
29 | WHERE
30 | price BETWEEN 5.00 AND 10.00
31 | ;
32 | SELECT
33 | name
34 | , price
35 | FROM
36 | items
37 | WHERE
38 | 5.00 <= price AND price <= 10.00
39 | ;
40 | /* Results of both queries should look like this --
41 | name price
42 | thingie 9.37
43 | gewgaw 5.00
44 | knickknack 10.00
45 | jigger 6.00
46 | gimmick 9.37
47 | dingbat 9.37
48 | */
--------------------------------------------------------------------------------
/sample_sql/Cart_03_ORDER_BY_price.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 8: The ORDER BY Clause */
2 |
3 | /* ORDER BY price, when some prices are NULL */
4 |
5 | SELECT
6 | name
7 | , price
8 | FROM
9 | items
10 | ORDER BY
11 | price
12 | ;
13 | /* Results should look like this --
14 | name price
15 | whatsis
16 | thingum
17 | thingamabob
18 | thingamajig
19 | bric-a-brac 2.00
20 | folderol 4.00
21 | gewgaw 5.00
22 | jigger 6.00
23 | dingbat 9.37
24 | gimmick 9.37
25 | thingie 9.37
26 | knickknack 10.00
27 | doohickey 12.00
28 | whatnot 15.00
29 | gadget 19.37
30 | dingus 29.37
31 | contraption 49.95
32 | whatchamacallit 59.95
33 | */
34 |
35 | SELECT
36 | name
37 | , price
38 | FROM
39 | items
40 | ORDER BY
41 | price DESC
42 | ;
43 | /* Results should look like this --
44 | name price
45 | whatchamacallit 59.95
46 | contraption 49.95
47 | dingus 29.37
48 | gadget 19.37
49 | whatnot 15.00
50 | doohickey 12.00
51 | knickknack 10.00
52 | dingbat 9.37
53 | gimmick 9.37
54 | thingie 9.37
55 | jigger 6.00
56 | gewgaw 5.00
57 | folderol 4.00
58 | bric-a-brac 2.00
59 | thingamajig
60 | thingamabob
61 | thingum
62 | whatsis
63 | */
64 |
--------------------------------------------------------------------------------
/sample_sql/Cart_04_ANDs_and_ORs.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 4: The WHERE Clause */
2 |
3 | /* ANDs and ORs */
4 |
5 | /* First, supply missing prices */
6 |
7 | UPDATE
8 | items
9 | SET
10 | price = 22.22
11 | WHERE
12 | name IN ( 'thingamajig'
13 | , 'thingamabob'
14 | , 'thingum' )
15 | ;
16 | UPDATE
17 | items
18 | SET
19 | price = 93.70
20 | WHERE
21 | name = 'whatsis'
22 | ;
23 |
24 | /* Next, create customers, carts, and cartitems */
25 |
26 | CREATE TABLE customers
27 | (
28 | id INTEGER NOT NULL PRIMARY KEY
29 | , name VARCHAR(99) NOT NULL
30 | , billaddr VARCHAR(255) NOT NULL
31 | , shipaddr VARCHAR(255) NOT NULL DEFAULT 'See billing address.'
32 | );
33 | INSERT INTO customers (id, name, billaddr) VALUES (710,'A. Jones','123 Sesame St., Eureka, KS');
34 | INSERT INTO customers (id, name, billaddr) VALUES (730,'B. Smith','456 Sesame St., Eureka, KS');
35 | INSERT INTO customers (id, name, billaddr) VALUES (750,'C. Brown','789 Sesame St., Eureka, KS');
36 | INSERT INTO customers (id, name, billaddr) VALUES (770,'D. White','246 Sesame St., Eureka, KS');
37 | INSERT INTO customers (id, name, billaddr) VALUES (820,'E. Baker','135 Sesame St., Eureka, KS');
38 | INSERT INTO customers (id, name, billaddr) VALUES (840,'F. Black','468 Sesame St., Eureka, KS');
39 | INSERT INTO customers (id, name, billaddr) VALUES (860,'G. Scott','357 Sesame St., Eureka, KS');
40 | INSERT INTO customers (id, name, billaddr, shipaddr) VALUES (880,'H. Clark','937 Sesame St., Eureka, KS', 'P.O. Box 9, Toledo, OH' );
41 |
42 | CREATE TABLE carts
43 | (
44 | id INTEGER NOT NULL PRIMARY KEY
45 | , customer_id INTEGER NOT NULL
46 | /* Note: use DATETIME if your database system does not support TIMESTAMP */
47 | , cartdate TIMESTAMP NOT NULL
48 | );
49 |
50 | INSERT INTO carts (id, customer_id, cartdate) VALUES (2131,710,'2008-09-03 00:00:00');
51 | INSERT INTO carts (id, customer_id, cartdate) VALUES (2461,820,'2008-09-16 00:00:00');
52 | INSERT INTO carts (id, customer_id, cartdate) VALUES (2921,730,'2008-09-19 00:00:00');
53 | INSERT INTO carts (id, customer_id, cartdate) VALUES (2937,750,'2008-09-21 00:00:00');
54 | INSERT INTO carts (id, customer_id, cartdate) VALUES (3001,750,'2008-09-23 00:00:00');
55 | INSERT INTO carts (id, customer_id, cartdate) VALUES (3002,730,'2008-10-07 00:00:00');
56 | INSERT INTO carts (id, customer_id, cartdate) VALUES (3081,880,'2008-10-13 00:00:00');
57 | INSERT INTO carts (id, customer_id, cartdate) VALUES (3197,770,'2008-10-14 00:00:00');
58 | INSERT INTO carts (id, customer_id, cartdate) VALUES (3321,860,'2008-10-26 00:00:00');
59 | INSERT INTO carts (id, customer_id, cartdate) VALUES (3937,750,'2008-10-28 00:00:00');
60 |
61 | CREATE TABLE cartitems
62 | (
63 | cart_id INTEGER NOT NULL
64 | , item_id INTEGER NOT NULL
65 | /* Remove the DEFAULT and CHECK constraint if not supported */
66 | , qty SMALLINT NOT NULL DEFAULT 1
67 | CHECK ( qty <= 10 )
68 | );
69 | INSERT INTO cartitems (cart_id, item_id, qty) VALUES (2131,5902,3);
70 | INSERT INTO cartitems (cart_id, item_id, qty) VALUES (2131,5913,2);
71 | INSERT INTO cartitems (cart_id, item_id, qty) VALUES (2461,5043,3);
72 | INSERT INTO cartitems (cart_id, item_id, qty) VALUES (2461,5901,2);
73 | INSERT INTO cartitems (cart_id, item_id, qty) VALUES (2921,5023,3);
74 | INSERT INTO cartitems (cart_id, item_id, qty) VALUES (2921,5937,2);
75 | INSERT INTO cartitems (cart_id, item_id, qty) VALUES (2937,5913,1);
76 | INSERT INTO cartitems (cart_id, item_id, qty) VALUES (3001,5912,3);
77 | INSERT INTO cartitems (cart_id, item_id, qty) VALUES (3001,5937,2);
78 | INSERT INTO cartitems (cart_id, item_id, qty) VALUES (3002,5901,1);
79 | INSERT INTO cartitems (cart_id, item_id, qty) VALUES (3081,5023,3);
80 | INSERT INTO cartitems (cart_id, item_id, qty) VALUES (3081,5913,2);
81 | INSERT INTO cartitems (cart_id, item_id, qty) VALUES (3197,5932,1);
82 | INSERT INTO cartitems (cart_id, item_id, qty) VALUES (3321,5932,3);
83 | INSERT INTO cartitems (cart_id, item_id, qty) VALUES (3937,5913,3);
84 |
85 |
86 | /* The following query will be used again in Chapter 5. Here, it
87 | serves to confirm that the tables have been populated properly.
88 | */
89 |
90 | SELECT
91 | customers.name AS customer
92 | , carts.id AS cart
93 | , items.name AS item
94 | , cartitems.qty
95 | , items.price
96 | , cartitems.qty
97 | * items.price AS total
98 | FROM
99 | customers
100 | INNER JOIN carts
101 | ON carts.customer_id = customers.id
102 | INNER JOIN cartitems
103 | ON cartitems.cart_id = carts.id
104 | INNER JOIN items
105 | ON items.id = cartitems.item_id
106 | ORDER BY
107 | customers.name
108 | , carts.id
109 | , items.name
110 | ;
111 | /* Results should look like this --
112 | customer cart item qty price total
113 | A. Jones 2131 gimmick 3 9.37 28.11
114 | A. Jones 2131 thingum 2 22.22 44.44
115 | B. Smith 2921 dingus 3 29.37 88.11
116 | B. Smith 2921 whatsis 2 93.70 187.40
117 | B. Smith 3002 doohickey 1 12.00 12.00
118 | C. Brown 2937 thingum 1 22.22 22.22
119 | C. Brown 3001 thingamabob 3 22.22 66.66
120 | C. Brown 3001 whatsis 2 93.70 187.40
121 | C. Brown 3937 thingum 3 22.22 66.66
122 | D. White 3197 whatchamacallit 1 59.95 59.95
123 | E. Baker 2461 doohickey 2 12.00 24.00
124 | E. Baker 2461 whatnot 3 15.00 45.00
125 | G. Scott 3321 whatchamacallit 3 59.95 179.85
126 | H. Clark 3081 dingus 3 29.37 88.11
127 | H. Clark 3081 thingum 2 22.22 44.44
128 | */
129 |
130 |
131 | /* Query with incorrect OR condition */
132 |
133 | SELECT
134 | id
135 | , name
136 | , billaddr
137 | FROM
138 | customers
139 | WHERE
140 | name = 'A. Jones' OR 'B. Smith'
141 | ;
142 | /* This query will fail on a syntax error in all database systems
143 | except MySQL, which will return this --
144 | id name billaddr
145 | 710 A. Jones 123 Sesame St., Eureka, KS
146 | */
147 |
148 |
149 | /* ANDs and ORs */
150 |
151 | SELECT
152 | customers.name AS customer
153 | , carts.id AS cart
154 | , items.name AS item
155 | FROM
156 | customers
157 | INNER JOIN carts
158 | ON carts.customer_id = customers.id
159 | INNER JOIN cartitems
160 | ON cartitems.cart_id = carts.id
161 | INNER JOIN items
162 | ON items.id = cartitems.item_id
163 | WHERE
164 | customers.name = 'A. Jones' OR customers.name = 'B. Smith'
165 | AND items.name = 'thingum'
166 | ;
167 | /* Results should look like this --
168 | customer cart item
169 | A. Jones 2131 gimmick
170 | A. Jones 2131 thingum
171 | */
172 |
173 | /* The query above returns no rows for B. Smith because B. Smith
174 | did not purchase any thingums. It returns all items for A. Jones.
175 | The same results are produced if the WHERE clause is --
176 |
177 | WHERE customers.name = 'A. Jones'
178 | OR ( customers.name = 'B. Smith' AND items.name = 'thingum' )
179 |
180 | */
181 |
182 |
183 | SELECT
184 | customers.name AS customer
185 | , carts.id AS cart
186 | , items.name AS item
187 | FROM
188 | customers
189 | INNER JOIN carts
190 | ON carts.customer_id = customers.id
191 | INNER JOIN cartitems
192 | ON cartitems.cart_id = carts.id
193 | INNER JOIN items
194 | ON items.id = cartitems.item_id
195 | WHERE
196 | (customers.name = 'A. Jones' OR customers.name = 'B. Smith' )
197 | AND items.name = 'thingum'
198 | ;
199 | /* Results should look like this --
200 | customer cart item
201 | A. Jones 2131 thingum
202 | */
203 |
204 |
205 | /* In the section on IN conditions (later on in the chapter),
206 | the above WHERE clause is rewritten as follows, with
207 | of course the same results:
208 |
209 | WHERE customers.name IN ( 'A. Jones', 'B. Smith' )
210 | AND items.name = 'thingum'
211 |
212 | */
213 |
214 |
215 | /* Here's the same query, using a NOT IN condition */
216 |
217 | SELECT
218 | customers.name AS customer
219 | , carts.id AS cart
220 | , items.name AS item
221 | FROM
222 | customers
223 | INNER JOIN carts
224 | ON carts.customer_id = customers.id
225 | INNER JOIN cartitems
226 | ON cartitems.cart_id = carts.id
227 | INNER JOIN items
228 | ON items.id = cartitems.item_id
229 | WHERE
230 | NOT ( customers.name IN ( 'A. Jones', 'B. Smith' ) )
231 | ;
232 | /* Results should look like this --
233 | customer cart item
234 | E. Baker 2461 whatnot
235 | E. Baker 2461 doohickey
236 | C. Brown 2937 thingum
237 | C. Brown 3001 thingamabob
238 | C. Brown 3001 whatsis
239 | H. Clark 3081 dingus
240 | H. Clark 3081 thingum
241 | D. White 3197 whatchamacallit
242 | G. Scott 3321 whatchamacallit
243 | C. Brown 3937 thingum
244 | */
245 |
246 | /* The above WHERE clause can also be written as follows with,
247 | of course, the same results:
248 |
249 | WHERE customers.name NOT IN ( 'A. Jones', 'B. Smith' )
250 |
251 | Two more WHERE clauses can be tried on the same query:
252 |
253 | WHERE NOT ( customers.name = 'A. Jones' )
254 |
255 | WHERE customers.name NOT = 'A. Jones'
256 |
257 | This last one will not work at all.
258 | */
--------------------------------------------------------------------------------
/sample_sql/Cart_05_WHERE_1=1_and_WHERE_1=0.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 4: The WHERE Clause */
2 |
3 | /* WHERE 1=1 and WHERE 1=0 */
4 |
5 | /* The following query will be mentioned again in Chapter 7.
6 | Here, it serves to produce the contents for the HTML
7 | drop-down list which precedes the WHERE 1=1 example.
8 | */
9 |
10 | SELECT DISTINCT
11 | type
12 | FROM
13 | items
14 | ;
15 | /* Results should look like this --
16 | type
17 | widgets
18 | doodads
19 | gizmos
20 | */
21 |
22 | SELECT
23 | name
24 | , price
25 | FROM
26 | items
27 | WHERE
28 | type = 'widgets'
29 | AND price BETWEEN 10.00 AND 20.00
30 | ;
31 | /* Results should look like this --
32 | name price
33 | doohickey 12.00
34 | */
35 |
36 | SELECT
37 | name
38 | , price
39 | FROM
40 | items
41 | WHERE
42 | type = 'widgets'
43 | ;
44 | /* Results should look like this --
45 | name price
46 | thingie 9.37
47 | gewgaw 5.00
48 | bric-a-brac 2.00
49 | doohickey 12.00
50 | thingamajig 22.22
51 | contraption 49.95
52 | */
53 |
54 | /* The following query, of course, produces the
55 | same results as the above.
56 | */
57 | SELECT
58 | name
59 | , price
60 | FROM
61 | items
62 | WHERE
63 | 1=1
64 | AND type = 'widgets'
65 | ;
66 |
67 | SELECT
68 | id
69 | , name
70 | , billaddr
71 | , shipaddr
72 | FROM
73 | customers
74 | WHERE
75 | 1=0
76 | OR name LIKE '%Toledo%'
77 | OR billaddr LIKE '%Toledo%'
78 | OR shipaddr LIKE '%Toledo%'
79 | ;
80 | /* Results should look like this --
81 | id name billaddr shipaddr
82 | 880 H. Clark 937 Sesame St., Eureka, KS P.O. Box 9, Toledo, OH
83 | */
--------------------------------------------------------------------------------
/sample_sql/Cart_06_IN_subquery.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 4: The WHERE Clause */
2 |
3 | /* IN subquery */
4 |
5 | SELECT
6 | name
7 | FROM
8 | items
9 | WHERE
10 | id IN (
11 | SELECT
12 | cartitems.item_id
13 | FROM
14 | carts
15 | INNER JOIN cartitems
16 | ON cartitems.cart_id = carts.id
17 | WHERE
18 | carts.customer_id = 750
19 | )
20 | ;
21 | /* Results should look like this --
22 | name
23 | thingamabob
24 | thingum
25 | whatsis
26 | */
27 |
28 | /* Notice that the subquery can be run by itself,
29 | and that it returns item 5913 twice.
30 | */
31 |
32 | SELECT
33 | cartitems.item_id
34 | FROM
35 | carts
36 | INNER JOIN cartitems
37 | ON cartitems.cart_id = carts.id
38 | WHERE
39 | carts.customer_id = 750
40 | ;
41 | /* Results should look like this --
42 | item_id
43 | 5913
44 | 5912
45 | 5937
46 | 5913
47 | */
--------------------------------------------------------------------------------
/sample_sql/Cart_07_NOT_EXISTS_and_NOT_IN.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 4: The WHERE Clause */
2 |
3 | /* NOT EXISTS and NOT IN */
4 |
5 | /* The following three queries all produce the same results.
6 | */
7 |
8 | SELECT
9 | name
10 | FROM
11 | customers
12 | WHERE
13 | NOT EXISTS (
14 | SELECT
15 | 1
16 | FROM
17 | carts
18 | WHERE
19 | customer_id = customers.id
20 | )
21 | ;
22 | SELECT
23 | name
24 | FROM
25 | customers
26 | WHERE
27 | NOT (
28 | id IN (
29 | SELECT
30 | customer_id
31 | FROM
32 | carts
33 | )
34 | )
35 | ;
36 | SELECT
37 | name
38 | FROM
39 | customers AS t
40 | WHERE
41 | NOT (
42 | id IN (
43 | SELECT
44 | customer_id
45 | FROM
46 | carts
47 | WHERE
48 | customer_id = t.id
49 | )
50 | )
51 | ;
52 | /* Results should look like this --
53 | name
54 | F. Black
55 | */
56 |
--------------------------------------------------------------------------------
/sample_sql/Cart_08_LEFT_OUTER_JOIN_with_IS_NULL.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 4: The WHERE Clause */
2 |
3 | /* LEFT OUTER JOIN with IS NULL */
4 |
5 | SELECT
6 | customers.name
7 | FROM
8 | customers
9 | LEFT OUTER JOIN carts
10 | ON carts.customer_id = customers.id
11 | WHERE
12 | carts.customer_id IS NULL
13 | ;
14 | /* Results should look like this --
15 | name
16 | F. Black
17 | */
18 |
--------------------------------------------------------------------------------
/sample_sql/Cart_09_Detail_rows.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 5: The GROUP BY Clause */
2 |
3 | /* Detailed rows */
4 |
5 | /* This is the same query used in Chapter 4 */
6 |
7 | SELECT
8 | customers.name AS customer
9 | , carts.id AS cart
10 | , items.name AS item
11 | , cartitems.qty
12 | , items.price
13 | , cartitems.qty
14 | * items.price AS total
15 | FROM
16 | customers
17 | INNER JOIN carts
18 | ON carts.customer_id = customers.id
19 | INNER JOIN cartitems
20 | ON cartitems.cart_id = carts.id
21 | INNER JOIN items
22 | ON items.id = cartitems.item_id
23 | ORDER BY
24 | customers.name
25 | , carts.id
26 | , items.name
27 | ;
28 | /* Results should look like this --
29 | customer cart item qty price total
30 | A. Jones 2131 gimmick 3 9.37 28.11
31 | A. Jones 2131 thingum 2 22.22 44.44
32 | B. Smith 2921 dingus 3 29.37 88.11
33 | B. Smith 2921 whatsis 2 93.70 187.40
34 | B. Smith 3002 doohickey 1 12.00 12.00
35 | C. Brown 2937 thingum 1 22.22 22.22
36 | C. Brown 3001 thingamabob 3 22.22 66.66
37 | C. Brown 3001 whatsis 2 93.70 187.40
38 | C. Brown 3937 thingum 3 22.22 66.66
39 | D. White 3197 whatchamacallit 1 59.95 59.95
40 | E. Baker 2461 doohickey 2 12.00 24.00
41 | E. Baker 2461 whatnot 3 15.00 45.00
42 | G. Scott 3321 whatchamacallit 3 59.95 179.85
43 | H. Clark 3081 dingus 3 29.37 88.11
44 | H. Clark 3081 thingum 2 22.22 44.44
45 | */
--------------------------------------------------------------------------------
/sample_sql/Cart_10_Group_rows.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 5: The GROUP BY Clause */
2 |
3 | /* Grouped rows */
4 |
5 | /* First, GROUP BY customer and cart */
6 |
7 | SELECT
8 | customers.name AS customer
9 | , carts.id AS cart
10 | , COUNT(items.name) AS items
11 | , SUM(cartitems.qty
12 | * items.price) AS total
13 | FROM
14 | customers
15 | INNER JOIN carts
16 | ON carts.customer_id = customers.id
17 | INNER JOIN cartitems
18 | ON cartitems.cart_id = carts.id
19 | INNER JOIN items
20 | ON items.id = cartitems.item_id
21 | GROUP BY
22 | customers.name
23 | , carts.id
24 | ;
25 | /* Results should look like this --
26 | customer cart items total
27 | A. Jones 2131 2 72.55
28 | B. Smith 2921 2 275.51
29 | B. Smith 3002 1 12.00
30 | C. Brown 2937 1 22.22
31 | C. Brown 3001 2 254.06
32 | C. Brown 3937 1 66.66
33 | D. White 3197 1 59.95
34 | E. Baker 2461 2 69.00
35 | G. Scott 3321 1 179.85
36 | H. Clark 3081 2 132.55
37 | */
38 |
39 |
40 | /* Next, GROUP BY customer only */
41 |
42 | SELECT
43 | customers.name AS customer
44 | , COUNT(items.name) AS items
45 | , SUM(cartitems.qty
46 | * items.price) AS total
47 | FROM
48 | customers
49 | INNER JOIN carts
50 | ON carts.customer_id = customers.id
51 | INNER JOIN cartitems
52 | ON cartitems.cart_id = carts.id
53 | INNER JOIN items
54 | ON items.id = cartitems.item_id
55 | GROUP BY
56 | customers.name
57 | ;
58 | /* Results should look like this --
59 | customer items total
60 | A. Jones 2 72.55
61 | B. Smith 3 287.51
62 | C. Brown 4 342.94
63 | D. White 1 59.95
64 | E. Baker 2 69.00
65 | G. Scott 1 179.85
66 | H. Clark 2 132.55
67 | */
68 |
--------------------------------------------------------------------------------
/sample_sql/Cart_11_GROUP_BY_with_WHERE.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 5: The GROUP BY Clause */
2 |
3 | /* A grouping query with a WHERE clause */
4 |
5 | SELECT
6 | customers.name AS customer
7 | , SUM(cartitems.qty) AS qty
8 | , SUM(cartitems.qty
9 | * items.price) AS total
10 | FROM
11 | customers
12 | INNER JOIN carts
13 | ON carts.customer_id = customers.id
14 | INNER JOIN cartitems
15 | ON cartitems.cart_id = carts.id
16 | INNER JOIN items
17 | ON items.id = cartitems.item_id
18 | WHERE
19 | items.name = 'thingum'
20 | GROUP BY
21 | customers.name
22 | ;
23 | /* Results should look like this --
24 | customer qty total
25 | A. Jones 2 44.44
26 | C. Brown 4 88.88
27 | H. Clark 2 44.44
28 | */
--------------------------------------------------------------------------------
/sample_sql/Cart_12_GROUP_BY_with_HAVING.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 6: The HAVING Clause */
2 |
3 | /* A grouping query with a HAVING clause */
4 |
5 | SELECT
6 | customers.name AS customer
7 | , SUM(cartitems.qty) AS sumqty
8 | , SUM(cartitems.qty
9 | * items.price) AS total
10 | FROM
11 | customers
12 | INNER JOIN carts
13 | ON carts.customer_id = customers.id
14 | INNER JOIN cartitems
15 | ON cartitems.cart_id = carts.id
16 | INNER JOIN items
17 | ON items.id = cartitems.item_id
18 | GROUP BY
19 | customers.name
20 | HAVING
21 | SUM(cartitems.qty) > 5
22 | ;
23 |
24 | /* Alternate HAVING clause --
25 |
26 | HAVING sumqty > 5
27 |
28 | */
29 |
30 | /* Results should look like this --
31 | customer sumqty totsales
32 | B. Smith 6 287.51
33 | C. Brown 9 342.94
34 | */
35 |
36 | /* Results without the HAVING clause --
37 | customer sumqty totsales
38 | A. Jones 5 72.55
39 | B. Smith 6 287.51
40 | C. Brown 9 342.94
41 | D. White 1 59.95
42 | E. Baker 5 69.00
43 | G. Scott 3 179.85
44 | H. Clark 5 132.55
45 | */
46 |
47 |
48 | /* A HAVING clause without a GROUP BY clause */
49 |
50 | SELECT
51 | SUM(cartitems.qty
52 | * items.price) AS totsales
53 | FROM
54 | carts
55 | INNER JOIN cartitems
56 | ON cartitems.cart_id = carts.id
57 | INNER JOIN items
58 | ON items.id = cartitems.item_id
59 | /*
60 | WHERE
61 | carts.cartdate = CURRENT_DATE - INTERVAL 1 DAY
62 |
63 | Note that the WHERE clause is commented out.
64 | Its intent is to obtain "yesterday's sales" but
65 | there are barely enough sales in the Shopping Cart
66 | sample data for all dates combined to exceed the total.
67 | */
68 | HAVING
69 | totsales > 1000
70 | ;
71 |
72 | /* Results should look like this --
73 | totsales
74 | 1144.35
75 | */
--------------------------------------------------------------------------------
/sample_sql/Cart_13_ORDER_BY_qty_DESC.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 8: The ORDER BY Clause */
2 |
3 | /* ORDER BY qty DESC */
4 |
5 | SELECT
6 | customers.name AS customer
7 | , carts.id AS cart
8 | , items.name AS item
9 | , cartitems.qty
10 | , items.price
11 | , cartitems.qty
12 | * items.price AS total
13 | FROM
14 | customers
15 | INNER JOIN carts
16 | ON carts.customer_id = customers.id
17 | INNER JOIN cartitems
18 | ON cartitems.cart_id = carts.id
19 | INNER JOIN items
20 | ON items.id = cartitems.item_id
21 | ORDER BY
22 | cartitems.qty DESC
23 | , items.name
24 | ;
25 | /* Results should look like this --
26 | customer cart item qty price total
27 | H. Clark 3081 dingus 3 29.37 88.11
28 | B. Smith 2921 dingus 3 29.37 88.11
29 | A. Jones 2131 gimmick 3 9.37 28.11
30 | C. Brown 3001 thingamabob 3 22.22 66.66
31 | C. Brown 3937 thingum 3 22.22 66.66
32 | G. Scott 3321 whatchamacallit 3 59.95 179.85
33 | E. Baker 2461 whatnot 3 15.00 45.00
34 | E. Baker 2461 doohickey 2 12.00 24.00
35 | A. Jones 2131 thingum 2 22.22 44.44
36 | H. Clark 3081 thingum 2 22.22 44.44
37 | B. Smith 2921 whatsis 2 93.70 187.40
38 | C. Brown 3001 whatsis 2 93.70 187.40
39 | B. Smith 3002 doohickey 1 12.00 12.00
40 | C. Brown 2937 thingum 1 22.22 22.22
41 | D. White 3197 whatchamacallit 1 59.95 59.95
42 | */
43 |
--------------------------------------------------------------------------------
/sample_sql/Cart_14_ORDER_BY_total.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 8: The ORDER BY Clause */
2 |
3 | /* ORDER BY total DESC */
4 |
5 | SELECT
6 | customers.name AS customer
7 | , carts.id AS cart
8 | , items.name AS item
9 | , cartitems.qty
10 | , items.price
11 | , cartitems.qty
12 | * items.price AS total
13 | FROM
14 | customers
15 | INNER JOIN carts
16 | ON carts.customer_id = customers.id
17 | INNER JOIN cartitems
18 | ON cartitems.cart_id = carts.id
19 | INNER JOIN items
20 | ON items.id = cartitems.item_id
21 | ORDER BY
22 | total DESC
23 | ;
24 | /* Results should look like this --
25 | customer cart item qty price total
26 | B. Smith 2921 whatsis 2 93.70 187.40
27 | C. Brown 3001 whatsis 2 93.70 187.40
28 | G. Scott 3321 whatchamacallit 3 59.95 179.85
29 | B. Smith 2921 dingus 3 29.37 88.11
30 | H. Clark 3081 dingus 3 29.37 88.11
31 | C. Brown 3937 thingum 3 22.22 66.66
32 | C. Brown 3001 thingamabob 3 22.22 66.66
33 | D. White 3197 whatchamacallit 1 59.95 59.95
34 | E. Baker 2461 whatnot 3 15.00 45.00
35 | H. Clark 3081 thingum 2 22.22 44.44
36 | A. Jones 2131 thingum 2 22.22 44.44
37 | A. Jones 2131 gimmick 3 9.37 28.11
38 | E. Baker 2461 doohickey 2 12.00 24.00
39 | C. Brown 2937 thingum 1 22.22 22.22
40 | B. Smith 3002 doohickey 1 12.00 12.00
41 | */
42 |
--------------------------------------------------------------------------------
/sample_sql/Cart_15_ORDER_BY_with_NULLs_last.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 8: The ORDER BY Clause */
2 |
3 | /* ORDER BY price, with NULLs last */
4 |
5 | SELECT
6 | name
7 | , price
8 | FROM
9 | items
10 | ORDER BY
11 | CASE WHEN price IS NULL
12 | THEN 2
13 | ELSE 1
14 | END
15 | , price
16 | ;
17 | /* Results should look like this --
18 | name price
19 | bric-a-brac 2.00
20 | folderol 4.00
21 | gewgaw 5.00
22 | jigger 6.00
23 | dingbat 9.37
24 | gimmick 9.37
25 | thingie 9.37
26 | knickknack 10.00
27 | doohickey 12.00
28 | whatnot 15.00
29 | gadget 19.37
30 | dingus 29.37
31 | contraption 49.95
32 | whatchamacallit 59.95
33 | thingamabob
34 | thingamajig
35 | thingum
36 | whatsis
37 | */
38 |
--------------------------------------------------------------------------------
/sample_sql/Cart_16_Details_and_Totals.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 8: The ORDER BY Clause */
2 |
3 | /* Detail and Total rows */
4 |
5 | SELECT
6 | *
7 | FROM (
8 | SELECT
9 | customers.name AS customer
10 | , carts.id AS cart
11 | , items.name AS item
12 | , cartitems.qty
13 | , items.price
14 | , cartitems.qty
15 | * items.price AS total
16 | FROM
17 | customers
18 | INNER JOIN carts
19 | ON carts.customer_id = customers.id
20 | INNER JOIN cartitems
21 | ON cartitems.cart_id = carts.id
22 | INNER JOIN items
23 | ON items.id = cartitems.item_id
24 |
25 | UNION ALL
26 |
27 | SELECT
28 | customers.name AS customer
29 | , NULL AS cart
30 | , CAST(COUNT(items.name) AS CHAR) AS item
31 | , NULL AS qty
32 | , NULL AS price
33 | , SUM(cartitems.qty
34 | * items.price) AS total
35 | FROM
36 | customers
37 | INNER JOIN carts
38 | ON carts.customer_id = customers.id
39 | INNER JOIN cartitems
40 | ON cartitems.cart_id = carts.id
41 | INNER JOIN items
42 | ON items.id = cartitems.item_id
43 | GROUP BY
44 | customers.name
45 | ) AS dt
46 | ORDER BY
47 | customer
48 | , cart
49 | , item
50 | ;
51 | /* Results should look like this --
52 | customer cart item qty price total
53 | A. Jones 2 72.55
54 | A. Jones 2131 gimmick 3 9.37 28.11
55 | A. Jones 2131 thingum 2 22.22 44.44
56 | B. Smith 3 287.51
57 | B. Smith 2921 dingus 3 29.37 88.11
58 | B. Smith 2921 whatsis 2 93.70 187.40
59 | B. Smith 3002 doohickey 1 12.00 12.00
60 | C. Brown 4 342.94
61 | C. Brown 2937 thingum 1 22.22 22.22
62 | C. Brown 3001 thingamabob 3 22.22 66.66
63 | C. Brown 3001 whatsis 2 93.70 187.40
64 | C. Brown 3937 thingum 3 2.22 66.66
65 | D. White 1 59.95
66 | D. White 3197 whatchamacallit 1 59.95 59.95
67 | E. Baker 2 69.00
68 | E. Baker 2461 doohickey 2 12.00 24.00
69 | E. Baker 2461 whatnot 3 15.00 45.00
70 | G. Scott 1 179.85
71 | G. Scott 3321 whatchamacallit 3 59.95 179.85
72 | H. Clark 2 132.55
73 | H. Clark 3081 dingus 3 29.37 88.11
74 | H. Clark 3081 thingum 2 22.22 44.44
75 | */
--------------------------------------------------------------------------------
/sample_sql/Cart_17_Vendors.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 10: Relational Integrity */
2 |
3 | /* Foreign keys may be NULL */
4 |
5 | /* Create and populate the vendors table */
6 |
7 | CREATE TABLE vendors
8 | (
9 | id INTEGER NOT NULL PRIMARY KEY
10 | , name VARCHAR(21) NOT NULL
11 | );
12 |
13 | INSERT INTO vendors VALUES ( 17, 'Acme Corp' );
14 | INSERT INTO vendors VALUES ( 19, 'Ersatz Inc' );
15 |
16 |
17 | /* Add and populate the vendor FK in the items table */
18 |
19 | ALTER TABLE items
20 | ADD COLUMN
21 | vendor_id INTEGER NULL
22 | ;
23 | ALTER TABLE items
24 | ADD INDEX
25 | vendor_ix (vendor_id)
26 | ;
27 | ALTER TABLE items
28 | ADD CONSTRAINT
29 | vendor_fk
30 | FOREIGN KEY (vendor_id)
31 | REFERENCES vendors (id)
32 | ON DELETE CASCADE
33 | ON UPDATE CASCADE
34 | ;
35 | UPDATE
36 | items
37 | SET
38 | vendor_id = 17 /* Acme */
39 | WHERE
40 | name < 't'
41 | ;
42 | UPDATE
43 | items
44 | SET
45 | vendor_id = 19 /* Ersatz */
46 | WHERE
47 | name > 'w'
48 | ;
49 |
50 | INSERT INTO items
51 | ( id, name, type, price, vendor_id )
52 | VALUES
53 | ( 9901, 'gift wrapping', 'service', 5.00, NULL )
54 | , ( 9902, 'discount coupon', 'service', -10.00, NULL )
55 | ;
56 |
57 | SELECT
58 | id
59 | , name
60 | , type
61 | , price
62 | , vendor_id
63 | FROM
64 | items
65 | ORDER BY
66 | id
67 | ;
68 | /* Results should look like this --
69 | id name type price vendor_id
70 | 5021 thingie widgets 9.37
71 | 5022 gadget doodads 19.37 17
72 | 5023 dingus gizmos 29.37 17
73 | 5041 gewgaw widgets 5.00 17
74 | 5042 knickknack doodads 10.00 17
75 | 5043 whatnot gizmos 15.00 19
76 | 5061 bric-a-brac widgets 2.00 17
77 | 5062 folderol doodads 4.00 17
78 | 5063 jigger gizmos 6.00 17
79 | 5901 doohickey widgets 12.00 17
80 | 5902 gimmick doodads 9.37 17
81 | 5903 dingbat gizmos 9.37 17
82 | 5911 thingamajig widgets 22.22
83 | 5912 thingamabob doodads 22.22
84 | 5913 thingum gizmos 22.22
85 | 5931 contraption widgets 49.95 17
86 | 5932 whatchamacallit doodads 59.95 19
87 | 5937 whatsis gizmos 93.70 19
88 | 9901 gift wrapping service 5.00
89 | 9902 discount coupon service -10.00
90 | */
--------------------------------------------------------------------------------
/sample_sql/Forums_01_Setup.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 7: The SELECT Clause */
2 |
3 | /* Create and populate the Discussion Forums tables */
4 |
5 | CREATE TABLE forums
6 | (
7 | id INTEGER NOT NULL PRIMARY KEY
8 | , name VARCHAR(37) NOT NULL
9 | , CONSTRAINT forum_name_uk UNIQUE ( name ) /* This is discussed in Chapter 10 */
10 | );
11 | INSERT INTO forums VALUES ( 10001 , 'Search Engines' );
12 | INSERT INTO forums VALUES ( 10002 , 'Databases' );
13 | INSERT INTO forums VALUES ( 10003 , 'Applications' );
14 |
15 | CREATE TABLE members
16 | (
17 | id INTEGER NOT NULL PRIMARY KEY
18 | , name VARCHAR(37) NOT NULL
19 | , CONSTRAINT name_uk UNIQUE ( name ) /* This is discussed in Chapter 10 */
20 | );
21 | INSERT INTO members VALUES ( 9 , 'noo13' );
22 | INSERT INTO members VALUES ( 37 , 'r937' );
23 | INSERT INTO members VALUES ( 42 , 'DeepThought' );
24 | INSERT INTO members VALUES ( 99 , 'BarbFeldon' );
25 | INSERT INTO members VALUES ( 187 , 'RJNeedham' );
26 |
27 | CREATE TABLE threads
28 | (
29 | id INTEGER NOT NULL PRIMARY KEY
30 | , name VARCHAR(99) NOT NULL
31 | , forum_id INTEGER NOT NULL
32 | , starter INTEGER NOT NULL
33 | , CONSTRAINT thread_name_uk UNIQUE ( id, name ) /* This is discussed in Chapter 10 */
34 | );
35 | INSERT INTO threads VALUES ( 15 , 'Difficulty with join query' , 10002 , 187 );
36 | INSERT INTO threads VALUES ( 25 , 'How do I get listed in Yahoo?' , 10001 , 9 );
37 | INSERT INTO threads VALUES ( 35 , 'People who bought ... also bought ...' , 10002 , 99 );
38 | INSERT INTO threads VALUES ( 45 , 'WHERE clause doesn''t work' , 10002 , 187 );
39 |
40 | CREATE TABLE posts
41 | (
42 | id INTEGER NOT NULL PRIMARY KEY
43 | , name VARCHAR(99) NULL
44 | , thread_id INTEGER NOT NULL
45 | , reply_to INTEGER NULL
46 | , posted_by INTEGER NOT NULL
47 | /* Note: use DATETIME if your database system does not support TIMESTAMP */
48 | /* Remove the DEFAULT and CHECK constraint if not supported */
49 | , created TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP
50 | , revised TIMESTAMP NULL CHECK ( revised >= created )
51 | , post TEXT NOT NULL
52 | );
53 | INSERT INTO posts
54 | VALUES
55 | ( 201 , 'Difficulty with join query' , 15, NULL , 187 , '2008-11-12 11:12:13', NULL
56 | , 'I''m having a lot of trouble joining my tables. What''s a foreign key?' );
57 |
58 | INSERT INTO posts
59 | VALUES
60 | ( 215 , 'How do I get listed in Yahoo?', 25, NULL , 9 , '2008-11-15 11:20:02', NULL
61 | , 'I''ve figured out how to submit my URL to Google, but I can''t seem to find where to post it on Yahoo! Can anyone help?' );
62 |
63 | INSERT INTO posts
64 | VALUES
65 | ( 216 , NULL , 25, 215 , 42 , '2008-11-15 11:37:10', NULL
66 | , 'Try http://search.yahoo.com/info/submit.html ' );
67 |
68 | INSERT INTO posts
69 | VALUES
70 | ( 218 , 'That''s it!' , 25, 216 , 9 , '2008-11-15 11:42:24', NULL
71 | , 'That''s it! How did you find it?' );
72 |
73 | INSERT INTO posts
74 | VALUES
75 | ( 219 , NULL , 25, 218 , 42 , '2008-11-15 11:51:45', '2008-11-15 11:57:57'
76 | , 'There''s a link at the bottom of the homepage called "Suggest a site"' );
77 |
78 | INSERT INTO posts
79 | VALUES
80 | ( 222 , 'People who bought ... also bought ...' , 35, NULL , 99 , '2008-11-22 22:22:22', NULL
81 | , 'For each item in the user''s cart, I want to show other items that people bought who bought that item, but the SQL is too hairy for me. HELP!' );
82 |
83 | INSERT INTO posts
84 | VALUES
85 | ( 230 , 'WHERE clause doesn''t work' , 45, NULL , 187 , '2008-12-04 09:37:00', NULL
86 | , 'My query has WHERE startdate > 2009-01-01 but I get 0 results, even though I know there are rows for next year!' );
87 |
88 | SELECT
89 | id
90 | , name
91 | , thread_id
92 | , reply_to
93 | , posted_by
94 | , post
95 | FROM
96 | posts
97 | ;
98 | /* Results should look like this --
99 | id name thread_id reply_to posted_by post
100 | 201 Difficulty with join query 15 187 I'm having a lot of trouble joining ...
101 | 215 How do I get listed in Yahoo? 25 9 I've figured out how to submit my URL ...
102 | 216 25 215 42 Try http://search.yahoo.com/info/submit.html
103 | 218 That's it! 25 216 9 That's it! How did you find it?
104 | 219 25 218 42 There's a link at the bottom of the ...
105 | 222 People who bought ... also bought ... 35 99 For each item in the user's cart, ...
106 | 230 WHERE clause doesn't work 45 187 My query has WHERE startdate > ...
107 | */
--------------------------------------------------------------------------------
/sample_sql/Forums_02_Aggregate_functions.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 7: The SELECT Clause */
2 |
3 | /* Aggregate functions */
4 |
5 | /* First, show the selected forums data */
6 |
7 | SELECT
8 | forums.id AS f_id
9 | , forums.name AS forum
10 | , threads.id AS t_id
11 | , threads.name AS thread
12 | , posts.id AS p_id
13 | , posts.name AS post
14 | FROM
15 | forums
16 | LEFT OUTER JOIN threads
17 | ON threads.forum_id = forums.id
18 | LEFT OUTER JOIN posts
19 | ON posts.thread_id = threads.id
20 | ;
21 | /* Results should look like this --
22 | f_id forum t_id thread p_id post
23 | 10001 Search Engines 25 How do I get listed in Yahoo? 215 How do I get listed in Yahoo?
24 | 10001 Search Engines 25 How do I get listed in Yahoo? 216
25 | 10001 Search Engines 25 How do I get listed in Yahoo? 218 That's it!
26 | 10001 Search Engines 25 How do I get listed in Yahoo? 219
27 | 10002 Databases 15 Difficulty with join query 201 Difficulty with join query
28 | 10002 Databases 35 People who bought ... also bought ... 222 People who bought ... also bought ...
29 | 10002 Databases 45 WHERE clause doesn't work 230 WHERE clause doesn't work
30 | 10003 Applications
31 | */
32 |
33 | /* Now, two queries using aggregate functions */
34 |
35 | SELECT
36 | COUNT(forums.id) AS forums
37 | , COUNT(threads.id) AS threads
38 | , COUNT(posts.id) AS posts
39 | FROM
40 | forums
41 | LEFT OUTER JOIN threads
42 | ON threads.forum_id = forums.id
43 | LEFT OUTER JOIN posts
44 | ON posts.thread_id = threads.id
45 | ;
46 | /* Results should look like this --
47 | forums threads posts
48 | 8 7 7
49 | */
50 |
51 | SELECT
52 | COUNT(DISTINCT forums.id) AS forums
53 | , COUNT(DISTINCT threads.id) AS threads
54 | , COUNT(DISTINCT posts.id) AS posts
55 | FROM
56 | forums
57 | LEFT OUTER JOIN threads
58 | ON threads.forum_id = forums.id
59 | LEFT OUTER JOIN posts
60 | ON posts.thread_id = threads.id
61 | ;
62 | /* Results should look like this --
63 | forums threads posts
64 | 3 4 7
65 | */
66 |
--------------------------------------------------------------------------------
/sample_sql/Forums_03_COUNT.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 7: The SELECT Clause */
2 |
3 | /* COUNT(*) */
4 |
5 | /* First, the ubiquitous "SELECT COUNT(*) FROM table" */
6 |
7 | SELECT
8 | COUNT(*) AS rows
9 | FROM
10 | members
11 | ;
12 | /* Results should look like this --
13 | rows
14 | 5
15 | */
16 |
17 | SELECT
18 | forums.id AS f_id
19 | , forums.name AS forum
20 | , threads.id AS t_id
21 | , threads.name AS thread
22 | FROM
23 | forums
24 | LEFT OUTER JOIN threads
25 | ON threads.forum_id = forums.id
26 | ;
27 | /* Results should look like this --
28 | f_id forum t_id thread
29 | 10001 Search Engines 25 How do I get listed in Yahoo?
30 | 10002 Databases 15 Difficulty with join query
31 | 10002 Databases 35 People who bought ... also bought ...
32 | 10002 Databases 45 WHERE clause doesn't work
33 | 10003 Applications
34 | */
35 |
36 | SELECT
37 | forums.id AS f_id
38 | , forums.name AS forum
39 | , COUNT(*) AS rows
40 | FROM
41 | forums
42 | LEFT OUTER JOIN threads
43 | ON threads.forum_id = forums.id
44 | GROUP BY
45 | forums.id
46 | , forums.name
47 | ;
48 | /* Results should look like this --
49 | f_id forum rows
50 | 10001 Search Engines 1
51 | 10002 Databases 3
52 | 10003 Applications 1
53 | */
54 |
55 | SELECT
56 | forums.id AS f_id
57 | , forums.name AS forum
58 | , COUNT(threads.id) AS threads
59 | FROM
60 | forums
61 | LEFT OUTER JOIN threads
62 | ON threads.forum_id = forums.id
63 | GROUP BY
64 | forums.id
65 | , forums.name
66 | ;
67 | /* Results should look like this --
68 | f_id forum threads
69 | 10001 Search Engines 1
70 | 10002 Databases 3
71 | 10003 Applications 0
72 | */
--------------------------------------------------------------------------------
/sample_sql/Forums_04_Scalar_functions.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 7: The SELECT Clause */
2 |
3 | /* Scalar functions */
4 |
5 | SELECT
6 | threads.id AS t_id
7 | , threads.name AS thread
8 | , posts.id AS p_id
9 | , SUBSTRING(posts.post FROM 1 FOR 21) AS excerpt
10 | /* One popular variation --
11 | , LEFT(posts.post,21) AS excerpt
12 | */
13 | FROM
14 | threads
15 | LEFT OUTER JOIN posts
16 | ON posts.thread_id = threads.id
17 | ;
18 | /* Results should look like this --
19 | t_id thread p_id excerpt
20 | 15 Difficulty with join query 201 I'm having a lot of t
21 | 25 How do I get listed in Yahoo? 215 I've figured out how
22 | 25 How do I get listed in Yahoo? 216 Try http://search.yah
23 | 25 How do I get listed in Yahoo? 218 That's it! How did yo
24 | 25 How do I get listed in Yahoo? 219 There's a link at the
25 | 35 People who bought ... also bought ... 222 For each item in the
26 | 45 WHERE clause doesn't work 230 My query has WHERE st
27 | */
28 |
29 | /* To demonstrate string concatenation and COALESCE,
30 | we'll quickly add and populate lastname/firstname
31 | columns in the members table.
32 | */
33 | ALTER TABLE members
34 | ADD lastname VARCHAR(21) NULL
35 | ;
36 | ALTER TABLE members
37 | ADD firstname VARCHAR(21) NULL
38 | ;
39 | UPDATE
40 | members
41 | SET
42 | lastname = 'Trudeau'
43 | , firstname = 'Pierre'
44 | WHERE
45 | id = 42
46 | ;
47 | UPDATE
48 | members
49 | SET
50 | firstname = 'Cher'
51 | WHERE
52 | id = 99
53 | ;
54 | UPDATE
55 | members
56 | SET
57 | lastname = 'Van Damme'
58 | , firstname = 'Jean-Claude'
59 | WHERE
60 | id = 187
61 | ;
62 |
63 | /* The following query may need to be modified to use the
64 | appropriate concatenation operator for your particular
65 | database system. The WHERE clause returns only those members
66 | for which we have supplied a firstname.
67 | */
68 | SELECT
69 | COALESCE(lastname||', ','')||firstname AS fullname
70 | FROM
71 | members
72 | WHERE
73 | firstname IS NOT NULL
74 | ;
75 | /* Results should look like this --
76 | fullname
77 | Trudeau, Pierre
78 | Cher
79 | Van Damme, Jean-Claude
80 | */
81 |
--------------------------------------------------------------------------------
/sample_sql/Forums_05_Foreign_keys.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 10: Relational Integrity */
2 |
3 | /* Add foreign key constraints to the Discussion Forum tables */
4 |
5 |
6 | /* If necessary (it is for MySQL), index the FK columns first */
7 |
8 | ALTER TABLE threads
9 | ADD INDEX forum_ix (forum_id)
10 | ;
11 | ALTER TABLE threads
12 | ADD INDEX starter_ix (starter)
13 | ;
14 |
15 | /* Add the foreign keys */
16 |
17 | ALTER TABLE threads
18 | ADD CONSTRAINT
19 | forum_fk
20 | FOREIGN KEY (forum_id)
21 | REFERENCES forums (id)
22 | ON DELETE CASCADE
23 | ON UPDATE CASCADE
24 | ;
25 | ALTER TABLE threads
26 | ADD CONSTRAINT
27 | starter_fk
28 | FOREIGN KEY (starter)
29 | REFERENCES members (id)
30 | ON DELETE CASCADE
31 | ON UPDATE CASCADE
32 | ;
33 |
--------------------------------------------------------------------------------
/sample_sql/Teams_01_CREATE_ALTER_DROP.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 1: Introduction to SQL */
2 |
3 | /* CREATE, ALTER, DROP */
4 |
5 | CREATE TABLE teams
6 | (
7 | id INTEGER NOT NULL PRIMARY KEY
8 | , name VARCHAR(37) NOT NULL
9 | , conference VARCHAR(2) NULL
10 | );
11 |
12 | ALTER TABLE teams DROP COLUMN conference
13 | ;
14 |
15 | DROP TABLE teams
16 | ;
17 |
--------------------------------------------------------------------------------
/sample_sql/Teams_02_INSERT.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 1: Introduction to SQL */
2 |
3 | /* INSERT */
4 |
5 | CREATE TABLE teams
6 | (
7 | id INTEGER NOT NULL PRIMARY KEY
8 | , name VARCHAR(37) NOT NULL
9 | , conference CHAR(2) NOT NULL
10 | /* The CHECK constraint is discussed in Chapter 9: Data Types.
11 | It is commented out here so as not to confuse you early.
12 | CHECK ( conference IN ( 'AA','A','B','C','D','E','F','G' ) )
13 | */
14 | );
15 |
16 | INSERT INTO teams
17 | ( id , name , conference )
18 | VALUES
19 | ( 9 , 'Riff Raff' , 'F' )
20 | ;
21 |
22 | INSERT INTO teams
23 | ( conference , id, name )
24 | VALUES
25 | ( 'F' , 9 , 'Riff Raff' )
26 | ;
27 | /* This yields a "duplicate key" error. The key in this case is
28 | the id column, which is a primary key. The database system
29 | automatically rejects duplicate values in primary key columns.
30 | */
--------------------------------------------------------------------------------
/sample_sql/Teams_03_DELETE_INSERT.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 1: Introduction to SQL */
2 |
3 | /* INSERT */
4 |
5 | DELETE FROM teams
6 | ;
7 | INSERT INTO teams
8 | ( conference , id, name )
9 | VALUES
10 | ( 'F' , 9 , 'Riff Raff' )
11 | ;
12 |
13 | DELETE FROM teams
14 | ;
15 | INSERT INTO teams
16 | VALUES
17 | ( 9 , 'Riff Raff' , 'F' )
18 | ;
19 |
20 | DELETE FROM teams
21 | ;
22 | INSERT INTO teams
23 | ( conference , id, name )
24 | VALUES
25 | ( 'F' , 9 , 'Riff Raff' )
26 | , ( 'F' , 37 , 'Havoc' )
27 | , ( 'C' , 63 , 'Brewers' )
28 | ;
--------------------------------------------------------------------------------
/sample_sql/Teams_04_UPDATE.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 1: Introduction to SQL */
2 |
3 | /* UPDATE */
4 |
5 | UPDATE
6 | teams
7 | SET
8 | conference = 'E'
9 | WHERE
10 | id = 9
11 | ;
12 |
13 | SELECT
14 | id
15 | , name
16 | , conference
17 | FROM
18 | teams
19 | ;
20 | /* Results should look like this:
21 | id name conference
22 | 9 Riff Raff E
23 | 37 Havoc F
24 | 63 Brewers C
25 | */
--------------------------------------------------------------------------------
/sample_sql/Teams_05_DELETE.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 1: Introduction to SQL */
2 |
3 | /* DELETE */
4 |
5 | DELETE
6 | FROM
7 | teams
8 | WHERE
9 | id = 63
10 | ;
11 |
12 | SELECT
13 | id
14 | , name
15 | , conference
16 | FROM
17 | teams
18 | ;
19 | /* Results should look like this:
20 | id name conference
21 | 9 Riff Raff E
22 | 37 Havoc F
23 | */
--------------------------------------------------------------------------------
/sample_sql/Teams_06_FROM_teans.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 3: The FROM Clause */
2 |
3 | /* parsing syntax error */
4 |
5 | SELECT name, id FROM teans WHERE conference = 'F'
6 | ;
7 |
8 | /* Results should be a syntax error, similar to:
9 |
10 | "Table 'teans' doesn't exist."
11 |
12 | or:
13 |
14 | "Invalid object name 'teans'."
15 |
16 | */
--------------------------------------------------------------------------------
/sample_sql/Teams_07_Games.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 11: Special Structures */
2 |
3 | /* Joining to a table twice */
4 |
5 | /* First, repopulate the teams table */
6 |
7 | DELETE FROM teams
8 | ;
9 | INSERT INTO teams
10 | ( id , name , conference )
11 | VALUES
12 | ( 9 , 'Riff Raff' , 'F' )
13 | , (11 , 'Savages' , 'F' )
14 | , (15 , 'Blue Devils' , 'F' )
15 | , (24 , 'Hurricanes' , 'F' )
16 | ;
17 |
18 | /* Create and populate some games */
19 |
20 | CREATE TABLE games
21 | (
22 | gamedate DATETIME NOT NULL
23 | , location VARCHAR(37) NOT NULL
24 | , hometeam INTEGER NOT NULL
25 | , awayteam INTEGER NOT NULL
26 | );
27 | INSERT INTO games
28 | ( gamedate , location , hometeam , awayteam )
29 | VALUES
30 | ( '2008-09-06' , 'McKenzie' , 9 , 24 )
31 | , ( '2008-09-13' , 'Applewood' , 15 , 9 )
32 | ;
33 |
34 | /* Query to list games with team names. */
35 |
36 | SELECT
37 | games.gamedate
38 | , games.location
39 | , home.name AS hometeam
40 | , away.name AS awayteam
41 | FROM
42 | games
43 | INNER JOIN teams AS home
44 | ON home.id = games.hometeam
45 | INNER JOIN teams AS away
46 | ON away.id = games.awayteam
47 | ;
48 | /* Results should look like this --
49 | gamedate location hometeam awayteam
50 | 2008-09-06 McKenzie Riff Raff Hurricanes
51 | 2008-09-13 Applewood Blue Devils Riff Raff
52 | */
53 |
--------------------------------------------------------------------------------
/sample_sql/test_01_illustrated.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 3: The FROM Clause */
2 |
3 | /* Create and populate a pair of test tables to
4 | illustrate the various types of join
5 | */
6 |
7 | CREATE TABLE A
8 | ( a SMALLINT NOT NULL PRIMARY KEY )
9 | ;
10 | INSERT INTO A
11 | VALUES
12 | (102),(104),(106),(107)
13 | ;
14 | CREATE TABLE B
15 | ( b SMALLINT NOT NULL PRIMARY KEY )
16 | ;
17 | INSERT INTO B
18 | VALUES
19 | (101),(102),(104),(106),(108)
20 | ;
21 |
22 | /* Results for the following queries are
23 | as shown in the illustrations in the book.
24 | */
25 | SELECT
26 | a,b
27 | FROM
28 | A INNER JOIN B
29 | ON a=b
30 | ;
31 |
32 | SELECT
33 | a,b
34 | FROM
35 | A LEFT OUTER JOIN B
36 | ON a=b
37 | ;
38 |
39 | SELECT
40 | a,b
41 | FROM
42 | A RIGHT OUTER JOIN B
43 | ON a=b
44 | ;
45 |
46 | SELECT
47 | a,b
48 | FROM
49 | A FULL OUTER JOIN B
50 | ON a=b
51 | ;
52 |
53 | SELECT
54 | a,b
55 | FROM
56 | A LEFT OUTER JOIN B
57 | ON a=b
58 |
59 | UNION
60 |
61 | SELECT
62 | a,b
63 | FROM
64 | A RIGHT OUTER JOIN B
65 | ON a=b
66 | ORDER BY
67 | COALESCE(a,b)
68 | ;
69 |
70 | SELECT
71 | a,b
72 | FROM
73 | A CROSS JOIN B
74 | ;
--------------------------------------------------------------------------------
/sample_sql/test_02_DECIMAL.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 9: Data Types */
2 |
3 | /* Create and populate a table to test DECIMAL */
4 |
5 | /* We'll use DECIMAL(3,2), to demonstrate what happens
6 | when inserts are attempted using numbers that exceed
7 | the precision or scale.
8 | */
9 |
10 | CREATE TABLE test_decimals
11 | ( d DECIMAL(3,2) NOT NULL PRIMARY KEY )
12 | ;
13 | INSERT INTO test_decimals (d) VALUES ( 9.37 );
14 | INSERT INTO test_decimals (d) VALUES ( 0.567 );
15 |
16 | SELECT
17 | d
18 | FROM
19 | test_decimals
20 | ;
21 | /* Results should look like this --
22 | d
23 | 0.57
24 | 9.37
25 | */
26 |
27 | /* The following may or may not create an error --
28 |
29 | INSERT INTO test_decimals (d) VALUES ( 12.34 );
30 | INSERT INTO test_decimals (d) VALUES ( 888.88 );
31 |
32 | In SQL Server, the message is "Arithmetic overflow error
33 | converting numeric to data type numeric." Seriously.
34 |
35 | */
36 |
37 | SELECT
38 | d
39 | FROM
40 | test_decimals
41 | ;
42 | /* In MySQL, results will look like this --
43 | d
44 | 0.57
45 | 9.37
46 | 12.34
47 | 99.99
48 |
49 | Can you see where 99.99 came from? and why?
50 | and why 12.34 was not treated the same way?
51 | */
--------------------------------------------------------------------------------
/sample_sql/test_03_FLOAT.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 9: Data Types */
2 |
3 | /* Create and populate a table to test FLOAT */
4 |
5 | /* We'll use FLOAT, without explicit precision/scale,
6 | as the syntax varies from one database system to another.
7 | */
8 |
9 | CREATE TABLE test_floats
10 | ( f FLOAT )
11 | ;
12 | INSERT INTO test_floats (f) VALUES ( 9.37 );
13 | INSERT INTO test_floats (f) VALUES ( 0.567 );
14 | INSERT INTO test_floats (f) VALUES ( 12.34 );
15 | INSERT INTO test_floats (f) VALUES ( 888.88 );
16 |
17 | SELECT
18 | f
19 | FROM
20 | test_floats
21 | ;
22 | /* Results should look like this --
23 | f
24 | 0.567
25 | 9.37
26 | 12.34
27 | 888.88
28 | */
29 |
30 |
31 | INSERT INTO test_floats
32 | ( f )
33 | VALUES
34 | ( 7900000000000000000000000 )
35 | ;
36 | INSERT INTO test_floats
37 | ( f )
38 | VALUES
39 | ( 7.9E24 )
40 | ;
41 |
42 | SELECT
43 | f
44 | FROM
45 | test_floats
46 | ;
47 | /* Results should look like this --
48 | f
49 | 0.567
50 | 9.37
51 | 12.34
52 | 888.88
53 | 7.9E24
54 | 7.9E24
55 |
56 | Alternatively 7.9E+24 for the latter.
57 | */
--------------------------------------------------------------------------------
/sample_sql/test_04_SUM_times.sql:
--------------------------------------------------------------------------------
1 | /* Chapter 9: Data Types */
2 |
3 | /* Create and populate a table for TIMEs */
4 |
5 | CREATE TABLE raceresults
6 | (
7 | split VARCHAR(7) NOT NULL
8 | /* Note: not all database systems support the TIME datatype */
9 | , splittime TIME NOT NULL
10 | );
11 | INSERT INTO raceresults VALUES ( 'swim' , '0:20:35' );
12 | INSERT INTO raceresults VALUES ( 'bike' , '1:49:59' );
13 | INSERT INTO raceresults VALUES ( 'run' , '1:28:32' );
14 |
15 | SELECT
16 | *
17 | FROM
18 | raceresults
19 | ;
20 | /* Results should look like this --
21 | split splittime
22 | swim 00:20:35
23 | bike 01:49:59
24 | run 01:28:32
25 | */
26 |
27 | SELECT
28 | SUM(splittime) AS total_time
29 | FROM
30 | raceresults
31 | ;
32 | /* In MySQL, results are unintelligible --
33 | total_time
34 | 29826
35 | */
36 |
37 | SELECT
38 | SUM( TIME_TO_SEC(splittime) ) AS total_seconds
39 | FROM
40 | raceresults
41 | ;
42 | /* TIME_TO_SEC is a MySQL function --
43 | total_seconds
44 | 13146
45 | */
46 |
47 | SELECT
48 | SEC_TO_TIME(
49 | SUM( TIME_TO_SEC(splittime) )
50 | ) AS total_time
51 | FROM
52 | raceresults
53 | ;
54 | /* SEC_TO_TIME is also a MySQL function --
55 | total_time
56 | 03:39:06
57 | */
--------------------------------------------------------------------------------
/shared/archive.css:
--------------------------------------------------------------------------------
1 | /*
2 | * SitePoint code archive for Build Your Own Web Site Using HTML And CSS
3 | * (C) 2006 SitePoint Pty Ltd
4 | *
5 | * For more books and articles visit http://www.sitepoint.com/
6 | *
7 | */
8 | html {
9 | background-color: #003366;
10 | }
11 | body {
12 | color: #143f62;
13 | background-color: #fefff8;
14 | margin: 20px;
15 | padding: 20px;
16 | font-family: sans-serif;
17 | font-size: .75em;
18 | line-height: 1.4em;
19 | }
20 | a:hover {
21 | color: #ffffff;
22 | background-color: #ff6600;
23 | text-decoration: none;
24 | }
25 | h2 a {
26 | text-decoration: none;
27 | }
28 | h1 {
29 | font-size: 1.7em;
30 | font-weight: normal;
31 | text-transform: uppercase;
32 | text-align: right;
33 | margin-bottom: 6px;
34 | }
35 | h2 {
36 | color: #003366;
37 | font-size: 1.3em;
38 | padding: 10px 0 5px 0;
39 | margin-bottom: 10px;
40 | border-bottom: 1px solid #003366;
41 | }
42 | h3 {
43 | color: #ff3603;
44 | font-size: 1.2em;
45 | padding: 0;
46 | }
47 | ul li {
48 | font-weight: bold;
49 | }
50 | ul li a {
51 | font-weight: normal;
52 | }
53 | img {
54 | float: left;
55 | border: 0;
56 | }
57 | .subtitle {
58 | font-size: 0.8em;
59 | }
60 | ol li {
61 | margin-bottom: 5px;
62 | }
63 | code {
64 | font-size: 1.3em;
65 | }
66 | #main {
67 | background: transparent url(book-cover.png) top right no-repeat;
68 | }
--------------------------------------------------------------------------------
/shared/book-cover.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/spbooks/sql1/64540bd036fbf865dc9b69f3c966bfe14457f830/shared/book-cover.png
--------------------------------------------------------------------------------
/shared/sitepoint-logo.gif:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/spbooks/sql1/64540bd036fbf865dc9b69f3c966bfe14457f830/shared/sitepoint-logo.gif
--------------------------------------------------------------------------------