├── .gitignore
├── LICENSE
├── README.md
├── chapter_01
├── README.md
├── images
│ └── sqlite_online.png
├── mysql_db.sql
├── oracle_db.sql
├── postgresql_db.sql
├── sql_server_db.sql
├── sqlite_db.sql
└── sqlite_online.sql
├── chapter_02
├── README.md
├── images
│ └── sqlite_online.png
├── mysql_db.sql
├── oracle_db.sql
├── postgresql_db.sql
├── sql_server_db.sql
├── sqlite_db.sql
└── sqlite_online.sql
├── chapter_04
├── README.md
├── dbdiagram.sql
├── images
│ ├── dbdiagram.png
│ └── er-diagram.png
└── workbench.mwb
├── chapter_05
├── README.md
├── dbdiagram.sql
├── images
│ ├── dbdiagram.png
│ └── er-diagram.png
└── workbench.mwb
├── chapter_06
├── README.md
├── dbdiagram.sql
├── images
│ ├── dbdiagram.png
│ └── er-diagram.png
└── workbench.mwb
├── chapter_07
├── README.md
├── dbdiagram.sql
├── images
│ ├── dbdiagram.png
│ └── er-diagram.png
└── workbench.mwb
├── chapter_08
├── README.md
├── chatgpt_request.md
├── dbdiagram.sql
├── images
│ ├── dbdiagram.png
│ └── er-diagram.png
└── workbench.mwb
└── images
└── Hao-Hi.png
/.gitignore:
--------------------------------------------------------------------------------
1 | .DS_Store
2 | chapter_08/workbench.mwb.bak
3 |
--------------------------------------------------------------------------------
/LICENSE:
--------------------------------------------------------------------------------
1 | MIT License
2 |
3 | Copyright (c) 2023 Qiang Hao and Michael Tsikerdekis
4 |
5 | Permission is hereby granted, free of charge, to any person obtaining a copy
6 | of this software and associated documentation files (the "Software"), to deal
7 | in the Software without restriction, including without limitation the rights
8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
9 | copies of the Software, and to permit persons to whom the Software is
10 | furnished to do so, subject to the following conditions:
11 |
12 | The above copyright notice and this permission notice shall be included in all
13 | copies or substantial portions of the Software.
14 |
15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
21 | SOFTWARE.
22 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | # Grokking Relational Database Design
2 |
3 | [
](https://mng.bz/1J2q)
4 |
5 | **A friendly illustrated guide to designing and implementing your first database.**
6 |
7 | A well-constructed database is easy to understand, query, manage, and scale when your app needs to grow. In Grokking Relational Database Design you’ll learn the basics of relational database design including how to name fields and tables, which data to store where, how to eliminate repetition, good practices for data collection and hygiene, and much more. You won’t need a computer science degree or in-depth knowledge of programming—the book’s practical examples and down-to-earth definitions are beginner-friendly.
8 |
9 | In [Grokking Relational Database Design](https://mng.bz/1J2q), you’ll learn how to:
10 |
11 | - Query and create databases using Structured Query Language (SQL)
12 | - Design databases from scratch
13 | - Implement and optimize database designs
14 | - Take advantage of generative AI when designing databases
15 |
16 |
17 | ## Table of contents (for this code repo)
18 |
19 | [This book](https://mng.bz/1J2q) is currently in the Manning Early Access Program (MEAP). Via MEAP, you can read chapters as they are written, and get the finished version as soon as it’s ready, and receive the print book long before it's in bookstores.
20 |
21 | There are currently 8 chapters planned for this book. The following table of contents lists the chapters that are currently available in the MEAP, and the chapters that are planned for the final book.
22 |
23 | - Chapter 1 - Introduction to Database and SQL ([code](./chapter_01/))
24 | - Chapter 2 - Related Tables and More SQL ([code](./chapter_02/))
25 | - Chapter 3 - Overview of Database Design (*No code*)
26 | - Chapter 4 - Entities and Attributes ([code](./chapter_04/))
27 | - Chapter 5 - Relationships ([code](./chapter_05/))
28 | - Chapter 6 - Normalization and Implementation ([code](./chapter_06/))
29 | - Chapter 7 - Security and Optimization ([code](./chapter_07/))
30 | - Chapter 8 - Database Design in the Age of Generative AI ([code](./chapter_08/))
31 |
32 | Interested? You can [check out this book on Manning](https://mng.bz/1J2q) directly, and start reading now.
33 |
34 | ## Authors
35 | [Qiang Hao](https://qhao.info/) ([@Neo-Hao](https://github.com/Neo-Hao)) and [Michail Tsikerdekis](https://michael.tsikerdekis.com) ([@tsikerdekis](https://github.com/tsikerdekis))
36 |
--------------------------------------------------------------------------------
/chapter_01/README.md:
--------------------------------------------------------------------------------
1 | # Introduction to databases and SQL
2 |
3 | The SQL code snippets covered in this chapter are all contained in this folder. The SQL code snippets covered in this chapter work perfectly with MySQL, MariaDB, SQLite, and PostgreSQL.
4 |
5 | If you are using SQL Server, you should refer to the SQL script contained in this folder and pay attention to the following differences that were made to make the script compatible with SQL Server:
6 |
7 | * `NVARCHAR(MAX)` was used instead of `TEXT`: SQL Server doesn't support `TEXT` data type.
8 | * Data insertion of string values was changed from `'...'` to `N'...'`: SQL Server requires the `N` prefix for string values, e.g., `N'Apple'`. SQL Server uses the UCS-2 encoding for string values, which is a subset of UTF-16. The `N` prefix tells SQL Server to use UTF-16 encoding for the string value.
9 |
10 | If you are using SQLite database, you should refer to the SQL script contained in this folder and pay attention to the following differences that were made to make the script compatible with SQLite database:
11 |
12 | * `TEXT` was used instead of `VARCHAR`: `VARCHAR` is the same as `TEXT` and has no length limit in SQLite.
13 | * `TEXT` was used instead of `DECIMAL`: SQLite doesn't support `DECIMAL` data type. `REAL` is typically used instead of `DECIMAL` in SQLite when precision doesn't matter. When precision matters, `TEXT` is typically used in practice instead of `DECIMAL` in SQLite.
14 |
15 |
19 |
20 | How to load the prepared scripts using different RDBMS and tools are covered in the following subsections.
21 |
22 | - [SQLite online](#sqlite-online)
23 | - [SQLite database](#sqlite-database)
24 | - [Install SQLite on Mac](#install-sqlite-on-mac)
25 | - [Install SQLite on Windows](#install-sqlite-on-windows)
26 | - [Install SQLite on Linux](#install-sqlite-on-linux)
27 | - [Load the prepared SQLite script](#load-the-prepared-sqlite-script)
28 | - [MySQL database](#mysql-database)
29 | - [Install and start MySQL on Mac](#install-and-start-mysql-on-mac)
30 | - [Install and start MySQL on Windows](#install-and-start-mysql-on-windows)
31 | - [Install and start MySQL on Linux](#install-and-start-mysql-on-linux)
32 | - [Load the prepared MySQL script](#load-the-prepared-mysql-script)
33 | - [PostgreSQL database](#postgresql-database)
34 | - [Install and start PostgreSQL on Mac](#install-and-start-postgresql-on-mac)
35 | - [Install and start PostgreSQL on Windows](#install-and-start-postgresql-on-windows)
36 | - [Install and start PostgreSQL on Linux](#install-and-start-postgresql-on-linux)
37 | - [Load the prepared PostgreSQL script](#load-the-prepared-postgresql-script)
38 | - [SQL Server database](#sql-server)
39 | - [Install and start SQL server on Mac](#install-and-start-sql-server-on-mac)
40 | - [Install and start SQL server on Windows](#install-and-start-sql-server-on-windows)
41 | - [Install and start SQL server on Linux](#install-and-start-sql-server-on-linux)
42 | - [Load the prepared SQL server script](#load-the-prepared-sql-server-script)
43 | - [Oracle database](#oracle-database)
44 | - [Install and start Oracle database on Mac or Linux](#install-and-start-oracle-database-on-mac-or-linux)
45 | - [Install and start Oracle database on Windows](#install-and-start-oracle-database-on-windows)
46 | - [Load the prepared Oracle script](#load-the-prepared-oracle-script)
47 |
48 |
49 | ## SQLite online
50 |
51 | SQLite online is a web-based tool that you can use to execute SQL queries. You can access it at [SQLite online](https://sqliteonline.com/).
52 |
53 | The script prepared for SQLite online is [`sqlite_online.sql`](./sqlite_online.sql). You can load the prepared script by:
54 |
55 | 1. Navigate to SQLite Online (https://sqliteonline.com)
56 | 2. Click _Import_ and load `sqlite_online.sql`
57 | 3. Click _Okay_
58 |
59 | Now you should see the script executed in the right sidebar. You are ready to type into the console, follow the book, and execute SQL queries.
60 |
61 |
62 |
63 | ## SQLite database
64 |
65 | SQLite is a lightweight RDBMS that you can use on your computer. If you don't have SQLite installed on your computer, you can follow the following approaches to install SQLite.
66 |
67 | ### Install SQLite on Mac
68 |
69 | If you are using a Mac, it is likely that SQLite is already installed on your computer. You can check it by running the following command in your terminal:
70 |
71 | ```
72 | sqlite3
73 | ```
74 |
75 | If you see the output similar to the following, it means that SQLite is already installed on your computer:
76 |
77 | ```
78 | SQLite version ...
79 | Enter ".help" for usage hints.
80 | Connected to a transient in-memory database.
81 | Use ".open FILENAME" to reopen on a persistent database.
82 | sqlite>
83 | ```
84 |
85 | You can quit by typing `.quit` and pressing `Enter`, or press `Command + D`.
86 |
87 | If you don't have SQLite installed, you can download the precompiled binaries for Mac OS from [SQLite website](https://www.sqlite.org/download.html), extract the archive, right click on the sqlite3 file, and click Open. This will allow you to execute a file from an untrusted developer.
88 |
89 | ### Install SQLite on Windows
90 |
91 | If you are using a Windows, you can download the ZIP file for Windows from [SQLite website](https://www.sqlite.org/download.html), (Look for this sqlite-tools-win32-x86-xxxxx.zip) extract the archive, right click on the sqlite3 file, and click Open. The software will then open in the command line and you can execute any sql commands after that.
92 |
93 | ### Install SQLite on Linux
94 |
95 | If you are using a Linux, you can download the ZIP file for Linux from [SQLite website](https://www.sqlite.org/download.html), extract the archive, right click on the sqlite3 file, and click Open. The software will then open in the command line and you can execute any sql commands after that.
96 |
97 | ### Load the prepared SQLite script
98 |
99 | The script prepared for SQLite database is [`sqlite_db.sql`](./sqlite_db.sql). You can load the prepared script by:
100 |
101 | 1. Open the terminal, navigate into the `chapter_01` folder of this repository
102 | 2. Run the following command to create a new database named `onlinestore.db`, and you will be in the SQLite console environment:
103 |
104 | ```
105 | sqlite3 onlinestore.db
106 | ```
107 |
108 | 3. In the same SQLite console environment (e.g., the line prompt starts with `sqlite>`), run the following command to load the script:
109 |
110 | ```
111 | .read sqlite_db.sql
112 | ```
113 |
114 | 4. In the same SQLite console environment, check if the table is created by running the following command:
115 |
116 | ```
117 | .tables
118 | ```
119 |
120 | If you see `products`, that means the script is loaded successfully, and the `product` table has been created. In the same SQLite console environment, you can run any SQL queries you want, including the examples covered by Chapter 1. You can always quit the SQLite console by typing `.quit` and pressing `Enter`.
121 |
122 | ## MySQL database
123 |
124 | MySQL is a popular open-source RDBMS. We would recommend you to install MySQL in different ways depending on your operating system.
125 |
126 | ### Install and start MySQL on Mac
127 |
128 | The recommended approach to install MySQL on a Mac is via [Homebrew](https://brew.sh/). If you don't have Homebrew installed, you can find the latest installation instructions on [Homebrew website](https://brew.sh/), and follow the instructions to install Homebrew first.
129 |
130 | Once you have Homebrew installed, you can run the following command to install MySQL in the terminal:
131 |
132 | ```
133 | brew install mysql
134 | ```
135 |
136 | You may need to manually start MySQL by running the following command:
137 |
138 | ```
139 | brew services start mysql
140 | ```
141 |
142 | You can always stop MySQL by running the following command:
143 |
144 | ```
145 | brew services stop mysql
146 | ```
147 |
148 | ### Install and start MySQL on Windows
149 |
150 | If you are using a Windows, you can download the ZIP file for Windows from [MySQL website](https://dev.mysql.com/downloads/mysql/). Use the installer and download the full installer (e.g., mysql-installer-community-8.0.33.0.msi) (not the web installer). Note: You do not have to make an Oracle account, look for the "No thanks, just start my download" at the bottom of the page.
151 |
152 | 1. Double click on the installer and follow the instructions.
153 |
154 | 2. Then hit "Add" from the right hand side panel of options.
155 |
156 | 3. Proceed with installing the "Developer Default" setup type. Keep the default options in the proceeding dialogs.
157 |
158 | 4. Setup a password for the super administrator (root) of the database system.
159 |
160 | 5. Follow the steps for configuration of the products. Keep all settings as default. Enter the password that you just configured when/if asked for it.
161 |
162 | 6. Once the installation is complete, type MySQL in the Start menu in Windows and click on the "MySQL 8.0 Command Line Client"
163 |
164 | 7. When asked for a password, enter the one configured for the root user (super administrator).
165 |
166 | ### Install and start MySQL on Linux
167 |
168 | You are recommended to follow the steps listed on [the MySQL official website](https://dev.mysql.com/doc/mysql-shell/8.0/en/mysql-shell-install-linux-quick.html) to install MySQL on a Linux machine.
169 |
170 | To start MySQL, you can run the following command:
171 |
172 | ```
173 | service mysql start
174 | ```
175 |
176 | To stop MySQL, you can run the following command:
177 |
178 | ```
179 | service mysql stop
180 | ```
181 |
182 | ### Load the prepared MySQL script
183 |
184 | The script prepared for MySQL database is [`mysql_db.sql`](./mysql_db.sql). You can load the prepared script by following the steps below.
185 |
186 | #### Linux and Mac
187 |
188 | 1. Open the terminal, navigate into the `chapter_01` folder of this repository
189 | 2. Run the following command:
190 |
191 | ```
192 | mysql -u root < mysql_db.sql
193 | ```
194 |
195 | If you have set up a password for your MySQL server, you can run the following command instead:
196 |
197 | ```
198 | mysql -u root -p < mysql_db.sql
199 | ```
200 |
201 | After that, you will be prompted to enter your password.
202 |
203 | #### Windows
204 |
205 | 1. Open "MySQL 8.0 Command Line Client"
206 |
207 | 2. Enter your root password. If the window closes it means that you either entered the password wrong or the database service is stopped. To start it, type taskmgr or "Task Manager" in the Start menu, then under Services look for MySQL80 and start the service if it is stopped.
208 |
209 | 3. Use the following command (replace the path to point to the location that you have downloaded the SQL files):
210 |
211 | ```
212 | source C:\Users\user\Downloads\database-design-from-scratch\chapter_01\mysql_db.sql
213 | ```
214 |
215 | 4. If you see the following, it means that everything was been imported correctly.
216 |
217 | ```
218 | Query OK, 1 row affected (0.00 sec)
219 |
220 | Database changed
221 | Query OK, 0 rows affected, 1 warning (0.01 sec)
222 |
223 | Query OK, 0 rows affected (0.02 sec)
224 |
225 | Query OK, 10 rows affected (0.01 sec)
226 | Records: 10 Duplicates: 0 Warnings: 0
227 | ```
228 |
229 | 5. You can verify that the product has been imported by running the following commands:
230 |
231 | ```
232 | USE onlinestore;
233 | SELECT * FROM product;
234 | ```
235 |
236 | 6. You should see records on a table. Now you have loaded the script. To query the database and table created by the script, you will need to navigate to the MySQL console environment. You can do this by running the following command:
237 |
238 | ```
239 | mysql -u root
240 | ```
241 |
242 | In the MySQL console environment, you can run any SQL queries you want, including the examples covered by Chapter 1. You can always quit the MySQL console by typing `quit` and pressing `Enter`.
243 |
244 | ## PostgreSQL database
245 |
246 | PostgreSQL is a popular open-source RDBMS. If you don't have PostgreSQL installed on your computer, you can follow the following approaches to install SQLite.
247 |
248 | ### Install and start PostgreSQL on Mac
249 |
250 | The recommended approach to install MySQL on a Mac is via [Homebrew](https://brew.sh/). If you don't have Homebrew installed, you can find the latest installation instructions on [Homebrew website](https://brew.sh/), and follow the instructions to install Homebrew first.
251 |
252 | Once you have Homebrew installed, you can run the following command to install MySQL in the terminal:
253 |
254 | ```
255 | brew install postgresql@15
256 | ```
257 |
258 | You may need to manually start PostgreSQL by running the following command:
259 |
260 | ```
261 | brew services start postgresql@15
262 | ```
263 |
264 | You can always stop PostgreSQL by running the following command:
265 |
266 | ```
267 | brew services stop postgresql@15
268 | ```
269 |
270 | On Windows or Linux a superuser will be set up automatically when you install PostgreSQL. The superuser is named `postgres` and its default password is empty. However, it may not be so on Mac. To make it consistent with other operating systems, you may need to locate the `createuser` on your Mac, and use it to create a superuser named `postgres` with an empty password.
271 |
272 | The location of `createuser` may vary depending on the version of your Mac OS. Here are a few possibilities:
273 |
274 | * `/usr/local/opt/postgresql@15/bin/createuser`
275 | * `/usr/local/Cellar/postgresql@15/14.0/bin/createuser`
276 | * `/opt/homebrew/bin/createuser`
277 | * `/opt/homebrew/opt/postgresql@15/bin/createuser`
278 |
279 | If you tried the above few options but still can't locate the `createuser` command, you can try to run the following command to locate it:
280 |
281 | ```
282 | sudo find / -name createuser
283 | ```
284 |
285 | When you locate the `createuser` command, you can run the following command to create a superuser named `postgres` with an empty password (you may need to replace the path with the one you found):
286 |
287 | ```
288 | sudo /opt/homebrew/opt/postgresql@15/bin/createuser -s postgres
289 | ```
290 |
291 | The above command assumes that you run it from the root directory `/`. If you are in the directory where you found the `createuser` command, you can simply run the following command:
292 |
293 | ```
294 | sudo ./createuser -s postgres
295 | ```
296 |
297 | ### Install and start PostgreSQL on Windows
298 |
299 | 1. If you are using a Windows, you can download the Windows installer from [PostgreSQL website](https://www.postgresql.org/download/windows/).
300 |
301 | 2. Follow the installation instructions. When asked to setup a password make a note of it, this will be the super user (root) password for the database system.
302 |
303 | 3. At the end of the installation, you may skip installing additional tools from stack builder (they are not necessary for our purposes).
304 |
305 | ### Install and start PostgreSQL on Linux
306 |
307 | You are recommended to follow the steps listed on [the PostgreSQL official website](https://www.postgresql.org/download/linux/) to install PostgreSQL on a Linux machine.
308 |
309 | To start PostgreSQL, you can run the following command:
310 |
311 | ```
312 | service postgresql start
313 | ```
314 |
315 | To stop PostgreSQL, you can run the following command:
316 |
317 | ```
318 | service postgresql start
319 | ```
320 |
321 | ### Load the prepared PostgreSQL script
322 |
323 | Before loading the script, you will need to create a database named `onlinestore` and use this database via the PostgreSQL console environment first. Different from SQLite and MySQL, there are no easy approach to merge these two steps into the script.
324 |
325 | #### Linux and Mac
326 |
327 | You can follow the following steps to load the prepared script:
328 |
329 | 1. Open the terminal, and navigate into the `chapter_01` folder of this repository
330 |
331 | 2. Log in to the PostgreSQL console environment by running the following command:
332 |
333 | ```
334 | psql -U postgres
335 | ```
336 |
337 |
338 | 1. Open the terminal, and navigate into the `chapter_02` folder of this repository
339 |
340 | 2. Log in to the PostgreSQL console environment by running the following command:
341 |
342 | ```
343 | psql -U postgres
344 | ```
345 | 3. In the console environment, create a database named `onlinestore` by running the following command:
346 |
347 | ```
348 | CREATE DATABASE onlinestore;
349 | ```
350 |
351 | 4. In the console environment, use the database `onlinestore` by running the following command:
352 |
353 | ```
354 | \c onlinestore
355 | ```
356 |
357 | 5. Now you are ready to load the prepared script. The script prepared for PostgreSQL database is [`postgresql_db.sql`](./postgresql_db.sql). In the console environment, run the following command:
358 |
359 | ```
360 | \i postgresql_db.sql
361 | ```
362 |
363 | #### Windows
364 |
365 | 1. Open the "SQL Shell (psql)" from the Start Menu.
366 |
367 | 2. Hit enter to use the default option and provide the password when asked for the default user. This is a correct interaction that leads to successful prompt:
368 |
369 | ```
370 | Server [localhost]:
371 | Database [postgres]:
372 | Port [5432]:
373 | Username [postgres]:
374 | Password for user postgres:
375 | psql (15.3)
376 | WARNING: Console code page (437) differs from Windows code page (1252)
377 | 8-bit characters might not work correctly. See psql reference
378 | page "Notes for Windows users" for details.
379 | Type "help" for help.
380 |
381 | postgres=#
382 | ```
383 |
384 | 3. In the console environment, create a database named `onlinestore` by running the following command:
385 |
386 | ```
387 | CREATE DATABASE onlinestore;
388 | ```
389 |
390 | 4. In the console environment, use the database `onlinestore` by running the following command:
391 |
392 | ```
393 | \c onlinestore
394 | ```
395 |
396 | 5. Now you are ready to load the prepared script. The script prepared for PostgreSQL database is [`postgresql_db.sql`](./postgresql_db.sql). In the console environment, run the following command:
397 |
398 | ```
399 | \i postgresql_db.sql
400 | ```
401 |
402 | OR you may provide an exact path
403 |
404 | ```
405 | \i C:/Users/user/Downloads/database-design-from-scratch/chapter_01/postgresql_db.sql
406 | ```
407 |
408 | Note: The slashes are not the normal ones used in Windows (\\) but the forward slash needs to be used instead (/).
409 |
410 | A successful import should show:
411 |
412 | ```
413 | psql:C:/Users/tsike/Desktop/database-design-from-scratch/chapter_01/postgresql_db.sql:10: NOTICE: table "product" does not exist, skipping
414 | DROP TABLE
415 | CREATE TABLE
416 | INSERT 0 10
417 | ```
418 |
419 | In the same console environment, you can run any SQL queries you want, including the examples covered by Chapter 1. You can always quit the PostgreSQL console by typing `\q` and pressing `Enter`.
420 |
421 | ## SQL server
422 |
423 | ### Install and start SQL server on Mac
424 |
425 | Microsoft doesn’t support running an SQL server database directly on a Mac computer. You are recommended to run a Linux/Windows virtual machine first, and then install Oracle database on the virtual machine. [You can also use a Docker to achieve this goal](https://database.guide/how-to-install-sql-server-on-a-mac/).
426 |
427 | ### Install and start SQL server on Windows
428 |
429 | You will need either the *Express edition* or the *Developer edition* for this purpose. Both versions are free, but the Express edition is limited in features. The Developer edition is also free but for development and testing purposes only, not for production.
430 |
431 | You can follow the steps below to install SQL server on Windows:
432 |
433 | 1. Go to https://www.microsoft.com/en-us/sql-server/sql-server-downloads to download the installer for the edition you want.
434 | 2. Run the installer. You will be presented with a few options like "Basic", "Custom", and "Download Media". The "Basic" option should be fine for most cases, which will install the default configuration of SQL Server.
435 | 3. After installation, you may need to install SQL Server Management Studio (SSMS) depending on if you want a graphical dashboard to manage SQL server. A link to download SSMS is usually provided at the end of the SQL Server installation process, or you can download it from https://learn.microsoft.com/en-us/sql/ssms/download-sql-server-management-studio-ssms?view=sql-server-ver16.
436 | 4. After installation, you may need to configure SQL Server, which involves setting up user accounts, configuring network protocols, or setting database properties. All such tasks can be done through SQL Server Management Studio. When everything is wrapped up, you may need to restart your computer.
437 |
438 | ### Install and start SQL server on Linux
439 |
440 | You are recommended to [follow these steps] (https://blog.devart.com/how-to-install-sql-server-on-linux-ubuntu.html) to install SQL server on a Linux machine. If you want a graphical interface to manage your SQL server, then dbForge Studio is a good option. The above link also provides instructions on how to install dbForge Studio on a Linux machine.
441 |
442 | ### Load the prepared SQL server script
443 |
444 | The script prepared for MySQL database is [`sql_server_db.sql`](./sql_server_db.sql). You can load the prepared script by following the steps below.
445 |
446 | #### Linux
447 |
448 | You can follow the following steps to load the prepared script:
449 |
450 | 1. Open the terminal, and navigate into the `chapter_01` folder of this repository
451 | 2. You need to connect to your SQL Server instance via your terminal. If you haven't set up any users yet, you'll likely need to connect with the default sa (system administrator) user. Run the following command in your terminal. You will be prompted to enter the password for the sa user -- if you follow the above link to install and configure your SQL server, you have already set up the password for the sa user. Please use that password.
452 | ```
453 | sqlcmd -S localhost -U SA
454 | ```
455 |
456 | 3. Once connected to the SQL Server, you can execute your script file (`sql_server_db.sql`) you can run it using the following command:
457 | ```
458 | :r ./sql_server_db.sql
459 | ```
460 |
461 | 4. After the script has executed, you can verify that the database and tables were created successfully. Use SQL commands to check:
462 |
463 | ```
464 | USE onlinestore;
465 | SELECT * FROM product;
466 | ```
467 |
468 | #### Windows
469 |
470 | 1. Open Microsoft SQL Server Management Studio (SSMS) and connect to the server. If you are using the Express edition, the server name should be `localhost\SQLEXPRESS`. If you are using the Developer edition, the server name should be `localhost`. You can use Windows Authentication to connect to the server.
471 | 2. Navigate to File -> Open -> File, and load the script [`sql_server_db.sql`](./sql_server_db.sql).
472 | 3. Click the Execute button to execute the script. You should see the following output in the Messages tab:
473 |
474 | ```
475 | (1 row affected)
476 | (1 row affected)
477 | (10 rows affected)
478 | ```
479 | 4. You can verify that the product has been imported by running the following commands in a new query window (Ctrl + N):
480 |
481 | ```
482 | USE onlinestore;
483 | SELECT * FROM product;
484 | ```
485 |
486 | ## Oracle database
487 |
488 | ### Install and start Oracle database on Mac or Linux
489 |
490 | Oracle doesn’t support running an Oracle database directly on a Mac computer. [You are recommended to run a virtual machine first, and then install Oracle database on the virtual machine](https://database.guide/how-to-install-oracle-on-a-mac/).
491 |
492 | Installing Oracle on a Linux machine is complicated and doesn't serve the learning purposes. If you need to do so, you can follow the steps listed on [the Oracle database official website](https://docs.oracle.com/en/java/java-components/advanced-management-console/2.21/install-guide/oracle-database-installation-and-configuration-advanced-management-console.html#GUID-DF2557D8-C727-4243-8387-6154E5C1C36A) to install Oracle database on a Linux machine. Please note that you need to use a supported Linux distribution like Oracle Linux, Red Hat Enterprise Linux, CentOS, or SUSE Linux Enterprise Server, and will need to create an Oracle account to download the installer.
493 |
494 | ### Install and start Oracle database on Windows
495 |
496 | You can download the Oracle database installer from [Oracle website](https://www.oracle.com/database/technologies/oracle-database-software-downloads.html). Scroll down and download the free version of Oracle, e.g., Oracle Database 21c XE (Express Edition). If it is a zip, remember to unzip the file once downloaded.
497 |
498 | Follow the instructions to install Oracle database on your Windows machine:
499 |
500 | 1. Run the installer (setup.msi). Setup a root password for the database and make a note of it. Then proceed with the installation instructions.
501 | 2. After installation, you may need to install Oracle SQL Developer depending on if you want a graphical dashboard to manage Oracle database. A link to download Oracle SQL Developer is usually provided at the end of the Oracle database installation process, or you can download it from https://www.oracle.com/tools/downloads/sqldev-downloads.html.
502 | 3. After installation, you may need to configure Oracle database, which involves setting up user accounts, configuring network protocols, or setting database properties. All such tasks can be done through Oracle SQL Developer. When everything is wrapped up, you may need to restart your computer.
503 |
504 | ### Load the prepared Oracle script
505 |
506 | 1. Open SQL developer and connect to the database. Look for the plus icon on the left hand side of the screen and click on it. Then select "New Database Connection". You will be presented with a window to enter the connection details.
507 | 2. You can use the following information to connect to the database. If you are using the Express edition, the hostname should be `localhost`. If you are using the Developer edition, the hostname should be `localhost`. The port should be `1521`. The SID should be `XE`. The username is `sys` with role `SYSDBA` and the password that you've set during the installation. Also make sure to name the connection.
508 | 3. After the connection opens, use File -> Open from the left hand side corner of the top menu and open the oracle_db.sql file. Then click on the green play button to execute the script ("Run Script" or use F5). You should see the following output in the Script Output tab:
509 |
510 | ```
511 | PL/SQL procedure successfully completed.
512 |
513 |
514 | Table PRODUCT created.
515 |
516 |
517 | 1 row inserted.
518 |
519 |
520 | 1 row inserted.
521 |
522 |
523 | 1 row inserted.
524 |
525 |
526 | 1 row inserted.
527 |
528 |
529 | 1 row inserted.
530 |
531 |
532 | 1 row inserted.
533 |
534 |
535 | 1 row inserted.
536 |
537 |
538 | 1 row inserted.
539 |
540 |
541 | 1 row inserted.
542 |
543 |
544 | 1 row inserted.
545 |
546 | ```
547 |
548 | 4. You can verify that the product has been imported by running the following commands in a new query window ("Unshared SQL Worksheet" or Ctrl + Shift + N):
549 |
550 | ```
551 | SELECT * FROM product;
552 | ```
--------------------------------------------------------------------------------
/chapter_01/images/sqlite_online.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/chapter_01/images/sqlite_online.png
--------------------------------------------------------------------------------
/chapter_01/mysql_db.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************************
2 | RDBMS: MySQL
3 | Create Date: 05/20/2023
4 | Author: Qiang Hao
5 | Description: Create a product table and insert some data for the onlinestore database.
6 | Note: This script is for MySQL 8.0 or above.
7 | *************************************************************************************/
8 |
9 | -- Create the onlinestore database if it doesn't exist.
10 | CREATE DATABASE IF NOT EXISTS onlinestore;
11 |
12 | -- Use the onlinestore database.
13 | USE onlinestore;
14 |
15 | -- Create the product table and insert some data.
16 | DROP TABLE IF EXISTS product;
17 | CREATE TABLE product (
18 | product_id INT PRIMARY KEY,
19 | name TEXT NOT NULL,
20 | description TEXT NOT NULL,
21 | price DECIMAL(5, 2) NOT NULL,
22 | manufacturer TEXT NOT NULL
23 | );
24 |
25 | INSERT INTO
26 | product (
27 | product_id,
28 | name,
29 | description,
30 | price,
31 | manufacturer
32 | )
33 | VALUES
34 | (
35 | 1,
36 | 'Atomic Nose Hair Trimmer',
37 | 'Trim your nose hairs with the precision of an atomic clock!',
38 | 19.99,
39 | 'Mad Inventors Inc.'
40 | ),
41 | (
42 | 2,
43 | 'Selfie Toaster',
44 | 'Get your face on your toast every morning with our selfie toaster!',
45 | 24.99,
46 | 'Goofy Gadgets Corp.'
47 | ),
48 | (
49 | 3,
50 | 'Cat-Poop Coffee',
51 | 'The only coffee made from the finest cat poop beans!',
52 | 29.99,
53 | 'Absurd Accessories'
54 | ),
55 | (
56 | 4,
57 | 'Inflatable Briefcase',
58 | 'Need more storage space? Inflate our briefcase to double its size!',
59 | 39.99,
60 | 'Wacky Wares Ltd.'
61 | ),
62 | (
63 | 5,
64 | 'Unicorn Horn Polish',
65 | 'Keep your unicorn''s horn shiny and smooth with our magical polish!',
66 | 9.99,
67 | 'Silly Supplies Co.'
68 | ),
69 | (
70 | 6,
71 | 'The Mind Probe',
72 | 'A device from Star Wars that can extract information directly from a person''s mind.',
73 | 19.99,
74 | 'Mad Inventors Inc.'
75 | ),
76 | (
77 | 7,
78 | 'Lightsabers',
79 | 'Elegant and deadly energy swords wielded by Jedi and Sith alike.',
80 | 25,
81 | 'Mad Inventors Inc.'
82 | ),
83 | (
84 | 8,
85 | 'The Sonic Screwdriver',
86 | 'A versatile tool capable of performing a wide variety of tasks, from unlocking doors to repairing electronics.',
87 | 15.1,
88 | 'Absurd Accessories'
89 | ),
90 | (
91 | 9,
92 | 'The Infinite Improbability Generator',
93 | 'A device that can create impossible and absurd events, such as a spaceship suddenly turning into a giant sperm whale.',
94 | 9.99,
95 | 'Silly Supplies Co.'
96 | ),
97 | (
98 | 10,
99 | 'The Neuralyzer',
100 | 'A flashy device that erases people''s memories of specific events or encounters.',
101 | 33.55,
102 | 'Silly Supplies Co.'
103 | );
--------------------------------------------------------------------------------
/chapter_01/oracle_db.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************************
2 | RDBMS: Oracle
3 | Create Date: 05/20/2023
4 | Author: Qiang Hao
5 | Description: Create a product table and insert some data for the onlinestore database.
6 | Note 1: This script is for Oracle 18c or above.
7 | Note 2: This script assumes that a database is created and used.
8 | *************************************************************************************/
9 |
10 | -- Assuming a schema 'onlinestore' is already created and used
11 |
12 | -- Drop the product table if it exists (using PL/SQL)
13 | DECLARE
14 | e_table_missing EXCEPTION;
15 | PRAGMA EXCEPTION_INIT(e_table_missing, -00942);
16 | BEGIN
17 | EXECUTE IMMEDIATE 'DROP TABLE product';
18 | EXCEPTION
19 | WHEN e_table_missing THEN NULL;
20 | END;
21 | /
22 |
23 | -- Create the product table
24 | CREATE TABLE product (
25 | product_id NUMBER PRIMARY KEY, -- NUMBER is Oracle's equivalent of INT or DECIMAL in MySQL
26 | name VARCHAR2(255) NOT NULL, -- VARCHAR2 is Oracle's equivalent of TEXT in MySQL
27 | description VARCHAR2(4000) NOT NULL,
28 | price NUMBER(5, 2) NOT NULL, -- NUMBER(5, 2) is Oracle's equivalent of DECIMAL(5, 2) in MySQL
29 | manufacturer VARCHAR2(255) NOT NULL
30 | );
31 |
32 | -- Insert data into the product table
33 | INSERT INTO product (product_id, name, description, price, manufacturer) VALUES (1, 'Atomic Nose Hair Trimmer', 'Trim your nose hairs with the precision of an atomic clock!', 19.99, 'Mad Inventors Inc.');
34 | INSERT INTO product (product_id, name, description, price, manufacturer) VALUES (2, 'Selfie Toaster', 'Get your face on your toast every morning with our selfie toaster!', 24.99, 'Goofy Gadgets Corp.');
35 | INSERT INTO product (product_id, name, description, price, manufacturer) VALUES (3, 'Cat-Poop Coffee', 'The only coffee made from the finest cat poop beans!', 29.99, 'Absurd Accessories');
36 | INSERT INTO product (product_id, name, description, price, manufacturer) VALUES (4, 'Inflatable Briefcase', 'Need more storage space? Inflate our briefcase to double its size!', 39.99, 'Wacky Wares Ltd.');
37 | INSERT INTO product (product_id, name, description, price, manufacturer) VALUES (5, 'Unicorn Horn Polish', 'Keep your unicorn''s horn shiny and smooth with our magical polish!', 9.99, 'Silly Supplies Co.');
38 | INSERT INTO product (product_id, name, description, price, manufacturer) VALUES (6, 'The Mind Probe', 'A device from Star Wars that can extract information directly from a person''s mind.', 19.99, 'Mad Inventors Inc.');
39 | INSERT INTO product (product_id, name, description, price, manufacturer) VALUES (7, 'Lightsabers', 'Elegant and deadly energy swords wielded by Jedi and Sith alike.', 25, 'Mad Inventors Inc.');
40 | INSERT INTO product (product_id, name, description, price, manufacturer) VALUES (8, 'The Sonic Screwdriver', 'A versatile tool capable of performing a wide variety of tasks, from unlocking doors to repairing electronics.', 15.1, 'Absurd Accessories');
41 | INSERT INTO product (product_id, name, description, price, manufacturer) VALUES (9, 'The Infinite Improbability Generator', 'A device that can create impossible and absurd events, such as a spaceship suddenly turning into a giant sperm whale.', 9.99, 'Silly Supplies Co.');
42 | INSERT INTO product (product_id, name, description, price, manufacturer) VALUES (10, 'The Neuralyzer', 'A flashy device that erases people''s memories of specific events or encounters.', 33.55, 'Silly Supplies Co.');
43 |
--------------------------------------------------------------------------------
/chapter_01/postgresql_db.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************************
2 | RDBMS: PostgreSQL
3 | Create Date: 05/20/2023
4 | Author: Qiang Hao
5 | Description: Create a product table and insert some data for the onlinestore database.
6 | Note 1: This script is for PostgreSQL 14 or above.
7 | Note 2: This script assumes that a database is created and used.
8 | *************************************************************************************/
9 |
10 | -- Assuming a database 'onlinestore' is already created and used
11 |
12 | -- Create the product table and insert some data
13 | DROP TABLE IF EXISTS product;
14 | CREATE TABLE product (
15 | product_id INT PRIMARY KEY,
16 | name TEXT NOT NULL,
17 | description TEXT NOT NULL,
18 | price DECIMAL(5, 2) NOT NULL,
19 | manufacturer TEXT NOT NULL
20 | );
21 |
22 | INSERT INTO
23 | product (
24 | product_id,
25 | name,
26 | description,
27 | price,
28 | manufacturer
29 | )
30 | VALUES
31 | (
32 | 1,
33 | 'Atomic Nose Hair Trimmer',
34 | 'Trim your nose hairs with the precision of an atomic clock!',
35 | 19.99,
36 | 'Mad Inventors Inc.'
37 | ),
38 | (
39 | 2,
40 | 'Selfie Toaster',
41 | 'Get your face on your toast every morning with our selfie toaster!',
42 | 24.99,
43 | 'Goofy Gadgets Corp.'
44 | ),
45 | (
46 | 3,
47 | 'Cat-Poop Coffee',
48 | 'The only coffee made from the finest cat poop beans!',
49 | 29.99,
50 | 'Absurd Accessories'
51 | ),
52 | (
53 | 4,
54 | 'Inflatable Briefcase',
55 | 'Need more storage space? Inflate our briefcase to double its size!',
56 | 39.99,
57 | 'Wacky Wares Ltd.'
58 | ),
59 | (
60 | 5,
61 | 'Unicorn Horn Polish',
62 | 'Keep your unicorn''s horn shiny and smooth with our magical polish!',
63 | 9.99,
64 | 'Silly Supplies Co.'
65 | ),
66 | (
67 | 6,
68 | 'The Mind Probe',
69 | 'A device from Star Wars that can extract information directly from a person''s mind.',
70 | 19.99,
71 | 'Mad Inventors Inc.'
72 | ),
73 | (
74 | 7,
75 | 'Lightsabers',
76 | 'Elegant and deadly energy swords wielded by Jedi and Sith alike.',
77 | 25,
78 | 'Mad Inventors Inc.'
79 | ),
80 | (
81 | 8,
82 | 'The Sonic Screwdriver',
83 | 'A versatile tool capable of performing a wide variety of tasks, from unlocking doors to repairing electronics.',
84 | 15.1,
85 | 'Absurd Accessories'
86 | ),
87 | (
88 | 9,
89 | 'The Infinite Improbability Generator',
90 | 'A device that can create impossible and absurd events, such as a spaceship suddenly turning into a giant sperm whale.',
91 | 9.99,
92 | 'Silly Supplies Co.'
93 | ),
94 | (
95 | 10,
96 | 'The Neuralyzer',
97 | 'A flashy device that erases people''s memories of specific events or encounters.',
98 | 33.55,
99 | 'Silly Supplies Co.'
100 | );
--------------------------------------------------------------------------------
/chapter_01/sql_server_db.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************************
2 | RDBMS: SQL server
3 | Create Date: 01/16/2024
4 | Author: Qiang Hao
5 | Description: Create a product table and insert some data for the onlinestore database.
6 | Note: This script is for SQL Server 2019 or above.
7 | *************************************************************************************/
8 |
9 | -- Check if the database exists and create if it does not
10 | IF NOT EXISTS(SELECT * FROM sys.databases WHERE name = N'onlinestore')
11 | BEGIN
12 | CREATE DATABASE onlinestore;
13 | END;
14 |
15 | -- Use the database
16 | USE onlinestore;
17 |
18 | -- Drop the table product if it exists
19 | DROP TABLE IF EXISTS product;
20 |
21 | -- Create the table product
22 | CREATE TABLE product (
23 | product_id INT PRIMARY KEY,
24 | name NVARCHAR(MAX) NOT NULL, -- NVARCHAR(MAX) is SQL Server's equivalent of TEXT in MySQL
25 | description NVARCHAR(MAX) NOT NULL,
26 | price DECIMAL(5, 2) NOT NULL,
27 | manufacturer NVARCHAR(MAX) NOT NULL
28 | );
29 |
30 | -- Insert data into the table
31 | -- In SQL Server, prefixing a string literal with N before storing it in an NVARCHAR
32 | -- (or NCHAR or NTEXT) column is important because it signifies that the subsequent
33 | -- string is in Unicode format. Unicode data types can store any character from
34 | -- any character set, including special characters and characters from non-Latin
35 | -- languages like Chinese, Japanese, Arabic, etc
36 | INSERT INTO
37 | product (
38 | product_id,
39 | name,
40 | description,
41 | price,
42 | manufacturer
43 | )
44 | VALUES
45 | (
46 | 1,
47 | N'Atomic Nose Hair Trimmer',
48 | N'Trim your nose hairs with the precision of an atomic clock!',
49 | 19.99,
50 | N'Mad Inventors Inc.'
51 | ),
52 | (
53 | 2,
54 | N'Selfie Toaster',
55 | N'Get your face on your toast every morning with our selfie toaster!',
56 | 24.99,
57 | N'Goofy Gadgets Corp.'
58 | ),
59 | (
60 | 3,
61 | N'Cat-Poop Coffee',
62 | N'The only coffee made from the finest cat poop beans!',
63 | 29.99,
64 | N'Absurd Accessories'
65 | ),
66 | (
67 | 4,
68 | N'Inflatable Briefcase',
69 | N'Need more storage space? Inflate our briefcase to double its size!',
70 | 39.99,
71 | N'Wacky Wares Ltd.'
72 | ),
73 | (
74 | 5,
75 | N'Unicorn Horn Polish',
76 | N'Keep your unicorn''s horn shiny and smooth with our magical polish!',
77 | 9.99,
78 | N'Silly Supplies Co.'
79 | ),
80 | (
81 | 6,
82 | N'The Mind Probe',
83 | N'A device from Star Wars that can extract information directly from a person''s mind.',
84 | 19.99,
85 | N'Mad Inventors Inc.'
86 | ),
87 | (
88 | 7,
89 | N'Lightsabers',
90 | N'Elegant and deadly energy swords wielded by Jedi and Sith alike.',
91 | 25,
92 | N'Mad Inventors Inc.'
93 | ),
94 | (
95 | 8,
96 | N'The Sonic Screwdriver',
97 | N'A versatile tool capable of performing a wide variety of tasks, from unlocking doors to repairing electronics.',
98 | 15.1,
99 | N'Absurd Accessories'
100 | ),
101 | (
102 | 9,
103 | N'The Infinite Improbability Generator',
104 | N'A device that can create impossible and absurd events, such as a spaceship suddenly turning into a giant sperm whale.',
105 | 9.99,
106 | N'Silly Supplies Co.'
107 | ),
108 | (
109 | 10,
110 | N'The Neuralyzer',
111 | N'A flashy device that erases people''s memories of specific events or encounters.',
112 | 33.55,
113 | N'Silly Supplies Co.'
114 | );
--------------------------------------------------------------------------------
/chapter_01/sqlite_db.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************************
2 | RDBMS: SQLite
3 | Create Date: 05/20/2023
4 | Author: Qiang Hao
5 | Description: Create a product table and insert some data for the onlinestore database.
6 | Note: This script is for SQLite 3.
7 | *************************************************************************************/
8 |
9 | -- Connect to a new or existing database file
10 | -- Connect to the database
11 | ATTACH DATABASE 'onlinestore.db' AS onlinestore;
12 |
13 | -- Drop the product table if it exists
14 | DROP TABLE IF EXISTS onlinestore.product;
15 |
16 | -- Create the product table
17 | -- SQlite database doesn't support DECIMAL data type, so we use TEXT instead
18 | -- This is typical when the precision of the number is important
19 | -- The alternative is to use REAL, which is a floating-point number and is not precise
20 | -- VARCHAR is the same as TEXT and has no length limit, so TEXT was used instead
21 | CREATE TABLE onlinestore.product (
22 | product_id INT PRIMARY KEY,
23 | name TEXT NOT NULL,
24 | description TEXT NOT NULL,
25 | price TEXT NOT NULL,
26 | manufacturer TEXT NOT NULL
27 | );
28 |
29 | -- Insert data into the table
30 | INSERT INTO
31 | onlinestore.product (
32 | product_id,
33 | name,
34 | description,
35 | price,
36 | manufacturer
37 | )
38 | VALUES
39 | (
40 | 1,
41 | 'Atomic Nose Hair Trimmer',
42 | 'Trim your nose hairs with the precision of an atomic clock!',
43 | '19.99',
44 | 'Mad Inventors Inc.'
45 | ),
46 | (
47 | 2,
48 | 'Selfie Toaster',
49 | 'Get your face on your toast every morning with our selfie toaster!',
50 | '24.99',
51 | 'Goofy Gadgets Corp.'
52 | ),
53 | (
54 | 3,
55 | 'Cat-Poop Coffee',
56 | 'The only coffee made from the finest cat poop beans!',
57 | 29.99,
58 | 'Absurd Accessories'
59 | ),
60 | (
61 | 4,
62 | 'Inflatable Briefcase',
63 | 'Need more storage space? Inflate our briefcase to double its size!',
64 | '39.99',
65 | 'Wacky Wares Ltd.'
66 | ),
67 | (
68 | 5,
69 | 'Unicorn Horn Polish',
70 | 'Keep your unicorn''s horn shiny and smooth with our magical polish!',
71 | 9.99,
72 | 'Silly Supplies Co.'
73 | ),
74 | (
75 | 6,
76 | 'The Mind Probe',
77 | 'A device from Star Wars that can extract information directly from a person''s mind.',
78 | '19.99',
79 | 'Mad Inventors Inc.'
80 | ),
81 | (
82 | 7,
83 | 'Lightsabers',
84 | 'Elegant and deadly energy swords wielded by Jedi and Sith alike.',
85 | '25',
86 | 'Mad Inventors Inc.'
87 | ),
88 | (
89 | 8,
90 | 'The Sonic Screwdriver',
91 | 'A versatile tool capable of performing a wide variety of tasks, from unlocking doors to repairing electronics.',
92 | '15.1',
93 | 'Absurd Accessories'
94 | ),
95 | (
96 | 9,
97 | 'The Infinite Improbability Generator',
98 | 'A device that can create impossible and absurd events, such as a spaceship suddenly turning into a giant sperm whale.',
99 | '9.99',
100 | 'Silly Supplies Co.'
101 | ),
102 | (
103 | 10,
104 | 'The Neuralyzer',
105 | 'A flashy device that erases people''s memories of specific events or encounters.',
106 | '33.55',
107 | 'Silly Supplies Co.'
108 | );
109 |
110 | -- Close the database connection
111 | DETACH onlinestore;
--------------------------------------------------------------------------------
/chapter_01/sqlite_online.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************************
2 | Create Date: 05/20/2023
3 | Author: Qiang Hao
4 | Description: Create a product table and insert some data for the onlinestore database.
5 | Note: This script is for the tool named SQLite Online.
6 | *************************************************************************************/
7 |
8 | -- Drop the product table if it exists
9 | DROP TABLE IF EXISTS product;
10 |
11 | -- Create the product table
12 | CREATE TABLE product (
13 | product_id INT PRIMARY KEY,
14 | name TEXT NOT NULL,
15 | description TEXT NOT NULL,
16 | price DECIMAL(5, 2) NOT NULL,
17 | manufacturer TEXT NOT NULL
18 | );
19 |
20 | -- Insert data into the table
21 | INSERT INTO
22 | product (
23 | product_id,
24 | name,
25 | description,
26 | price,
27 | manufacturer
28 | )
29 | VALUES
30 | (
31 | 1,
32 | 'Atomic Nose Hair Trimmer',
33 | 'Trim your nose hairs with the precision of an atomic clock!',
34 | 19.99,
35 | 'Mad Inventors Inc.'
36 | ),
37 | (
38 | 2,
39 | 'Selfie Toaster',
40 | 'Get your face on your toast every morning with our selfie toaster!',
41 | 24.99,
42 | 'Goofy Gadgets Corp.'
43 | ),
44 | (
45 | 3,
46 | 'Cat-Poop Coffee',
47 | 'The only coffee made from the finest cat poop beans!',
48 | 29.99,
49 | 'Absurd Accessories'
50 | ),
51 | (
52 | 4,
53 | 'Inflatable Briefcase',
54 | 'Need more storage space? Inflate our briefcase to double its size!',
55 | 39.99,
56 | 'Wacky Wares Ltd.'
57 | ),
58 | (
59 | 5,
60 | 'Unicorn Horn Polish',
61 | 'Keep your unicorn''s horn shiny and smooth with our magical polish!',
62 | 9.99,
63 | 'Silly Supplies Co.'
64 | ),
65 | (
66 | 6,
67 | 'The Mind Probe',
68 | 'A device from Star Wars that can extract information directly from a person''s mind.',
69 | 19.99,
70 | 'Mad Inventors Inc.'
71 | ),
72 | (
73 | 7,
74 | 'Lightsabers',
75 | 'Elegant and deadly energy swords wielded by Jedi and Sith alike.',
76 | 25,
77 | 'Mad Inventors Inc.'
78 | ),
79 | (
80 | 8,
81 | 'The Sonic Screwdriver',
82 | 'A versatile tool capable of performing a wide variety of tasks, from unlocking doors to repairing electronics.',
83 | 15.1,
84 | 'Absurd Accessories'
85 | ),
86 | (
87 | 9,
88 | 'The Infinite Improbability Generator',
89 | 'A device that can create impossible and absurd events, such as a spaceship suddenly turning into a giant sperm whale.',
90 | 9.99,
91 | 'Silly Supplies Co.'
92 | ),
93 | (
94 | 10,
95 | 'The Neuralyzer',
96 | 'A flashy device that erases people''s memories of specific events or encounters.',
97 | 33.55,
98 | 'Silly Supplies Co.'
99 | );
--------------------------------------------------------------------------------
/chapter_02/README.md:
--------------------------------------------------------------------------------
1 | # Related tables and more SQL
2 |
3 | The SQL code snippets covered in this chapter are all contained in this folder. The SQL code snippets covered in this chapter work perfectly with MySQL, MariaDB, and SQLite.
4 |
5 | If you are using PostgreSQL, you should refer to the SQL script contained in this folder and pay attention to the following differences that were made to make the script compatible with PostgreSQL:
6 |
7 | * `TIMESTAMP` was used instead of `DATETIME`: PostgreSQL doesn't support `DATETIME` data type.
8 |
9 | If you are using SQL Server, you should refer to the SQL script contained in this folder and pay attention to the following differences that were made to make the script compatible with SQL Server:
10 |
11 | * `NVARCHAR(MAX)` was used instead of `TEXT`: SQL Server doesn't support `TEXT` data type.
12 | * Data insertion of string values was changed from `'...'` to `N'...'`: SQL Server requires the `N` prefix for string values, e.g., `N'Apple'`. SQL Server uses the UCS-2 encoding for string values, which is a subset of UTF-16. The `N` prefix tells SQL Server to use UTF-16 encoding for the string value.
13 | * `GETDATE()` was used instead of `CURRENT_TIMESTAMP`: SQL Server doesn't support `CURRENT_TIMESTAMP` function.
14 |
15 | If you are using SQLite database, you should refer to the SQL script contained in this folder and pay attention to the following differences that were made to make the script compatible with SQLite database:
16 |
17 | * `TEXT` was used instead of `VARCHAR`: `VARCHAR` is the same as `TEXT` and has no length limit in SQLite.
18 | * `TEXT` was used instead of `DECIMAL`: SQLite doesn't support `DECIMAL` data type. `REAL` is typically used instead of `DECIMAL` in SQLite when precision doesn't matter. When precision matters, `TEXT` is typically used in practice instead of `DECIMAL` in SQLite.
19 | * `TEXT` was used instead of `DATETIME`: SQLite doesn't support `DATETIME` data type. `TEXT` is typically used instead of `DATETIME` in SQLite.
20 |
21 |
25 |
26 | How to load the prepared scripts using different RDBMS and tools are covered in the following subsections.
27 |
28 | - [SQLite online](#sqlite-online)
29 | - [SQLite database](#sqlite-database)
30 | - [Load the prepared SQLite script](#load-the-prepared-sqlite-script)
31 | - [MySQL database](#mysql-database)
32 | - [Load the prepared MySQL script](#load-the-prepared-mysql-script)
33 | - [PostgreSQL database](#postgresql-database)
34 | - [Load the prepared PostgreSQL script](#load-the-prepared-postgresql-script)
35 | - [SQL Server database](#sql-server-database)
36 | - [Load the prepared SQL Server script](#load-the-prepared-sql-server-script)
37 | - [Oracle database](#oracle-database)
38 | - [Load the prepared Oracle script](#load-the-prepared-oracle-script)
39 |
40 | ## SQLite online
41 |
42 | SQLite online is a web-based tool that you can use to execute SQL queries. You can access it at [SQLite online](https://sqliteonline.com/).
43 |
44 | The script prepared for SQLite online is [`sqlite_online.sql`](./sqlite_online.sql). You can load the prepared script by:
45 |
46 | 1. Navigate to SQLite Online (https://sqliteonline.com)
47 | 2. Click _Import_ and load `sqlite_online.sql`
48 | 3. Click _Okay_
49 |
50 | Now you should see the script executed in the right sidebar. You are ready to type into the console, follow the book, and execute SQL queries.
51 |
52 |
53 |
54 | ## SQLite database
55 |
56 | In case you jump to this chapter directly, you need to refer to [the README file](../chapter_01/README.md/#sqlite-database) in the `chapter_01` folder to install SQLite first.
57 |
58 | ### Load the prepared SQLite script
59 |
60 | The script prepared for SQLite database is [`sqlite_db.sql`](./sqlite_db.sql). You can load the prepared script by:
61 |
62 | 1. Open the terminal, navigate into the `chapter_02` folder of this repository
63 | 2. **** Run the following command, and you will be in the SQLite console environment:
64 |
65 | ```
66 | sqlite3 onlinestore_chapter2.db
67 | ```
68 |
69 | 3. In the same SQLite console environment (e.g., the line prompt starts with `sqlite>`), run the following command to load the script:
70 |
71 | ```
72 | .read sqlite_db.sql
73 | ```
74 |
75 | 4. In the same SQLite console environment, check if the table is created by running the following command:
76 |
77 | ```
78 | .tables
79 | ```
80 |
81 | If you see `products` and `review`, that means the script is loaded successfully. In the same SQLite console environment, you can run any SQL queries you want, including the examples covered by Chapter 2. You can always quit the SQLite console by typing `.quit` and pressing `Enter`.
82 |
83 | ## MySQL database
84 |
85 | In case you jump to this chapter directly, you need to refer to [the README file](../chapter_01/README.md/#mysql-database) in the `chapter_01` folder to install MySQL first.
86 |
87 | ### Load the prepared MySQL script
88 |
89 | The script prepared for MySQL database is [`mysql_db.sql`](./mysql_db.sql). You can load the prepared script by:
90 |
91 | 1. Open the terminal, navigate into the `chapter_02` folder of this repository
92 | 2. Run the following command:
93 |
94 | ```
95 | mysql -u root < mysql_db.sql
96 | ```
97 |
98 | If you have set up a password for your MySQL server, you can run the following command instead:
99 |
100 | ```
101 | mysql -u root -p < mysql_db.sql
102 | ```
103 |
104 | After that, you will be prompted to enter your password.
105 |
106 | Now you have loaded the script. To query the database and table created by the script, you will need to navigate to the MySQL console environment. You can do this by running the following command:
107 |
108 | ```
109 | mysql -u root
110 | ```
111 |
112 | In the MySQL console environment, you can run any SQL queries you want, including the examples covered by Chapter 2. You can always quit the MySQL console by typing `quit` and pressing `Enter`.
113 |
114 | ## PostgreSQL database
115 |
116 | In case you jump to this chapter directly, you need to refer to [the README file](../chapter_01/README.md/#postgresql-database) in the `chapter_01` folder to install PostgreSQL first.
117 |
118 | ### Load the prepared PostgreSQL script
119 |
120 | Before loading the script, you will need to create a database named `onlinestore_chapter2` and use this database via the PostgreSQL console environment first. Different from SQLite and MySQL, there are no easy approach to merge these two steps into the script.
121 |
122 | You can follow the following steps to load the prepared script:
123 |
124 | 1. Open the terminal, and navigate into the `chapter_02` folder of this repository
125 |
126 | 2. Log in to the PostgreSQL console environment by running the following command:
127 |
128 | ```
129 | psql -U postgres
130 | ```
131 | 3. In the console environment, create a database named `onlinestore_chapter2` by running the following command:
132 |
133 | ```
134 | CREATE DATABASE onlinestore_chapter2;
135 | ```
136 |
137 | 4. In the console environment, use the database `onlinestore_chapter2` by running the following command:
138 |
139 | ```
140 | \c onlinestore_chapter2
141 | ```
142 |
143 | 5. Now you are ready to load the prepared script. The script prepared for PostgreSQL database is [`postgresql_db.sql`](./postgresql_db.sql). In the console environment, run the following command:
144 |
145 | ```
146 | \i postgresql_db.sql
147 | ```
148 |
149 | In the same console environment, you can run any SQL queries you want, including the examples covered by Chapter 2. You can always quit the PostgreSQL console by typing `\q` and pressing `Enter`.
150 |
151 | ## SQL Server database
152 |
153 | In case you jump to this chapter directly, you need to refer to [the README file](../chapter_01/README.md/#sql-server) in the `chapter_01` folder to install SQL Server first.
154 |
155 | ### Load the prepared SQL Server script
156 |
157 | The script prepared for SQL Server database is [`sql_server_db.sql`](./sql_server_db.sql). You can refer to [the same instructions for Chapter 1](../chapter_01/README.md#load-the-prepared-sql-server-script) to load the script. Please remember that you should load the script from the folder of `chapter_02` instead of `chapter_01`.
158 |
159 | ## Oracle database
160 |
161 | In case you jump to this chapter directly, you need to refer to [the README file](../chapter_01/README.md/#oracle-database) in the `chapter_01` folder to install Oracle first.
162 |
163 | ### Load the prepared Oracle script
164 |
165 | The script prepared for Oracle is [`sql_server_db.sql`](./oracle_db.sql). You can refer to [the same instructions for Chapter 1](../chapter_01/README.md#load-the-prepared-oracle-script) to load the script. Please remember that you should load the script from the folder of `chapter_02` instead of `chapter_01`.
--------------------------------------------------------------------------------
/chapter_02/images/sqlite_online.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/chapter_02/images/sqlite_online.png
--------------------------------------------------------------------------------
/chapter_02/mysql_db.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************************
2 | RDBMS: MySQL
3 | Create Date: 05/20/2023
4 | Author: Qiang Hao
5 | Description: Create a pair of two related tables, product and review,
6 | and insert some data into the two tables that support the
7 | onlinestore database.
8 | Note: This script is for MySQL 8.0 or above.
9 | *************************************************************************************/
10 |
11 | -- Create the onlinestore_chapter2 database if it doesn't exist
12 | CREATE DATABASE IF NOT EXISTS onlinestore_chapter2;
13 |
14 | -- Use the onlinestore_chapter2 database
15 | USE onlinestore_chapter2;
16 |
17 | -- Create the product table
18 | DROP TABLE IF EXISTS product;
19 | CREATE TABLE product (
20 | product_id INT PRIMARY KEY,
21 | name TEXT NOT NULL,
22 | description TEXT NOT NULL,
23 | price DECIMAL(5, 2) NOT NULL,
24 | manufacturer TEXT NOT NULL
25 | );
26 |
27 | -- Insert data into the product table
28 | INSERT INTO
29 | product (
30 | product_id,
31 | name,
32 | description,
33 | price,
34 | manufacturer
35 | )
36 | VALUES
37 | (
38 | 1,
39 | 'Atomic Nose Hair Trimmer',
40 | 'Trim your nose hairs with the precision of an atomic clock!',
41 | 19.99,
42 | 'Mad Inventors Inc.'
43 | ),
44 | (
45 | 2,
46 | 'Selfie Toaster',
47 | 'Get your face on your toast every morning with our selfie toaster!',
48 | 24.99,
49 | 'Goofy Gadgets Corp.'
50 | ),
51 | (
52 | 3,
53 | 'Cat-Poop Coffee',
54 | 'The only coffee made from the finest cat poop beans!',
55 | 29.99,
56 | 'Absurd Accessories'
57 | ),
58 | (
59 | 4,
60 | 'Inflatable Briefcase',
61 | 'Need more storage space? Inflate our briefcase to double its size!',
62 | 39.99,
63 | 'Wacky Wares Ltd.'
64 | ),
65 | (
66 | 5,
67 | 'Unicorn Horn Polish',
68 | 'Keep your unicorn''s horn shiny and smooth with our magical polish!',
69 | 9.99,
70 | 'Silly Supplies Co.'
71 | ),
72 | (
73 | 6,
74 | 'The Mind Probe',
75 | 'A device from Star Wars that can extract information directly from a person''s mind.',
76 | 19.99,
77 | 'Mad Inventors Inc.'
78 | ),
79 | (
80 | 7,
81 | 'Lightsabers',
82 | 'Elegant and deadly energy swords wielded by Jedi and Sith alike.',
83 | 25,
84 | 'Mad Inventors Inc.'
85 | ),
86 | (
87 | 8,
88 | 'The Sonic Screwdriver',
89 | 'A versatile tool capable of performing a wide variety of tasks, from unlocking doors to repairing electronics.',
90 | 15.1,
91 | 'Absurd Accessories'
92 | ),
93 | (
94 | 9,
95 | 'The Infinite Improbability Generator',
96 | 'A device that can create impossible and absurd events, such as a spaceship suddenly turning into a giant sperm whale.',
97 | 9.99,
98 | 'Silly Supplies Co.'
99 | ),
100 | (
101 | 10,
102 | 'The Neuralyzer',
103 | 'A flashy device that erases people''s memories of specific events or encounters.',
104 | 33.55,
105 | 'Silly Supplies Co.'
106 | );
107 |
108 | -- Create the review table
109 | DROP TABLE IF EXISTS review;
110 | CREATE TABLE review (
111 | review_id BIGINT PRIMARY KEY,
112 | product_id INT NOT NULL,
113 | review_text TEXT NOT NULL,
114 | datetime DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
115 | CONSTRAINT fk_product_review FOREIGN KEY (product_id) REFERENCES product (product_id)
116 | );
117 |
118 | -- Insert data into the review table
119 | INSERT INTO
120 | review (
121 | review_id,
122 | product_id,
123 | review_text,
124 | datetime
125 | )
126 | VALUES
127 | (
128 | 1,
129 | 3,
130 | 'Great product, would definitely recommend!',
131 | '2022-01-01 12:30:00'
132 | ),
133 | (
134 | 2,
135 | 5,
136 | 'This is the best thing I have ever bought!',
137 | '2022-01-02 13:45:00'
138 | ),
139 | (
140 | 3,
141 | 2,
142 | 'Not worth the money, would not recommend',
143 | '2022-01-03 14:15:00'
144 | ),
145 | (
146 | 4,
147 | 4,
148 | 'Disappointing purchase. Wouldn''t buy again.',
149 | '2022-01-04 15:00:00'
150 | ),
151 | (
152 | 5,
153 | 1,
154 | 'Decent product for the price, happy with my purchase',
155 | '2022-01-05 16:30:00'
156 | ),
157 | (
158 | 6,
159 | 2,
160 | 'Really impressed with the quality of this product!',
161 | '2022-01-06 17:00:00'
162 | ),
163 | (
164 | 7,
165 | 4,
166 | 'Great value for the price, would buy again',
167 | '2022-01-07 18:15:00'
168 | ),
169 | (
170 | 8,
171 | 3,
172 | 'Not the best quality, but it gets the job done',
173 | '2022-01-08 19:00:00'
174 | ),
175 | (
176 | 9,
177 | 5,
178 | 'I am really happy with this purchase, it exceeded my expectations',
179 | '2022-01-09 20:30:00'
180 | ),
181 | (
182 | 10,
183 | 1,
184 | 'Would not recommend this product, very disappointing',
185 | '2022-01-10 21:00:00'
186 | ),
187 | (
188 | 11,
189 | 3,
190 | 'This product is great, I use it every day!',
191 | '2022-01-11 22:15:00'
192 | ),
193 | (
194 | 12,
195 | 5,
196 | 'I would definitely buy this again, great value for the price',
197 | '2022-01-12 23:00:00'
198 | );
--------------------------------------------------------------------------------
/chapter_02/oracle_db.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************************
2 | RDBMS: Oracle Database
3 | Create Date: 01/17/2024
4 | Author: Qiang Hao
5 | Description: Create a pair of two related tables, product and review,
6 | and insert some data into the two tables that support the
7 | onlinestore database.
8 | Note 1: This script is for Oracle 18c or above.
9 | Note 2: This script assumes that a database is created and used.
10 | *************************************************************************************/
11 |
12 | -- Assuming the schema onlinestore_chapter2 is created and used
13 |
14 | -- Drop 'review' table if it exists
15 | BEGIN
16 | EXECUTE IMMEDIATE 'DROP TABLE review';
17 | EXCEPTION
18 | WHEN OTHERS THEN
19 | IF SQLCODE != -942 THEN
20 | RAISE;
21 | END IF;
22 | END;
23 | /
24 | -- Drop 'review' table if it exists
25 | BEGIN
26 | EXECUTE IMMEDIATE 'DROP TABLE product';
27 | EXCEPTION
28 | WHEN OTHERS THEN
29 | IF SQLCODE != -942 THEN
30 | RAISE;
31 | END IF;
32 | END;
33 | /
34 |
35 | -- Creating the 'product' table
36 | CREATE TABLE product (
37 | product_id NUMBER PRIMARY KEY, -- NUMBER is Oracle's equivalent of INT or DECIMAL in MySQL
38 | name VARCHAR2(255) NOT NULL, -- VARCHAR2 is Oracle's equivalent of TEXT in MySQL
39 | description VARCHAR2(4000) NOT NULL,
40 | price NUMBER(5, 2) NOT NULL, -- NUMBER(5, 2) is Oracle's equivalent of DECIMAL(5, 2) in MySQL
41 | manufacturer VARCHAR2(255) NOT NULL
42 | );
43 |
44 | -- Inserting data into 'product'
45 | -- Inserting data into 'product' (Product 1)
46 | INSERT INTO product (product_id, name, description, price, manufacturer)
47 | VALUES (1, 'Atomic Nose Hair Trimmer', 'Trim your nose hairs with the precision of an atomic clock!', 19.99, 'Mad Inventors Inc.');
48 |
49 | -- Inserting data into 'product' (Product 2)
50 | INSERT INTO product (product_id, name, description, price, manufacturer)
51 | VALUES (2, 'Selfie Toaster', 'Get your face on your toast every morning with our selfie toaster!', 24.99, 'Goofy Gadgets Corp.');
52 |
53 | -- Inserting data into 'product' (Product 3)
54 | INSERT INTO product (product_id, name, description, price, manufacturer)
55 | VALUES (3, 'Cat-Poop Coffee', 'The only coffee made from the finest cat poop beans!', 29.99, 'Absurd Accessories');
56 |
57 | -- Inserting data into 'product' (Product 4)
58 | INSERT INTO product (product_id, name, description, price, manufacturer)
59 | VALUES (4, 'Inflatable Briefcase', 'Need more storage space? Inflate our briefcase to double its size!', 39.99, 'Wacky Wares Ltd.');
60 |
61 | -- Inserting data into 'product' (Product 5)
62 | INSERT INTO product (product_id, name, description, price, manufacturer)
63 | VALUES (5, 'Unicorn Horn Polish', 'Keep your unicorn''s horn shiny and smooth with our magical polish!', 9.99, 'Silly Supplies Co.');
64 |
65 | -- Inserting data into 'product' (Product 6)
66 | INSERT INTO product (product_id, name, description, price, manufacturer)
67 | VALUES (6, 'The Mind Probe', 'A device from Star Wars that can extract information directly from a person''s mind.', 19.99, 'Mad Inventors Inc.');
68 |
69 | -- Inserting data into 'product' (Product 7)
70 | INSERT INTO product (product_id, name, description, price, manufacturer)
71 | VALUES (7, 'Lightsabers', 'Elegant and deadly energy swords wielded by Jedi and Sith alike.', 25, 'Mad Inventors Inc.');
72 |
73 | -- Inserting data into 'product' (Product 8)
74 | INSERT INTO product (product_id, name, description, price, manufacturer)
75 | VALUES (8, 'The Sonic Screwdriver', 'A versatile tool capable of performing a wide variety of tasks, from unlocking doors to repairing electronics.', 15.1, 'Absurd Accessories');
76 |
77 | -- Inserting data into 'product' (Product 9)
78 | INSERT INTO product (product_id, name, description, price, manufacturer)
79 | VALUES (9, 'The Infinite Improbability Generator', 'A device that can create impossible and absurd events, such as a spaceship suddenly turning into a giant sperm whale.', 9.99, 'Silly Supplies Co.');
80 |
81 | -- Inserting data into 'product' (Product 10)
82 | INSERT INTO product (product_id, name, description, price, manufacturer)
83 | VALUES (10, 'The Neuralyzer', 'A flashy device that erases people''s memories of specific events or encounters.', 33.55, 'Silly Supplies Co.');
84 |
85 |
86 | -- Creating the 'review' table
87 | CREATE TABLE review (
88 | review_id NUMBER PRIMARY KEY, -- NUMBER is Oracle's equivalent of INT or DECIMAL in MySQL
89 | product_id NUMBER NOT NULL,
90 | review_text VARCHAR2(4000) NOT NULL, -- VARCHAR2 is Oracle's equivalent of TEXT in MySQL
91 | datetime TIMESTAMP DEFAULT CURRENT_TIMESTAMP NOT NULL, -- TIMESTAMP is Oracle's equivalent of DATETIME in MySQL
92 | CONSTRAINT fk_product_review FOREIGN KEY (product_id) REFERENCES product (product_id)
93 | );
94 |
95 | -- Inserting data into 'review'
96 | -- In Oracle SQL, TO_TIMESTAMP is a function used to convert a string
97 | -- representation of a date and time into a TIMESTAMP value. This function is
98 | -- particularly useful when you need to work with date and time data that
99 | -- comes in a string format and you need to convert it to a TIMESTAMP data
100 | -- type for storage, comparison, or calculation purposes. The TO_TIMESTAMP
101 | -- function allows you to specify the format of the input string so that Oracle
102 | -- knows how to correctly interpret it. The basic syntax of the TO_TIMESTAMP
103 | -- function is TO_TIMESTAMP(string, format_mask)
104 | -- Inserting data into 'review' (Review 1)
105 | -- Inserting data into 'review' (Review 1)
106 | INSERT INTO review (review_id, product_id, review_text, datetime)
107 | VALUES (1, 3, 'Great product, would definitely recommend!', TIMESTAMP '2022-01-01 12:30:00');
108 |
109 | -- Inserting data into 'review' (Review 2)
110 | INSERT INTO review (review_id, product_id, review_text, datetime)
111 | VALUES (2, 5, 'This is the best thing I have ever bought!', TIMESTAMP '2022-01-02 13:45:00');
112 |
113 | -- Inserting data into 'review' (Review 3)
114 | INSERT INTO review (review_id, product_id, review_text, datetime)
115 | VALUES (3, 2, 'Not worth the money, would not recommend', TIMESTAMP '2022-01-03 14:15:00');
116 |
117 | -- Inserting data into 'review' (Review 4)
118 | INSERT INTO review (review_id, product_id, review_text, datetime)
119 | VALUES (4, 4, 'Disappointing purchase. Wouldn''t buy again.', TIMESTAMP '2022-01-04 15:00:00');
120 |
121 | -- Inserting data into 'review' (Review 5)
122 | INSERT INTO review (review_id, product_id, review_text, datetime)
123 | VALUES (5, 1, 'Decent product for the price, happy with my purchase', TIMESTAMP '2022-01-05 16:30:00');
124 |
125 | -- Inserting data into 'review' (Review 6)
126 | INSERT INTO review (review_id, product_id, review_text, datetime)
127 | VALUES (6, 2, 'Really impressed with the quality of this product!', TIMESTAMP '2022-01-06 17:00:00');
128 |
129 | -- Inserting data into 'review' (Review 7)
130 | INSERT INTO review (review_id, product_id, review_text, datetime)
131 | VALUES (7, 4, 'Great value for the price, would buy again', TIMESTAMP '2022-01-07 18:15:00');
132 |
133 | -- Inserting data into 'review' (Review 8)
134 | INSERT INTO review (review_id, product_id, review_text, datetime)
135 | VALUES (8, 3, 'Not the best quality, but it gets the job done', TIMESTAMP '2022-01-08 19:00:00');
136 |
137 | -- Inserting data into 'review' (Review 9)
138 | INSERT INTO review (review_id, product_id, review_text, datetime)
139 | VALUES (9, 5, 'I am really happy with this purchase, it exceeded my expectations', TIMESTAMP '2022-01-09 20:30:00');
140 |
141 | -- Inserting data into 'review' (Review 10)
142 | INSERT INTO review (review_id, product_id, review_text, datetime)
143 | VALUES (10, 1, 'Would not recommend this product, very disappointing', TIMESTAMP '2022-01-10 21:00:00');
144 |
145 | -- Inserting data into 'review' (Review 11)
146 | INSERT INTO review (review_id, product_id, review_text, datetime)
147 | VALUES (11, 3, 'This product is great, I use it every day!', TIMESTAMP '2022-01-11 22:15:00');
148 |
149 | -- Inserting data into 'review' (Review 12)
150 | INSERT INTO review (review_id, product_id, review_text, datetime)
151 | VALUES (12, 5, 'I would definitely buy this again, great value for the price', TIMESTAMP '2022-01-12 23:00:00');
152 |
--------------------------------------------------------------------------------
/chapter_02/postgresql_db.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************************
2 | RDBMS: PostgreSQL
3 | Create Date: 05/20/2023
4 | Author: Qiang Hao
5 | Description: Create a pair of two related tables, product and review,
6 | and insert some data into the two tables that support the
7 | onlinestore database.
8 | Note 1: This script is for PostgreSQL 14 or above.
9 | Note 2: This script assumes that a database is created and used.
10 | *************************************************************************************/
11 |
12 | -- Assuming a database 'onlinestore_chapter2' is already created and used
13 |
14 | -- Create the product table and insert some data
15 | DROP TABLE IF EXISTS product;
16 | CREATE TABLE product (
17 | product_id INT PRIMARY KEY,
18 | name TEXT NOT NULL,
19 | description TEXT NOT NULL,
20 | price DECIMAL(5, 2) NOT NULL,
21 | manufacturer TEXT NOT NULL
22 | );
23 |
24 | INSERT INTO
25 | product (
26 | product_id,
27 | name,
28 | description,
29 | price,
30 | manufacturer
31 | )
32 | VALUES
33 | (
34 | 1,
35 | 'Atomic Nose Hair Trimmer',
36 | 'Trim your nose hairs with the precision of an atomic clock!',
37 | 19.99,
38 | 'Mad Inventors Inc.'
39 | ),
40 | (
41 | 2,
42 | 'Selfie Toaster',
43 | 'Get your face on your toast every morning with our selfie toaster!',
44 | 24.99,
45 | 'Goofy Gadgets Corp.'
46 | ),
47 | (
48 | 3,
49 | 'Cat-Poop Coffee',
50 | 'The only coffee made from the finest cat poop beans!',
51 | 29.99,
52 | 'Absurd Accessories'
53 | ),
54 | (
55 | 4,
56 | 'Inflatable Briefcase',
57 | 'Need more storage space? Inflate our briefcase to double its size!',
58 | 39.99,
59 | 'Wacky Wares Ltd.'
60 | ),
61 | (
62 | 5,
63 | 'Unicorn Horn Polish',
64 | 'Keep your unicorn''s horn shiny and smooth with our magical polish!',
65 | 9.99,
66 | 'Silly Supplies Co.'
67 | ),
68 | (
69 | 6,
70 | 'The Mind Probe',
71 | 'A device from Star Wars that can extract information directly from a person''s mind.',
72 | 19.99,
73 | 'Mad Inventors Inc.'
74 | ),
75 | (
76 | 7,
77 | 'Lightsabers',
78 | 'Elegant and deadly energy swords wielded by Jedi and Sith alike.',
79 | 25,
80 | 'Mad Inventors Inc.'
81 | ),
82 | (
83 | 8,
84 | 'The Sonic Screwdriver',
85 | 'A versatile tool capable of performing a wide variety of tasks, from unlocking doors to repairing electronics.',
86 | 15.1,
87 | 'Absurd Accessories'
88 | ),
89 | (
90 | 9,
91 | 'The Infinite Improbability Generator',
92 | 'A device that can create impossible and absurd events, such as a spaceship suddenly turning into a giant sperm whale.',
93 | 9.99,
94 | 'Silly Supplies Co.'
95 | ),
96 | (
97 | 10,
98 | 'The Neuralyzer',
99 | 'A flashy device that erases people''s memories of specific events or encounters.',
100 | 33.55,
101 | 'Silly Supplies Co.'
102 | );
103 |
104 | -- Create the review table and insert some data
105 | DROP TABLE IF EXISTS review;
106 | CREATE TABLE review (
107 | review_id BIGINT PRIMARY KEY,
108 | product_id INT NOT NULL,
109 | review_text TEXT NOT NULL,
110 | datetime TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, -- TIMESTAMP is PostgreSQL's equivalent of DATETIME in MySQL
111 | CONSTRAINT fk_product_review FOREIGN KEY (product_id) REFERENCES product (product_id)
112 | );
113 |
114 | INSERT INTO
115 | review (
116 | review_id,
117 | product_id,
118 | review_text,
119 | datetime
120 | )
121 | VALUES
122 | (
123 | 1,
124 | 3,
125 | 'Great product, would definitely recommend!',
126 | '2022-01-01 12:30:00'
127 | ),
128 | (
129 | 2,
130 | 5,
131 | 'This is the best thing I have ever bought!',
132 | '2022-01-02 13:45:00'
133 | ),
134 | (
135 | 3,
136 | 2,
137 | 'Not worth the money, would not recommend',
138 | '2022-01-03 14:15:00'
139 | ),
140 | (
141 | 4,
142 | 4,
143 | 'Disappointing purchase. Wouldn''t buy again.',
144 | '2022-01-04 15:00:00'
145 | ),
146 | (
147 | 5,
148 | 1,
149 | 'Decent product for the price, happy with my purchase',
150 | '2022-01-05 16:30:00'
151 | ),
152 | (
153 | 6,
154 | 2,
155 | 'Really impressed with the quality of this product!',
156 | '2022-01-06 17:00:00'
157 | ),
158 | (
159 | 7,
160 | 4,
161 | 'Great value for the price, would buy again',
162 | '2022-01-07 18:15:00'
163 | ),
164 | (
165 | 8,
166 | 3,
167 | 'Not the best quality, but it gets the job done',
168 | '2022-01-08 19:00:00'
169 | ),
170 | (
171 | 9,
172 | 5,
173 | 'I am really happy with this purchase, it exceeded my expectations',
174 | '2022-01-09 20:30:00'
175 | ),
176 | (
177 | 10,
178 | 1,
179 | 'Would not recommend this product, very disappointing',
180 | '2022-01-10 21:00:00'
181 | ),
182 | (
183 | 11,
184 | 3,
185 | 'This product is great, I use it every day!',
186 | '2022-01-11 22:15:00'
187 | ),
188 | (
189 | 12,
190 | 5,
191 | 'I would definitely buy this again, great value for the price',
192 | '2022-01-12 23:00:00'
193 | );
--------------------------------------------------------------------------------
/chapter_02/sql_server_db.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************************
2 | RDBMS: SQL server
3 | Create Date: 01/16/2024
4 | Author: Qiang Hao
5 | Description: Create a product table and insert some data for the onlinestore_chapter2 database.
6 | Note: This script is for SQL Server 2019 or above.
7 | *************************************************************************************/
8 |
9 | -- Check if the database exists and create if it does not
10 | IF NOT EXISTS(SELECT * FROM sys.databases WHERE name = N'onlinestore_chapter2')
11 | BEGIN
12 | CREATE DATABASE onlinestore_chapter2;
13 | END;
14 |
15 | -- Use the database
16 | USE onlinestore_chapter2;
17 |
18 | -- Create the product table
19 | DROP TABLE IF EXISTS product;
20 | CREATE TABLE product (
21 | product_id INT PRIMARY KEY,
22 | name NVARCHAR(MAX) NOT NULL, -- NVARCHAR(MAX) in SQL Server is equivalent to TEXT in MySQL
23 | description NVARCHAR(MAX) NOT NULL,
24 | price DECIMAL(5, 2) NOT NULL,
25 | manufacturer NVARCHAR(MAX) NOT NULL,
26 | );
27 |
28 | -- Insert data into the product table
29 | -- In SQL Server, prefixing a string literal with N before storing it in an NVARCHAR
30 | -- (or NCHAR or NTEXT) column is important because it signifies that the subsequent
31 | -- string is in Unicode format. Unicode data types can store any character from
32 | -- any character set, including special characters and characters from non-Latin
33 | -- languages like Chinese, Japanese, Arabic, etc
34 | INSERT INTO
35 | product (
36 | product_id,
37 | name,
38 | description,
39 | price,
40 | manufacturer
41 | )
42 | VALUES
43 | (
44 | 1,
45 | N'Atomic Nose Hair Trimmer',
46 | N'Trim your nose hairs with the precision of an atomic clock!',
47 | 19.99,
48 | N'Mad Inventors Inc.'
49 | ),
50 | (
51 | 2,
52 | N'Selfie Toaster',
53 | N'Get your face on your toast every morning with our selfie toaster!',
54 | 24.99,
55 | N'Goofy Gadgets Corp.'
56 | ),
57 | (
58 | 3,
59 | N'Cat-Poop Coffee',
60 | N'The only coffee made from the finest cat poop beans!',
61 | 29.99,
62 | N'Absurd Accessories'
63 | ),
64 | (
65 | 4,
66 | N'Inflatable Briefcase',
67 | N'Need more storage space? Inflate our briefcase to double its size!',
68 | 39.99,
69 | N'Wacky Wares Ltd.'
70 | ),
71 | (
72 | 5,
73 | N'Unicorn Horn Polish',
74 | N'Keep your unicorn''s horn shiny and smooth with our magical polish!',
75 | 9.99,
76 | N'Silly Supplies Co.'
77 | ),
78 | (
79 | 6,
80 | N'The Mind Probe',
81 | N'A device from Star Wars that can extract information directly from a person''s mind.',
82 | 19.99,
83 | N'Mad Inventors Inc.'
84 | ),
85 | (
86 | 7,
87 | N'Lightsabers',
88 | N'Elegant and deadly energy swords wielded by Jedi and Sith alike.',
89 | 25,
90 | N'Mad Inventors Inc.'
91 | ),
92 | (
93 | 8,
94 | N'The Sonic Screwdriver',
95 | N'A versatile tool capable of performing a wide variety of tasks, from unlocking doors to repairing electronics.',
96 | 15.1,
97 | N'Absurd Accessories'
98 | ),
99 | (
100 | 9,
101 | N'The Infinite Improbability Generator',
102 | N'A device that can create impossible and absurd events, such as a spaceship suddenly turning into a giant sperm whale.',
103 | 9.99,
104 | N'Silly Supplies Co.'
105 | ),
106 | (
107 | 10,
108 | N'The Neuralyzer',
109 | N'A flashy device that erases people''s memories of specific events or encounters.',
110 | 33.55,
111 | N'Silly Supplies Co.'
112 | );
113 |
114 | -- Create the review table
115 | DROP TABLE IF EXISTS review;
116 | CREATE TABLE review (
117 | review_id BIGINT PRIMARY KEY,
118 | product_id INT NOT NULL,
119 | review_text NVARCHAR(MAX) NOT NULL,
120 | datetime DATETIME NOT NULL DEFAULT GETDATE(), -- GETDATE() in SQL Server is equivalent to CURRENT_TIMESTAMP in MySQL
121 | CONSTRAINT fk_product_review FOREIGN KEY (product_id) REFERENCES product (product_id)
122 | );
123 |
124 | -- Insert data into the review table
125 | -- In SQL Server, prefixing a string literal with N before storing it in an NVARCHAR
126 | -- (or NCHAR or NTEXT) column is important because it signifies that the subsequent
127 | -- string is in Unicode format. Unicode data types can store any character from
128 | -- any character set, including special characters and characters from non-Latin
129 | -- languages like Chinese, Japanese, Arabic, etc
130 | INSERT INTO
131 | review (review_id, product_id, review_text, datetime)
132 | VALUES
133 | (
134 | 1,
135 | 3,
136 | N'Great product, would definitely recommend!',
137 | '2022-01-01 12:30:00'
138 | ),
139 | (
140 | 2,
141 | 5,
142 | N'This is the best thing I have ever bought!',
143 | '2022-01-02 13:45:00'
144 | ),
145 | (
146 | 3,
147 | 2,
148 | N'Not worth the money, would not recommend',
149 | '2022-01-03 14:15:00'
150 | ),
151 | (
152 | 4,
153 | 4,
154 | N'Disappointing purchase. Wouldn''t buy again.',
155 | '2022-01-04 15:00:00'
156 | ),
157 | (
158 | 5,
159 | 1,
160 | N'Decent product for the price, happy with my purchase',
161 | '2022-01-05 16:30:00'
162 | ),
163 | (
164 | 6,
165 | 2,
166 | N'Really impressed with the quality of this product!',
167 | '2022-01-06 17:00:00'
168 | ),
169 | (
170 | 7,
171 | 4,
172 | N'Great value for the price, would buy again',
173 | '2022-01-07 18:15:00'
174 | ),
175 | (
176 | 8,
177 | 3,
178 | N'Not the best quality, but it gets the job done',
179 | '2022-01-08 19:00:00'
180 | ),
181 | (
182 | 9,
183 | 5,
184 | N'I am really happy with this purchase, it exceeded my expectations',
185 | '2022-01-09 20:30:00'
186 | ),
187 | (
188 | 10,
189 | 1,
190 | N'Would not recommend this product, very disappointing',
191 | '2022-01-10 21:00:00'
192 | ),
193 | (
194 | 11,
195 | 3,
196 | N'This product is great, I use it every day!',
197 | '2022-01-11 22:15:00'
198 | ),
199 | (
200 | 12,
201 | 5,
202 | N'I would definitely buy this again, great value for the price',
203 | '2022-01-12 23:00:00'
204 | );
--------------------------------------------------------------------------------
/chapter_02/sqlite_db.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************************
2 | RDBMS: SQLite
3 | Create Date: 05/20/2023
4 | Author: Qiang Hao
5 | Description: Create a pair of two related tables, product and review,
6 | and insert some data into the two tables that support the
7 | onlinestore_chapter2 database.
8 | Note: This script is for SQLite.
9 | *************************************************************************************/
10 |
11 |
12 | -- Connect to a new or existing database file
13 | -- Connect to the database
14 | ATTACH DATABASE 'onlinestore_chapter2.db' AS onlinestore2;
15 |
16 | -- Create the product table
17 | -- SQlite database doesn't support DECIMAL data type, so we use TEXT instead
18 | -- This is typical when the precision of the number is important
19 | -- The alternative is to use REAL, which is a floating-point number and is not precise
20 | -- VARCHAR is the same as TEXT and comes with no length limit in SQLite, so we use TEXT instead
21 | DROP TABLE IF EXISTS onlinestore2.product;
22 | CREATE TABLE onlinestore2.product (
23 | product_id INT PRIMARY KEY,
24 | name TEXT NOT NULL,
25 | description TEXT NOT NULL,
26 | price TEXT NOT NULL,
27 | manufacturer TEXT NOT NULL
28 | );
29 |
30 | -- Insert data into the product table
31 | INSERT INTO
32 | onlinestore2.product (
33 | product_id,
34 | name,
35 | description,
36 | price,
37 | manufacturer
38 | )
39 | VALUES
40 | (
41 | 1,
42 | 'Atomic Nose Hair Trimmer',
43 | 'Trim your nose hairs with the precision of an atomic clock!',
44 | '19.99',
45 | 'Mad Inventors Inc.'
46 | ),
47 | (
48 | 2,
49 | 'Selfie Toaster',
50 | 'Get your face on your toast every morning with our selfie toaster!',
51 | '24.99',
52 | 'Goofy Gadgets Corp.'
53 | ),
54 | (
55 | 3,
56 | 'Cat-Poop Coffee',
57 | 'The only coffee made from the finest cat poop beans!',
58 | '29.99',
59 | 'Absurd Accessories'
60 | ),
61 | (
62 | 4,
63 | 'Inflatable Briefcase',
64 | 'Need more storage space? Inflate our briefcase to double its size!',
65 | '39.99',
66 | 'Wacky Wares Ltd.'
67 | ),
68 | (
69 | 5,
70 | 'Unicorn Horn Polish',
71 | 'Keep your unicorn''s horn shiny and smooth with our magical polish!',
72 | '9.99',
73 | 'Silly Supplies Co.'
74 | ),
75 | (
76 | 6,
77 | 'The Mind Probe',
78 | 'A device from Star Wars that can extract information directly from a person''s mind.',
79 | '19.99',
80 | 'Mad Inventors Inc.'
81 | ),
82 | (
83 | 7,
84 | 'Lightsabers',
85 | 'Elegant and deadly energy swords wielded by Jedi and Sith alike.',
86 | '25',
87 | 'Mad Inventors Inc.'
88 | ),
89 | (
90 | 8,
91 | 'The Sonic Screwdriver',
92 | 'A versatile tool capable of performing a wide variety of tasks, from unlocking doors to repairing electronics.',
93 | '15.1',
94 | 'Absurd Accessories'
95 | ),
96 | (
97 | 9,
98 | 'The Infinite Improbability Generator',
99 | 'A device that can create impossible and absurd events, such as a spaceship suddenly turning into a giant sperm whale.',
100 | '9.99',
101 | 'Silly Supplies Co.'
102 | ),
103 | (
104 | 10,
105 | 'The Neuralyzer',
106 | 'A flashy device that erases people''s memories of specific events or encounters.',
107 | '33.55',
108 | 'Silly Supplies Co.'
109 | );
110 |
111 | -- Create the review table
112 | --- SQLite doesn't support DATETIME data type, so we use TEXT instead
113 | -- This is a common workaround for SQLite
114 | -- The datetime('now') function is used to get the current timestamp
115 | -- in a format compatible with SQLite.
116 | DROP TABLE IF EXISTS onlinestore2.review;
117 | CREATE TABLE onlinestore2.review (
118 | review_id INT PRIMARY KEY,
119 | product_id INT NOT NULL,
120 | review_text TEXT NOT NULL,
121 | datetime TEXT NOT NULL DEFAULT (datetime('now')),
122 | CONSTRAINT fk_product_review FOREIGN KEY (product_id) REFERENCES product (product_id)
123 | );
124 |
125 | -- Enable foreign key constraints
126 | PRAGMA foreign_keys = ON;
127 |
128 | -- Insert data into the review table
129 | INSERT INTO
130 | onlinestore2.review (
131 | review_id,
132 | product_id,
133 | review_text,
134 | datetime
135 | )
136 | VALUES
137 | (
138 | 1,
139 | 3,
140 | 'Great product, would definitely recommend!',
141 | '2022-01-01 12:30:00'
142 | ),
143 | (
144 | 2,
145 | 5,
146 | 'This is the best thing I have ever bought!',
147 | '2022-01-02 13:45:00'
148 | ),
149 | (
150 | 3,
151 | 2,
152 | 'Not worth the money, would not recommend',
153 | '2022-01-03 14:15:00'
154 | ),
155 | (
156 | 4,
157 | 4,
158 | 'Disappointing purchase. Wouldn''t buy again.',
159 | '2022-01-04 15:00:00'
160 | ),
161 | (
162 | 5,
163 | 1,
164 | 'Decent product for the price, happy with my purchase',
165 | '2022-01-05 16:30:00'
166 | ),
167 | (
168 | 6,
169 | 2,
170 | 'Really impressed with the quality of this product!',
171 | '2022-01-06 17:00:00'
172 | ),
173 | (
174 | 7,
175 | 4,
176 | 'Great value for the price, would buy again',
177 | '2022-01-07 18:15:00'
178 | ),
179 | (
180 | 8,
181 | 3,
182 | 'Not the best quality, but it gets the job done',
183 | '2022-01-08 19:00:00'
184 | ),
185 | (
186 | 9,
187 | 5,
188 | 'I am really happy with this purchase, it exceeded my expectations',
189 | '2022-01-09 20:30:00'
190 | ),
191 | (
192 | 10,
193 | 1,
194 | 'Would not recommend this product, very disappointing',
195 | '2022-01-10 21:00:00'
196 | ),
197 | (
198 | 11,
199 | 3,
200 | 'This product is great, I use it every day!',
201 | '2022-01-11 22:15:00'
202 | ),
203 | (
204 | 12,
205 | 5,
206 | 'I would definitely buy this again, great value for the price',
207 | '2022-01-12 23:00:00'
208 | );
--------------------------------------------------------------------------------
/chapter_02/sqlite_online.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************************
2 | Create Date: 05/20/2023
3 | Author: Qiang Hao
4 | Description: Create a pair of two related tables, product and review,
5 | and insert some data into the two tables that support the
6 | onlinestore database.
7 | Note: This script is for the tool named SQLite Online.
8 | *************************************************************************************/
9 |
10 | -- Create the product table and insert some data
11 | DROP TABLE IF EXISTS product;
12 | CREATE TABLE product (
13 | product_id INT NOT NULL,
14 | name TEXT NOT NULL,
15 | description TEXT NOT NULL,
16 | price DECIMAL(5, 2) NOT NULL,
17 | manufacturer TEXT NOT NULL,
18 | PRIMARY KEY (product_id)
19 | );
20 |
21 | INSERT INTO
22 | product (
23 | product_id,
24 | name,
25 | description,
26 | price,
27 | manufacturer
28 | )
29 | VALUES
30 | (
31 | 1,
32 | 'Atomic Nose Hair Trimmer',
33 | 'Trim your nose hairs with the precision of an atomic clock!',
34 | 19.99,
35 | 'Mad Inventors Inc.'
36 | ),
37 | (
38 | 2,
39 | 'Selfie Toaster',
40 | 'Get your face on your toast every morning with our selfie toaster!',
41 | 24.99,
42 | 'Goofy Gadgets Corp.'
43 | ),
44 | (
45 | 3,
46 | 'Cat-Poop Coffee',
47 | 'The only coffee made from the finest cat poop beans!',
48 | 29.99,
49 | 'Absurd Accessories'
50 | ),
51 | (
52 | 4,
53 | 'Inflatable Briefcase',
54 | 'Need more storage space? Inflate our briefcase to double its size!',
55 | 39.99,
56 | 'Wacky Wares Ltd.'
57 | ),
58 | (
59 | 5,
60 | 'Unicorn Horn Polish',
61 | 'Keep your unicorn''s horn shiny and smooth with our magical polish!',
62 | 9.99,
63 | 'Silly Supplies Co.'
64 | ),
65 | (
66 | 6,
67 | 'The Mind Probe',
68 | 'A device from Star Wars that can extract information directly from a person''s mind.',
69 | 19.99,
70 | 'Mad Inventors Inc.'
71 | ),
72 | (
73 | 7,
74 | 'Lightsabers',
75 | 'Elegant and deadly energy swords wielded by Jedi and Sith alike.',
76 | 25,
77 | 'Mad Inventors Inc.'
78 | ),
79 | (
80 | 8,
81 | 'The Sonic Screwdriver',
82 | 'A versatile tool capable of performing a wide variety of tasks, from unlocking doors to repairing electronics.',
83 | 15.1,
84 | 'Absurd Accessories'
85 | ),
86 | (
87 | 9,
88 | 'The Infinite Improbability Generator',
89 | 'A device that can create impossible and absurd events, such as a spaceship suddenly turning into a giant sperm whale.',
90 | 9.99,
91 | 'Silly Supplies Co.'
92 | ),
93 | (
94 | 10,
95 | 'The Neuralyzer',
96 | 'A flashy device that erases people''s memories of specific events or encounters.',
97 | 33.55,
98 | 'Silly Supplies Co.'
99 | );
100 |
101 | -- Create the review table and insert some data
102 | DROP TABLE IF EXISTS review;
103 | CREATE TABLE review (
104 | review_id BIGINT NOT NULL,
105 | product_id INT NOT NULL,
106 | review_text TEXT NOT NULL,
107 | datetime DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
108 | PRIMARY KEY (review_id),
109 | CONSTRAINT fk_product_review FOREIGN KEY (product_id) REFERENCES product (product_id)
110 | );
111 |
112 | INSERT INTO
113 | review (
114 | review_id,
115 | product_id,
116 | review_text,
117 | datetime
118 | )
119 | VALUES
120 | (
121 | 1,
122 | 3,
123 | 'Great product, would definitely recommend!',
124 | '2022-01-01 12:30:00'
125 | ),
126 | (
127 | 2,
128 | 5,
129 | 'This is the best thing I have ever bought!',
130 | '2022-01-02 13:45:00'
131 | ),
132 | (
133 | 3,
134 | 2,
135 | 'Not worth the money, would not recommend',
136 | '2022-01-03 14:15:00'
137 | ),
138 | (
139 | 4,
140 | 4,
141 | 'Disappointing purchase. Wouldn''t buy again.',
142 | '2022-01-04 15:00:00'
143 | ),
144 | (
145 | 5,
146 | 1,
147 | 'Decent product for the price, happy with my purchase',
148 | '2022-01-05 16:30:00'
149 | ),
150 | (
151 | 6,
152 | 2,
153 | 'Really impressed with the quality of this product!',
154 | '2022-01-06 17:00:00'
155 | ),
156 | (
157 | 7,
158 | 4,
159 | 'Great value for the price, would buy again',
160 | '2022-01-07 18:15:00'
161 | ),
162 | (
163 | 8,
164 | 3,
165 | 'Not the best quality, but it gets the job done',
166 | '2022-01-08 19:00:00'
167 | ),
168 | (
169 | 9,
170 | 5,
171 | 'I am really happy with this purchase, it exceeded my expectations',
172 | '2022-01-09 20:30:00'
173 | ),
174 | (
175 | 10,
176 | 1,
177 | 'Would not recommend this product, very disappointing',
178 | '2022-01-10 21:00:00'
179 | ),
180 | (
181 | 11,
182 | 3,
183 | 'This product is great, I use it every day!',
184 | '2022-01-11 22:15:00'
185 | ),
186 | (
187 | 12,
188 | 5,
189 | 'I would definitely buy this again, great value for the price',
190 | '2022-01-12 23:00:00'
191 | );
--------------------------------------------------------------------------------
/chapter_04/README.md:
--------------------------------------------------------------------------------
1 | # Entities and attributes
2 |
3 | Practioners use tools such as dbdiagram.io, LucidChart, or MySQL Workbench to create and edit E-R diagrams.
4 |
5 | The corresponding chapter in this book developed the entities and their attributes for the database of The Sci-fi Collective. You can find the developed entities and their attributes, as well as how to load (or check) them using corresponding tools.
6 |
7 | - [View or edit the E-R diagram via dbdiagram](#view-or-edit-the-e-r-diagram-via-dbdiagram)
8 | - [View or edit the E-R diagram via MySQL Workbench](#view-or-edit-the-e-r-diagram-via-mysql-workbench)
9 | - [Modifications to attributes for different RDBMS](#modifications-to-attributes-for-different-rdbms)
10 |
11 | The final state of entities as described in Chapter 4 is as follows:
12 |
13 |
14 |
15 | ## View or edit the E-R diagram via dbdiagram
16 |
17 | [dbdiagram.io](https://dbdiagram.io) is a free online tool for drawing E-R Diagrams by writing code. You can also generate `SQL CREATE TABLE` statements given a diagram using dbdiagram.io. dbdiagram.io supports three RDBMS: MySQL, PostgreSQL, and SQL Server.
18 |
19 | What we achieved in this chapter is not the end of the E-R diagram that we aim to develop. As a result, we only provide a MySQL script (`dbdiagram.sql`) that correspond to the final state of entities and attributes of this chapter.
20 |
21 |
22 |
23 | When you import the provided script into dbdiagram.io, you will be able to view or edit the corresponding E-R diagram. You can also generate a new SQL script for PostgreSQL or SQL server from the diagram. To import the script, please follow the steps below:
24 |
25 | 1. Visit the [dbdiagram.io](https://dbdiagram.io/home) website, and log into your account.
26 | 2. Click on the "Import Database" button in the top navigation bar.
27 | 3. You can either copy and paste the content of the `dbdiagram.sql` file into the text area or click on the "Upload .sql" button to upload the `dbdiagram.sql` file.
28 | 4. When you are done, click on the "Submit" button.
29 |
30 | You can refer to [the manual of diagram.io](https://dbdiagram.io/docs/) if you have any questions about diagram.io.
31 |
32 | ## View or edit the E-R diagram via MySQL Workbench
33 |
34 | MySQL Workbench is an administration tool for MySQL as much as an E-R diagramming software. Different from dbdiagram.io, MySQL Workbench is a desktop application that you need to install on your computer. Additionally, MySQL only supports MySQL as the RDBMS. However, you can use use MySQL Workbench to generate a MySQL script first, and then convert it to scripts for other RSBMS using SQL converter tools such as [SQLines](https://sqlines.com/online).
35 |
36 | There are extensive tutorials for how to use MySQL Workbench for Database Design, you can use this part of the manual as a reference: [Database Design and Modeling](https://dev.mysql.com/doc/workbench/en/wb-data-modeling.html). MySQL Workbench is available for Windows, Linux, and Mac.
37 |
38 | ### Windows
39 |
40 | 1. Visit the [MySQL Workbench Download Page](https://dev.mysql.com/downloads/workbench/).
41 | 2. Download the `mysql-workbench-community-8.0.33-winx64.msi` file from "Other Downloads" section. The Download button is to the right. Make sure to download this file since if you download the MySQL Installer it will also install MySQL on your system (which we assume you already have installed from previous chapters and do not need to on this one).
42 | 3. Follow the installation instructions from the installer.
43 | 4. Once installed, double-click on the file or use File -> Open Model ... from within MySQL Workbench.
44 | 5. The file (`workbench.mwb`) is a MySQL Workbench Document that allows you to edit entity relationship diagrams and generate SQL CREATE TABLE statements based on these diagrams. The current file contains all entities as described in their final state in Chapter 4.
45 | 6. Once you see the entities you can freely double-click and evaluate them as well as make any necessary changes.
46 |
47 | ### Linux
48 |
49 | 1. Visit the [MySQL Workbench Download Page](https://dev.mysql.com/downloads/workbench/).
50 | 2. Download the `mysql-workbench-community-8.0.33-1.el8.x86_64.rpm` file from "Other Downloads" section. The Download button is to the right. Make sure to download this file since if you download the MySQL Installer it will also install MySQL on your system (which we assume you already have installed from previous chapters and do not need to on this one).
51 | 3. Follow the installation instructions from the installer.
52 | 4. Once installed, double-click on the file or use File -> Open Model ... from within MySQL Workbench.
53 | 5. The file (`workbench.mwb`) is a MySQL Workbench Document that allows you to edit entity relationship diagrams and generate SQL CREATE TABLE statements based on these diagrams. The current file contains all entities as described in their final state in Chapter 4.
54 | 6. Once you see the entities you can freely double-click and evaluate them as well as make any necessary changes.
55 |
56 | ### Mac
57 |
58 | 1. Visit the [MySQL Workbench Download Page](https://dev.mysql.com/downloads/workbench/).
59 | 2. Download the `mysql-workbench-community-8.0.33-macos-x86_64.dmg` file from "Other Downloads" section. The Download button is to the right. Make sure to download this file since if you download the MySQL Installer it will also install MySQL on your system (which we assume you already have installed from previous chapters).
60 | 3. Follow the installation instructions from the installer.
61 | 4. Once installed, double-click on the file or use File -> Open Model ... from within MySQL Workbench.
62 | 5. The file (`workbench.mwb`) is a MySQL Workbench Document that allows you to edit entity relationship diagrams and generate SQL CREATE TABLE statements based on these diagrams. The current file contains all entities as described in their final state in Chapter 4.
63 | 6. Once you see the entities you can freely double-click and evaluate them as well as make any necessary changes.
64 |
65 | ## Modifications to attributes for different RDBMS
66 |
67 | You will need to make some modifications to the attributes for different RDBMS. Considering that this chapter is not the end of the E-R diagram that we are still developing, we won't provide different versions of the E-R diagram tailored to different RDBMS. Instead, we will only describe the necessary modifications for SQL Server, SQLite and Oracle below for your reference.
68 |
69 | ### MySQL and MariaDB
70 |
71 | The entities and attributes depicted in the E-R diagram don't require any modifications for MySQL and MariaDB.
72 |
73 | ### PostgreSQL
74 |
75 | `user` is a reserved keyword in PostgreSQL. You can't use it as a table name. You can use `system_user` instead of `user`.
76 |
77 | ### SQL Server
78 |
79 | The following changes need to be made for SQL Server:
80 |
81 | * `TIMESTAMP` to `DATETIMEOFFSET`
82 | * `VARCHAR` to `NVARCHAR`
83 | * `TEXT` to `NVARCHAR(MAX)`
84 |
85 | **`TIMESTAMP` to `DATETIMEOFFSET`**: SQL Server uses DATETIMEOFFSET instead of TIMESTAMP. DATETIMEOFFSET stores the date, time, and offset from UTC. DATETIMEOFFSET is a SQL Server-specific data type that is not part of the ANSI SQL standard. DATETIMEOFFSET is used when you need to store the time zone offset of a particular date and time value.
86 |
87 | **`VARCHAR` to `NVARCHAR`**: It is recommended to use `NVARCHAR` instead of `VARCHAR` for SQL Server. `VARCHAR` is used for non-Unicode character data. It stores ASCII characters and can represent a limited set of characters (specifically those in the code page of your server's collation setting). `NVARCHAR` is used for Unicode character data -- It can store characters from multiple languages and alphabets and uses two bytes per character.If your application needs to support multiple languages or special characters that are not represented in the default character set, then you should use `NVARCHAR`.
88 |
89 | **`TEXT` to `NVARCHAR(MAX)`**: `TEXT` is a deprecated data type in SQL Server. It is recommended to use `NVARCHAR(MAX)` instead of `TEXT`. `NVARCHAR(MAX)` is used for Unicode character data of variable length. `NVARCHAR(MAX)` can store up to 2GB of data. `NVARCHAR(MAX)` is a SQL Server-specific data type that is not part of the ANSI SQL standard. `NVARCHAR(MAX)` is used when you need to store large amounts of Unicode character data (more than 4000 characters).
90 |
91 | ### SQLite
92 |
93 | The following changes need to be made for SQLite:
94 |
95 | * `TIMESTAMP` to `TEXT`
96 | * `CHAR` and `VARCHAR` to `TEXT`
97 | * `DECIMAL` to `INT` or `TEXT`
98 |
99 | **`TIMESTAMP` to `TEXT`**: SQLite doesn't support the `TIMESTAMP` data type. It is recommended to use `TEXT` instead of `TIMESTAMP` for SQLite.
100 |
101 | **`CHAR` and `VARCHAR` to `TEXT`**: `CHAR` and `VARCHAR` are the same as `TEXT` in SQLite, and all of which have no length limit in SQLite.
102 |
103 | **`DECIMAL` to `INT` or `TEXT`**: SQLite doesn't support `DECIMAL` data type. `REAL` is typically used instead of `DECIMAL` in SQLite when precision doesn't matter. When precision matters, `INT` or `TEXT` are typically used in practice for decimal numbers.
104 |
105 |
115 |
--------------------------------------------------------------------------------
/chapter_04/dbdiagram.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************************
2 | RDBMS: MySQL
3 | Create Date: 01/17/2023
4 | Author: Qiang Hao
5 | Description: Create all the tables for the scificollective_chapter4 database
6 | corresponding to what's covered in Chapter 4.
7 | *************************************************************************************/
8 |
9 | -- create database scificollective_chapter4
10 | -- character set utf8
11 | CREATE DATABASE IF NOT EXISTS scificollective_chapter4
12 | CHARACTER SET utf8
13 | COLLATE utf8_general_ci;
14 |
15 | -- Use the database
16 | USE scificollective_chapter4;
17 |
18 | -- Table payment_method
19 | DROP TABLE IF EXISTS payment_method;
20 | CREATE TABLE payment_method (
21 | payment_id INT PRIMARY KEY,
22 | name VARCHAR(30),
23 | card_number CHAR(16),
24 | expiry_date CHAR(4),
25 | billing_address VARCHAR(255)
26 | );
27 |
28 |
29 | -- Table product
30 | DROP TABLE IF EXISTS product;
31 | CREATE TABLE product (
32 | code CHAR(12) PRIMARY KEY,
33 | name VARCHAR(100),
34 | description TEXT,
35 | manufacturer VARCHAR(100),
36 | photo VARCHAR(1000),
37 | price DECIMAL(7,2),
38 | cost DECIMAL(7,2),
39 | inventory_quantity INT
40 | );
41 |
42 |
43 | -- Table purchase
44 | DROP TABLE IF EXISTS purchase;
45 | CREATE TABLE purchase (
46 | purchase_id INT PRIMARY KEY,
47 | total_price DECIMAL(13,2),
48 | purchase_time TIMESTAMP,
49 | product_time DECIMAL(7,2),
50 | product_quantity INT
51 | );
52 |
53 |
54 |
55 | -- Table review
56 | DROP TABLE IF EXISTS review;
57 | CREATE TABLE review (
58 | review_id INT PRIMARY KEY,
59 | review_text TEXT,
60 | review_time TIMESTAMP
61 | );
62 |
63 |
64 | -- Table user
65 | DROP TABLE IF EXISTS user;
66 | CREATE TABLE user (
67 | email VARCHAR(320) PRIMARY KEY,
68 | username VARCHAR(30),
69 | password VARCHAR(20),
70 | first_name VARCHAR(50),
71 | last_name VARCHAR(50),
72 | address VARCHAR(255),
73 | phone_number VARCHAR(15),
74 | last_login_time TIMESTAMP
75 | );
76 |
--------------------------------------------------------------------------------
/chapter_04/images/dbdiagram.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/chapter_04/images/dbdiagram.png
--------------------------------------------------------------------------------
/chapter_04/images/er-diagram.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/chapter_04/images/er-diagram.png
--------------------------------------------------------------------------------
/chapter_04/workbench.mwb:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/chapter_04/workbench.mwb
--------------------------------------------------------------------------------
/chapter_05/README.md:
--------------------------------------------------------------------------------
1 | # Relationships
2 |
3 | Practioners use tools such as dbdiagram.io, LucidChart, or MySQL Workbench to create and edit E-R diagrams.
4 |
5 | The corresponding chapter in this book developed the entities and their attributes for the database of The Sci-fi Collective. You can find the developed entities and their relationships, as well as how to load (or check) them using corresponding tools.
6 |
7 | - [View or edit the E-R diagram via dbdiagram](#view-or-edit-the-e-r-diagram-via-dbdiagram)
8 | - [View or edit the E-R diagram via MySQL Workbench](#view-or-edit-the-e-r-diagram-via-mysql-workbench)
9 | - [Modifications to attributes for different RDBMS](#modifications-to-attributes-for-different-rdbms)
10 |
11 | The final state of entities as described in Chapter 5 is as follows:
12 |
13 |
14 |
15 | ## View or edit the E-R diagram via dbdiagram
16 |
17 | [dbdiagram.io](https://dbdiagram.io) is a free online tool for drawing E-R Diagrams by writing code. You can also generate `SQL CREATE TABLE` statements given a diagram using dbdiagram.io. dbdiagram.io supports three RDBMS: MySQL, PostgreSQL, and SQL Server.
18 |
19 | What we achieved in this chapter is not the end of the E-R diagram that we aim to develop. As a result, we only provide a MySQL script (`dbdiagram.sql`) that correspond to the final state of entities and relationships of this chapter.
20 |
21 |
22 |
23 | When you import the provided script into dbdiagram.io, you will be able to view or edit the corresponding E-R diagram. You can also generate a new SQL script for PostgreSQL or SQL server from the diagram. To import the script, please follow the steps below:
24 |
25 | 1. Visit the [dbdiagram.io](https://dbdiagram.io/home) website, and log into your account.
26 | 2. Click on the "Import Database" button in the top navigation bar.
27 | 3. You can either copy and paste the content of the `dbdiagram.sql` file into the text area or click on the "Upload .sql" button to upload the `dbdiagram.sql` file.
28 | 4. When you are done, click on the "Submit" button.
29 |
30 | You can refer to [the manual of diagram.io](https://dbdiagram.io/docs/) if you have any questions about diagram.io.
31 |
32 | ## View or edit the E-R diagram via MySQL Workbench
33 |
34 | MySQL Workbench is an administration tool for MySQL as much as an E-R diagramming software. Different from dbdiagram.io, MySQL Workbench is a desktop application that you need to install on your computer. Additionally, MySQL only supports MySQL as the RDBMS. However, you can use use MySQL Workbench to generate a MySQL script first, and then convert it to scripts for other RSBMS using SQL converter tools such as [SQLines](https://sqlines.com/online).
35 |
36 | There are extensive tutorials for how to use MySQL Workbench for Database Design, you can use this part of the manual as a reference: [Database Design and Modeling](https://dev.mysql.com/doc/workbench/en/wb-data-modeling.html). MySQL Workbench is available for Windows, Linux, and Mac.
37 |
38 | ### Windows
39 |
40 | 1. Visit the [MySQL Workbench Download Page](https://dev.mysql.com/downloads/workbench/).
41 | 2. Download the `mysql-workbench-community-8.0.33-winx64.msi` file from "Other Downloads" section. The Download button is to the right. Make sure to download this file since if you download the MySQL Installer it will also install MySQL on your system (which we assume you already have installed from previous chapters and do not need to on this one).
42 | 3. Follow the installation instructions from the installer.
43 | 4. Once installed, double-click on the file or use File -> Open Model ... from within MySQL Workbench.
44 | 5. The file (`workbench.mwb`) is a MySQL Workbench Document that allows you to edit entity relationship diagrams and generate SQL CREATE TABLE statements based on these diagrams. The current file contains all entities as described in their final state in Chapter 5.
45 | 6. Once you see the entities you can freely double-click and evaluate them as well as make any necessary changes.
46 |
47 | ### Linux
48 |
49 | 1. Visit the [MySQL Workbench Download Page](https://dev.mysql.com/downloads/workbench/).
50 | 2. Download the `mysql-workbench-community-8.0.33-1.el8.x86_64.rpm` file from "Other Downloads" section. The Download button is to the right. Make sure to download this file since if you download the MySQL Installer it will also install MySQL on your system (which we assume you already have installed from previous chapters and do not need to on this one).
51 | 3. Follow the installation instructions from the installer.
52 | 4. Once installed, double-click on the file or use File -> Open Model ... from within MySQL Workbench.
53 | 5. The file (`workbench.mwb`) is a MySQL Workbench Document that allows you to edit entity relationship diagrams and generate SQL CREATE TABLE statements based on these diagrams. The current file contains all entities as described in their final state in Chapter 5.
54 | 6. Once you see the entities you can freely double-click and evaluate them as well as make any necessary changes.
55 |
56 | ### Mac
57 |
58 | 1. Visit the [MySQL Workbench Download Page](https://dev.mysql.com/downloads/workbench/).
59 | 2. Download the `mysql-workbench-community-8.0.33-macos-x86_64.dmg` file from "Other Downloads" section. The Download button is to the right. Make sure to download this file since if you download the MySQL Installer it will also install MySQL on your system (which we assume you already have installed from previous chapters).
60 | 3. Follow the installation instructions from the installer.
61 | 4. Once installed, double-click on the file or use File -> Open Model ... from within MySQL Workbench.
62 | 5. The file (`workbench.mwb`) is a MySQL Workbench Document that allows you to edit entity relationship diagrams and generate SQL CREATE TABLE statements based on these diagrams. The current file contains all entities as described in their final state in Chapter 5.
63 | 6. Once you see the entities you can freely double-click and evaluate them as well as make any necessary changes.
64 |
65 | ## Modifications for different RDBMS
66 |
67 | You will need to make some modifications to the attributes for different RDBMS. Considering that this chapter is not the end of the E-R diagram that we are still developing, we won't provide different versions of the E-R diagram tailored to different RDBMS. Instead, we will only describe the necessary modifications for SQL Server, SQLite and Oracle below for your reference.
68 |
69 | ### MySQL and MariaDB
70 |
71 | The entities and attributes depicted in the E-R diagram don't require any modifications for MySQL and MariaDB.
72 |
73 | ### PostgreSQL
74 |
75 | `user` is a reserved keyword in PostgreSQL. You can't use it as a table name. You can use `system_user` instead of `user`.
76 |
77 | ### SQL Server
78 |
79 | The following changes need to be made for SQL Server:
80 |
81 | * `TIMESTAMP` to `DATETIMEOFFSET`
82 | * `VARCHAR` to `NVARCHAR`
83 | * `TEXT` to `NVARCHAR(MAX)`
84 |
85 | **`TIMESTAMP` to `DATETIMEOFFSET`**: SQL Server uses DATETIMEOFFSET instead of TIMESTAMP. DATETIMEOFFSET stores the date, time, and offset from UTC. DATETIMEOFFSET is a SQL Server-specific data type that is not part of the ANSI SQL standard. DATETIMEOFFSET is used when you need to store the time zone offset of a particular date and time value.
86 |
87 | **`VARCHAR` to `NVARCHAR`**: It is recommended to use `NVARCHAR` instead of `VARCHAR` for SQL Server. `VARCHAR` is used for non-Unicode character data. It stores ASCII characters and can represent a limited set of characters (specifically those in the code page of your server's collation setting). `NVARCHAR` is used for Unicode character data -- It can store characters from multiple languages and alphabets and uses two bytes per character.If your application needs to support multiple languages or special characters that are not represented in the default character set, then you should use `NVARCHAR`.
88 |
89 | **`TEXT` to `NVARCHAR(MAX)`**: `TEXT` is a deprecated data type in SQL Server. It is recommended to use `NVARCHAR(MAX)` instead of `TEXT`. `NVARCHAR(MAX)` is used for Unicode character data of variable length. `NVARCHAR(MAX)` can store up to 2GB of data. `NVARCHAR(MAX)` is a SQL Server-specific data type that is not part of the ANSI SQL standard. `NVARCHAR(MAX)` is used when you need to store large amounts of Unicode character data (more than 4000 characters).
90 |
91 | ### SQLite
92 |
93 | The following changes need to be made for SQLite:
94 |
95 | * `TIMESTAMP` to `TEXT`
96 | * `CHAR` and `VARCHAR` to `TEXT`
97 | * `DECIMAL` to `INT` or `TEXT`
98 |
99 | **`TIMESTAMP` to `TEXT`**: SQLite doesn't support the `TIMESTAMP` data type. It is recommended to use `TEXT` instead of `TIMESTAMP` for SQLite.
100 |
101 | **`CHAR` and `VARCHAR` to `TEXT`**: `CHAR` and `VARCHAR` are the same as `TEXT` in SQLite, and all of which have no length limit in SQLite.
102 |
103 | **`DECIMAL` to `INT` or `TEXT`**: SQLite doesn't support `DECIMAL` data type. `REAL` is typically used instead of `DECIMAL` in SQLite when precision doesn't matter. When precision matters, `INT` or `TEXT` are typically used in practice for decimal numbers.
104 |
--------------------------------------------------------------------------------
/chapter_05/dbdiagram.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************************
2 | RDBMS: MySQL
3 | Create Date: 01/18/2023
4 | Author: Qiang Hao
5 | Description: Create all the tables for the scificollective_chapter5 database
6 | corresponding to what's covered in Chapter 5.
7 | *************************************************************************************/
8 |
9 | -- drop database scificollective_chapter5 if it exists
10 | DROP DATABASE IF EXISTS scificollective_chapter5;
11 |
12 | -- create database scificollective_chapter5
13 | -- character set utf8
14 | CREATE DATABASE IF NOT EXISTS scificollective_chapter5
15 | CHARACTER SET utf8
16 | COLLATE utf8_general_ci;
17 |
18 | -- Use the database
19 | USE scificollective_chapter5;
20 |
21 | -- Table payment_method
22 | DROP TABLE IF EXISTS payment_method;
23 | CREATE TABLE payment_method (
24 | payment_id INT PRIMARY KEY,
25 | name VARCHAR(30),
26 | card_number CHAR(16),
27 | expiry_date CHAR(4),
28 | email VARCHAR(320),
29 | CONSTRAINT fk_payment_method_user FOREIGN KEY (email) REFERENCES user (email)
30 | );
31 |
32 | -- Table product
33 | DROP TABLE IF EXISTS product;
34 | CREATE TABLE product (
35 | code CHAR(12) PRIMARY KEY,
36 | name VARCHAR(100),
37 | description TEXT,
38 | manufacturer VARCHAR(100),
39 | photo VARCHAR(1000),
40 | price DECIMAL(7, 2),
41 | cost DECIMAL(7, 2),
42 | inventory_quantity INT
43 | );
44 |
45 | -- Table purchase
46 | DROP TABLE IF EXISTS purchase;
47 | CREATE TABLE purchase (
48 | purchase_id INT PRIMARY KEY,
49 | total_price DECIMAL(13, 2),
50 | purchase_time TIMESTAMP,
51 | product_price DECIMAL(7, 2),
52 | product_quantity INT,
53 | payment_id INT,
54 | email VARCHAR(320),
55 | CONSTRAINT fk_purchase_payment_method FOREIGN KEY (payment_id) REFERENCES payment_method (payment_id),
56 | CONSTRAINT fk_purchase_user FOREIGN KEY (email) REFERENCES user (email)
57 | );
58 |
59 | -- Table purchase_product
60 | DROP TABLE IF EXISTS purchase_product;
61 | CREATE TABLE purchase_product (
62 | purchase_id INT,
63 | code CHAR(12),
64 | PRIMARY KEY (purchase_id, code),
65 | CONSTRAINT fk_product_has_purchase_product FOREIGN KEY (code) REFERENCES product (code),
66 | CONSTRAINT fk_product_has_purchase_purchase FOREIGN KEY (purchase_id) REFERENCES purchase (purchase_id)
67 | );
68 |
69 | -- Table review
70 | DROP TABLE IF EXISTS review;
71 | CREATE TABLE review (
72 | review_id INT PRIMARY KEY,
73 | review_text TEXT,
74 | review_time TIMESTAMP,
75 | email VARCHAR(320),
76 | code CHAR(12),
77 | CONSTRAINT fk_review_user FOREIGN KEY (email) REFERENCES user (email),
78 | CONSTRAINT fk_review_product FOREIGN KEY (code) REFERENCES product (code)
79 | );
80 |
81 | -- Table user
82 | DROP TABLE IF EXISTS user;
83 | CREATE TABLE user (
84 | email VARCHAR(320) PRIMARY KEY,
85 | username VARCHAR(30),
86 | password VARCHAR(20),
87 | first_name VARCHAR(50),
88 | last_name VARCHAR(50),
89 | address VARCHAR(255),
90 | phone_number VARCHAR(15),
91 | last_login_time TIMESTAMP
92 | );
93 |
94 | -- Table user_address
95 | DROP TABLE IF EXISTS user_address;
96 | CREATE TABLE user_address (
97 | email VARCHAR(320) PRIMARY KEY,
98 | street_address VARCHAR(255),
99 | address_line_optional VARCHAR(100),
100 | city VARCHAR(100),
101 | state VARCHAR(20),
102 | postal_code CHAR(5),
103 | CONSTRAINT fk_user_address_user FOREIGN KEY (email) REFERENCES user (email)
104 | );
105 |
106 | -- Table billing_address
107 | DROP TABLE IF EXISTS billing_address;
108 | CREATE TABLE billing_address (
109 | payment_id INT PRIMARY KEY,
110 | street_address VARCHAR(255),
111 | address_line_optional VARCHAR(100),
112 | city VARCHAR(100),
113 | state VARCHAR(20),
114 | postal_code CHAR(5),
115 | CONSTRAINT fk_payment_method_billing_address FOREIGN KEY (payment_id) REFERENCES payment_method (payment_id)
116 | );
--------------------------------------------------------------------------------
/chapter_05/images/dbdiagram.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/chapter_05/images/dbdiagram.png
--------------------------------------------------------------------------------
/chapter_05/images/er-diagram.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/chapter_05/images/er-diagram.png
--------------------------------------------------------------------------------
/chapter_05/workbench.mwb:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/chapter_05/workbench.mwb
--------------------------------------------------------------------------------
/chapter_06/README.md:
--------------------------------------------------------------------------------
1 | # Normalization and Implementation
2 |
3 | Practioners use tools such as dbdiagram.io, LucidChart, or MySQL Workbench to create and edit E-R diagrams.
4 |
5 | The corresponding chapter in this book developed the entities and their attributes for the database of The Sci-fi Collective. You can find the developed entities and their relationships, as well as how to load (or check) them using corresponding tools.
6 |
7 | - [View or edit the E-R diagram via dbdiagram](#view-or-edit-the-e-r-diagram-via-dbdiagram)
8 | - [View or edit the E-R diagram via MySQL Workbench](#view-or-edit-the-e-r-diagram-via-mysql-workbench)
9 |
10 | The final state of entities as described in Chapter 6 is as follows:
11 |
12 |
13 |
14 | ## View or edit the E-R diagram via dbdiagram
15 |
16 | [dbdiagram.io](https://dbdiagram.io) is a free online tool for drawing E-R Diagrams by writing code. You can also generate `SQL CREATE TABLE` statements given a diagram using dbdiagram.io. dbdiagram.io supports three RDBMS: MySQL, PostgreSQL, and SQL Server.
17 |
18 | What we achieved in this chapter is not the end of the E-R diagram that we aim to develop. As a result, we only provide a MySQL script (`dbdiagram.sql`) that correspond to the final state of entities and relationships of this chapter.
19 |
20 |
21 |
22 | When you import the provided script into dbdiagram.io, you will be able to view or edit the corresponding E-R diagram. You can also generate a new SQL script for PostgreSQL or SQL server from the diagram. To import the script, please follow the steps below:
23 |
24 | 1. Visit the [dbdiagram.io](https://dbdiagram.io/home) website, and log into your account.
25 | 2. Click on the "Import Database" button in the top navigation bar.
26 | 3. You can either copy and paste the content of the `dbdiagram.sql` file into the text area or click on the "Upload .sql" button to upload the `dbdiagram.sql` file.
27 | 4. When you are done, click on the "Submit" button.
28 |
29 | You can refer to [the manual of diagram.io](https://dbdiagram.io/docs/) if you have any questions about diagram.io.
30 |
31 | ## View or edit the E-R diagram via MySQL Workbench
32 |
33 | MySQL Workbench is an administration tool for MySQL as much as an E-R diagramming software. Different from dbdiagram.io, MySQL Workbench is a desktop application that you need to install on your computer. Additionally, MySQL only supports MySQL as the RDBMS. However, you can use use MySQL Workbench to generate a MySQL script first, and then convert it to scripts for other RSBMS using SQL converter tools such as [SQLines](https://sqlines.com/online).
34 |
35 | There are extensive tutorials for how to use MySQL Workbench for Database Design, you can use this part of the manual as a reference: [Database Design and Modeling](https://dev.mysql.com/doc/workbench/en/wb-data-modeling.html). MySQL Workbench is available for Windows, Linux, and Mac.
36 |
37 | ### Windows
38 |
39 | 1. Visit the [MySQL Workbench Download Page](https://dev.mysql.com/downloads/workbench/).
40 | 2. Download the `mysql-workbench-community-8.0.33-winx64.msi` file from "Other Downloads" section. The Download button is to the right. Make sure to download this file since if you download the MySQL Installer it will also install MySQL on your system (which we assume you already have installed from previous chapters and do not need to on this one).
41 | 3. Follow the installation instructions from the installer.
42 | 4. Once installed, double-click on the file or use File -> Open Model ... from within MySQL Workbench.
43 | 5. The file (`workbench.mwb`) is a MySQL Workbench Document that allows you to edit entity relationship diagrams and generate SQL CREATE TABLE statements based on these diagrams. The current file contains all entities as described in their final state in Chapter 6.
44 | 6. Once you see the entities you can freely double-click and evaluate them as well as make any necessary changes.
45 |
46 | ### Linux
47 |
48 | 1. Visit the [MySQL Workbench Download Page](https://dev.mysql.com/downloads/workbench/).
49 | 2. Download the `mysql-workbench-community-8.0.33-1.el8.x86_64.rpm` file from "Other Downloads" section. The Download button is to the right. Make sure to download this file since if you download the MySQL Installer it will also install MySQL on your system (which we assume you already have installed from previous chapters and do not need to on this one).
50 | 3. Follow the installation instructions from the installer.
51 | 4. Once installed, double-click on the file or use File -> Open Model ... from within MySQL Workbench.
52 | 5. The file (`workbench.mwb`) is a MySQL Workbench Document that allows you to edit entity relationship diagrams and generate SQL CREATE TABLE statements based on these diagrams. The current file contains all entities as described in their final state in Chapter 6.
53 | 6. Once you see the entities you can freely double-click and evaluate them as well as make any necessary changes.
54 |
55 | ### Mac
56 |
57 | 1. Visit the [MySQL Workbench Download Page](https://dev.mysql.com/downloads/workbench/).
58 | 2. Download the `mysql-workbench-community-8.0.33-macos-x86_64.dmg` file from "Other Downloads" section. The Download button is to the right. Make sure to download this file since if you download the MySQL Installer it will also install MySQL on your system (which we assume you already have installed from previous chapters).
59 | 3. Follow the installation instructions from the installer.
60 | 4. Once installed, double-click on the file or use File -> Open Model ... from within MySQL Workbench.
61 | 5. The file (`workbench.mwb`) is a MySQL Workbench Document that allows you to edit entity relationship diagrams and generate SQL CREATE TABLE statements based on these diagrams. The current file contains all entities as described in their final state in Chapter 6.
62 | 6. Once you see the entities you can freely double-click and evaluate them as well as make any necessary changes.
63 |
64 | ## Modifications for different RDBMS
65 |
66 | You will need to make some modifications to the attributes for different RDBMS. Considering that this chapter is not the end of the E-R diagram that we are still developing, we won't provide different versions of the E-R diagram tailored to different RDBMS. Instead, we will only describe the necessary modifications for SQL Server, SQLite and Oracle below for your reference.
67 |
68 | ### MySQL and MariaDB
69 |
70 | The entities and attributes depicted in the E-R diagram don't require any modifications for MySQL and MariaDB.
71 |
72 | ### PostgreSQL
73 |
74 | `user` is a reserved keyword in PostgreSQL. You can't use it as a table name. You can use `system_user` instead of `user`.
75 |
76 | ### SQL Server
77 |
78 | The following changes need to be made for SQL Server:
79 |
80 | **`TIMESTAMP` to `DATETIMEOFFSET`**: SQL Server uses DATETIMEOFFSET instead of TIMESTAMP. DATETIMEOFFSET stores the date, time, and offset from UTC. DATETIMEOFFSET is a SQL Server-specific data type that is not part of the ANSI SQL standard. DATETIMEOFFSET is used when you need to store the time zone offset of a particular date and time value.
81 |
82 | **`VARCHAR` to `NVARCHAR`**: It is recommended to use `NVARCHAR` instead of `VARCHAR` for SQL Server. `VARCHAR` is used for non-Unicode character data. It stores ASCII characters and can represent a limited set of characters (specifically those in the code page of your server's collation setting). `NVARCHAR` is used for Unicode character data -- It can store characters from multiple languages and alphabets and uses two bytes per character.If your application needs to support multiple languages or special characters that are not represented in the default character set, then you should use `NVARCHAR`.
83 |
84 | **`TEXT` to `NVARCHAR(MAX)`**: `TEXT` is a deprecated data type in SQL Server. It is recommended to use `NVARCHAR(MAX)` instead of `TEXT`. `NVARCHAR(MAX)` is used for Unicode character data of variable length. `NVARCHAR(MAX)` can store up to 2GB of data. `NVARCHAR(MAX)` is a SQL Server-specific data type that is not part of the ANSI SQL standard. `NVARCHAR(MAX)` is used when you need to store large amounts of Unicode character data (more than 4000 characters).
85 |
86 | **`AUTO_INCREMENT` to `IDENTITY`**: `IDENTITY` the name used for `AUTO_INCREMENT` in SQL Server. The effect is the same.
87 |
88 | **`CURRENT_TIMESTAMP` to `GETDATE()`**: The function name is different but the use is exactly the same.
89 |
90 | **`VISIBLE` is not necessary**: It is the default for SQL server so it is ommitted from the create table statement.
91 |
92 | ### SQLite
93 |
94 | The following changes need to be made for SQLite:
95 |
96 | **`TIMESTAMP` to `TEXT`**: SQLite doesn't support the `TIMESTAMP` data type. It is recommended to use `TEXT` instead of `TIMESTAMP` for SQLite.
97 |
98 | **`CHAR` and `VARCHAR` to `TEXT`**: `CHAR` and `VARCHAR` are the same as `TEXT` in SQLite, and all of which have no length limit in SQLite.
99 |
100 | **`DECIMAL` to `INT` or `TEXT`**: SQLite doesn't support `DECIMAL` data type. `REAL` is typically used instead of `DECIMAL` in SQLite when precision doesn't matter. When precision matters, `INT` or `TEXT` are typically used in practice for decimal numbers.
101 |
102 | **Character encodings not supported**: SQLite uses UTF-8 by default.
103 |
104 | **`AUTO_INCREMENT` to `INTEGER PRIMARY KEY`**: As long as a column is a primary key and integer the auto-incrementing effect is automatic.
105 |
106 | **`VISIBLE` is not necessary**: It is the default for SQLite so it is ommitted from the create table statement.
107 |
108 | **`CURRENT_TIMESTAMP` to `datetime('now')`**: Use is exactly the same just the syntax is different.
--------------------------------------------------------------------------------
/chapter_06/dbdiagram.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************************
2 | RDBMS: MySQL
3 | Create Date: 01/31/2023
4 | Author: Michail Tsikerdekis
5 | Description: Create all the tables for the scificollective_chapter6 database
6 | corresponding to what's covered in Chapter 6
7 | *************************************************************************************/
8 |
9 | -- drop database scificollective_chapter6 if it exists
10 | DROP DATABASE IF EXISTS scificollective_chapter6;
11 |
12 | -- create database scificollective_chapter6
13 | -- character set utf8
14 | CREATE DATABASE IF NOT EXISTS scificollective_chapter6
15 | CHARACTER SET utf8
16 | COLLATE utf8_general_ci;
17 |
18 | USE scificollective_chapter6;
19 |
20 | -- Table user
21 | DROP TABLE IF EXISTS user;
22 | CREATE TABLE IF NOT EXISTS user (
23 | email VARCHAR(320),
24 | username VARCHAR(30) NOT NULL,
25 | password VARCHAR(20) NOT NULL,
26 | first_name VARCHAR(50) NOT NULL,
27 | last_name VARCHAR(50) NOT NULL,
28 | phone_number VARCHAR(15),
29 | last_login_time TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
30 | PRIMARY KEY (email),
31 | UNIQUE INDEX unq_username (username ASC) VISIBLE,
32 | UNIQUE INDEX unq_phone_number (phone_number ASC) VISIBLE
33 | );
34 |
35 |
36 | -- Table product
37 | DROP TABLE IF EXISTS product;
38 | CREATE TABLE product (
39 | code CHAR(12),
40 | name VARCHAR(100) NOT NULL,
41 | description TEXT NOT NULL,
42 | manufacturer VARCHAR(100) NOT NULL,
43 | photo VARCHAR(1000) NOT NULL,
44 | price DECIMAL(7,2) NOT NULL,
45 | cost DECIMAL(7,2) NOT NULL,
46 | inventory_quantity INT NOT NULL,
47 | PRIMARY KEY (code),
48 | UNIQUE INDEX unq_name_manufacturer (name ASC, manufacturer ASC) VISIBLE
49 | );
50 |
51 | -- Table review
52 | DROP TABLE IF EXISTS review;
53 | CREATE TABLE IF NOT EXISTS review (
54 | review_id INT PRIMARY KEY,
55 | review_text TEXT NOT NULL,
56 | review_time TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
57 | email VARCHAR(320) NOT NULL,
58 | code CHAR(12) NOT NULL,
59 | CONSTRAINT fk_review_user FOREIGN KEY (email) REFERENCES user (email) ON DELETE CASCADE ON UPDATE CASCADE,
60 | CONSTRAINT fk_review_product FOREIGN KEY (code) REFERENCES product (code) ON DELETE CASCADE ON UPDATE CASCADE
61 | );
62 |
63 | -- Table payment_method
64 | DROP TABLE IF EXISTS payment_method;
65 | CREATE TABLE payment_method (
66 | payment_id INT PRIMARY KEY,
67 | name VARCHAR(30) NOT NULL,
68 | card_number CHAR(16) NOT NULL,
69 | expiry_date CHAR(4) NOT NULL,
70 | email VARCHAR(320) NOT NULL,
71 | CONSTRAINT fk_payment_method_user FOREIGN KEY (email) REFERENCES user (email)
72 | );
73 |
74 |
75 | -- Table `purchase`
76 | DROP TABLE IF EXISTS purchase;
77 | CREATE TABLE purchase (
78 | purchase_id INT PRIMARY KEY,
79 | total_price DECIMAL(13,2) NOT NULL DEFAULT 0,
80 | purchase_time TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
81 | payment_id INT NOT NULL,
82 | CONSTRAINT fk_purchase_payment_method FOREIGN KEY (payment_id) REFERENCES payment_method (payment_id)
83 | );
84 |
85 |
86 | -- Table user_address
87 | CREATE TABLE IF NOT EXISTS user_address (
88 | email VARCHAR(320) NOT NULL,
89 | street_address VARCHAR(255) NOT NULL,
90 | address_line_optional VARCHAR(100),
91 | city VARCHAR(100) NOT NULL,
92 | state VARCHAR(20) NOT NULL,
93 | postal_code CHAR(5) NOT NULL,
94 | PRIMARY KEY (email),
95 | CONSTRAINT fk_user_address_user
96 | FOREIGN KEY (email)
97 | REFERENCES user (email)
98 | ON DELETE CASCADE
99 | ON UPDATE CASCADE
100 | );
101 |
102 | -- Table billing_address
103 | CREATE TABLE IF NOT EXISTS billing_address (
104 | payment_id INT NOT NULL,
105 | street_address VARCHAR(255) NOT NULL,
106 | address_line_optional VARCHAR(100),
107 | city VARCHAR(100) NOT NULL,
108 | state VARCHAR(20) NOT NULL,
109 | postal_code CHAR(5) NOT NULL,
110 | PRIMARY KEY (payment_id),
111 | CONSTRAINT fk_billing_address_payment_id
112 | FOREIGN KEY (payment_id)
113 | REFERENCES payment_method (payment_id)
114 | ON DELETE CASCADE
115 | ON UPDATE CASCADE
116 | );
117 |
118 | -- Table purchase_product
119 | DROP TABLE IF EXISTS purchase_product;
120 | CREATE TABLE purchase_product (
121 | purchase_id INT NOT NULL,
122 | code CHAR(12) NOT NULL,
123 | product_price DECIMAL(7,2) NOT NULL,
124 | product_quantity INT NOT NULL DEFAULT 1,
125 | product_name VARCHAR(100) NOT NULL,
126 | PRIMARY KEY (code, purchase_id),
127 | CONSTRAINT fk_product_has_purchase_product1
128 | FOREIGN KEY (code)
129 | REFERENCES product (code)
130 | ON DELETE CASCADE
131 | ON UPDATE CASCADE,
132 | CONSTRAINT fk_product_has_purchase_purchase1
133 | FOREIGN KEY (purchase_id)
134 | REFERENCES purchase (purchase_id)
135 | ON DELETE CASCADE
136 | ON UPDATE CASCADE
137 | );
138 |
139 |
--------------------------------------------------------------------------------
/chapter_06/images/dbdiagram.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/chapter_06/images/dbdiagram.png
--------------------------------------------------------------------------------
/chapter_06/images/er-diagram.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/chapter_06/images/er-diagram.png
--------------------------------------------------------------------------------
/chapter_06/workbench.mwb:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/chapter_06/workbench.mwb
--------------------------------------------------------------------------------
/chapter_07/README.md:
--------------------------------------------------------------------------------
1 | # Security and Optimization
2 |
3 | Practioners use tools such as dbdiagram.io, LucidChart, or MySQL Workbench to create and edit E-R diagrams.
4 |
5 | The corresponding chapter in this book developed the entities and their attributes for the database of The Sci-fi Collective. You can find the developed entities and their relationships, as well as how to load (or check) them using corresponding tools.
6 |
7 | - [View or edit the E-R diagram via dbdiagram](#view-or-edit-the-e-r-diagram-via-dbdiagram)
8 | - [View or edit the E-R diagram via MySQL Workbench](#view-or-edit-the-e-r-diagram-via-mysql-workbench)
9 |
10 | The final state of entities as described in Chapter 7 is as follows:
11 |
12 |
13 |
14 |
15 |
16 | ## View or edit the E-R diagram via dbdiagram
17 |
18 | [dbdiagram.io](https://dbdiagram.io) is a free online tool for drawing E-R Diagrams by writing code. You can also generate `SQL CREATE TABLE` statements given a diagram using dbdiagram.io. dbdiagram.io supports three RDBMS: MySQL, PostgreSQL, and SQL Server.
19 |
20 | What we achieved in this chapter is not the end of the E-R diagram that we aim to develop. As a result, we only provide a MySQL script (`dbdiagram.sql`) that correspond to the final state of entities and relationships of this chapter.
21 |
22 |
23 |
24 | When you import the provided script into dbdiagram.io, you will be able to view or edit the corresponding E-R diagram. You can also generate a new SQL script for PostgreSQL or SQL server from the diagram. To import the script, please follow the steps below:
25 |
26 | 1. Visit the [dbdiagram.io](https://dbdiagram.io/home) website, and log into your account.
27 | 2. Click on the "Import Database" button in the top navigation bar.
28 | 3. You can either copy and paste the content of the `dbdiagram.sql` file into the text area or click on the "Upload .sql" button to upload the `dbdiagram.sql` file.
29 | 4. When you are done, click on the "Submit" button.
30 |
31 | You can refer to [the manual of diagram.io](https://dbdiagram.io/docs/) if you have any questions about diagram.io.
32 |
33 | ## View or edit the E-R diagram via MySQL Workbench
34 |
35 | MySQL Workbench is an administration tool for MySQL as much as an E-R diagramming software. Different from dbdiagram.io, MySQL Workbench is a desktop application that you need to install on your computer. Additionally, MySQL only supports MySQL as the RDBMS. However, you can use use MySQL Workbench to generate a MySQL script first, and then convert it to scripts for other RSBMS using SQL converter tools such as [SQLines](https://sqlines.com/online).
36 |
37 | There are extensive tutorials for how to use MySQL Workbench for Database Design, you can use this part of the manual as a reference: [Database Design and Modeling](https://dev.mysql.com/doc/workbench/en/wb-data-modeling.html). MySQL Workbench is available for Windows, Linux, and Mac.
38 |
39 | ### Windows
40 |
41 | 1. Visit the [MySQL Workbench Download Page](https://dev.mysql.com/downloads/workbench/).
42 | 2. Download the `mysql-workbench-community-8.0.33-winx64.msi` file from "Other Downloads" section. The Download button is to the right. Make sure to download this file since if you download the MySQL Installer it will also install MySQL on your system (which we assume you already have installed from previous chapters and do not need to on this one).
43 | 3. Follow the installation instructions from the installer.
44 | 4. Once installed, double-click on the file or use File -> Open Model ... from within MySQL Workbench.
45 | 5. The file (`workbench.mwb`) is a MySQL Workbench Document that allows you to edit entity relationship diagrams and generate SQL CREATE TABLE statements based on these diagrams. The current file contains all entities as described in their final state in Chapter 7.
46 | 6. Once you see the entities you can freely double-click and evaluate them as well as make any necessary changes.
47 |
48 | ### Linux
49 |
50 | 1. Visit the [MySQL Workbench Download Page](https://dev.mysql.com/downloads/workbench/).
51 | 2. Download the `mysql-workbench-community-8.0.33-1.el8.x86_64.rpm` file from "Other Downloads" section. The Download button is to the right. Make sure to download this file since if you download the MySQL Installer it will also install MySQL on your system (which we assume you already have installed from previous chapters and do not need to on this one).
52 | 3. Follow the installation instructions from the installer.
53 | 4. Once installed, double-click on the file or use File -> Open Model ... from within MySQL Workbench.
54 | 5. The file (`workbench.mwb`) is a MySQL Workbench Document that allows you to edit entity relationship diagrams and generate SQL CREATE TABLE statements based on these diagrams. The current file contains all entities as described in their final state in Chapter 7.
55 | 6. Once you see the entities you can freely double-click and evaluate them as well as make any necessary changes.
56 |
57 | ### Mac
58 |
59 | 1. Visit the [MySQL Workbench Download Page](https://dev.mysql.com/downloads/workbench/).
60 | 2. Download the `mysql-workbench-community-8.0.33-macos-x86_64.dmg` file from "Other Downloads" section. The Download button is to the right. Make sure to download this file since if you download the MySQL Installer it will also install MySQL on your system (which we assume you already have installed from previous chapters).
61 | 3. Follow the installation instructions from the installer.
62 | 4. Once installed, double-click on the file or use File -> Open Model ... from within MySQL Workbench.
63 | 5. The file (`workbench.mwb`) is a MySQL Workbench Document that allows you to edit entity relationship diagrams and generate SQL CREATE TABLE statements based on these diagrams. The current file contains all entities as described in their final state in Chapter 7.
64 | 6. Once you see the entities you can freely double-click and evaluate them as well as make any necessary changes.
65 |
66 | ## Modifications for different RDBMS
67 |
68 | You will need to make some modifications to the attributes for different RDBMS. Considering that this chapter is not the end of the E-R diagram that we are still developing, we won't provide different versions of the E-R diagram tailored to different RDBMS. Instead, we will only describe the necessary modifications for SQL Server, SQLite and Oracle below for your reference.
69 |
70 | ### MySQL and MariaDB
71 |
72 | The entities and attributes depicted in the E-R diagram don't require any modifications for MySQL and MariaDB.
73 |
74 | ### PostgreSQL
75 |
76 | `user` is a reserved keyword in PostgreSQL. You can't use it as a table name. You can use `system_user` instead of `user`.
77 |
78 | ### SQL Server
79 |
80 | The following changes need to be made for SQL Server:
81 |
82 | **`TIMESTAMP` to `DATETIMEOFFSET`**: SQL Server uses DATETIMEOFFSET instead of TIMESTAMP. DATETIMEOFFSET stores the date, time, and offset from UTC. DATETIMEOFFSET is a SQL Server-specific data type that is not part of the ANSI SQL standard. DATETIMEOFFSET is used when you need to store the time zone offset of a particular date and time value.
83 |
84 | **`VARCHAR` to `NVARCHAR`**: It is recommended to use `NVARCHAR` instead of `VARCHAR` for SQL Server. `VARCHAR` is used for non-Unicode character data. It stores ASCII characters and can represent a limited set of characters (specifically those in the code page of your server's collation setting). `NVARCHAR` is used for Unicode character data -- It can store characters from multiple languages and alphabets and uses two bytes per character.If your application needs to support multiple languages or special characters that are not represented in the default character set, then you should use `NVARCHAR`.
85 |
86 | **`TEXT` to `NVARCHAR(MAX)`**: `TEXT` is a deprecated data type in SQL Server. It is recommended to use `NVARCHAR(MAX)` instead of `TEXT`. `NVARCHAR(MAX)` is used for Unicode character data of variable length. `NVARCHAR(MAX)` can store up to 2GB of data. `NVARCHAR(MAX)` is a SQL Server-specific data type that is not part of the ANSI SQL standard. `NVARCHAR(MAX)` is used when you need to store large amounts of Unicode character data (more than 4000 characters).
87 |
88 | **`AUTO_INCREMENT` to `IDENTITY`**: `IDENTITY` the name used for `AUTO_INCREMENT` in SQL Server. The effect is the same.
89 |
90 | **`CURRENT_TIMESTAMP` to `GETDATE()`**: The function name is different but the use is exactly the same.
91 |
92 | **`VISIBLE` is not necessary**: It is the default for SQL server so it is ommitted from the create table statement.
93 |
94 | ### SQLite
95 |
96 | The following changes need to be made for SQLite:
97 |
98 | **`TIMESTAMP` to `TEXT`**: SQLite doesn't support the `TIMESTAMP` data type. It is recommended to use `TEXT` instead of `TIMESTAMP` for SQLite.
99 |
100 | **`CHAR` and `VARCHAR` to `TEXT`**: `CHAR` and `VARCHAR` are the same as `TEXT` in SQLite, and all of which have no length limit in SQLite.
101 |
102 | **`DECIMAL` to `INT` or `TEXT`**: SQLite doesn't support `DECIMAL` data type. `REAL` is typically used instead of `DECIMAL` in SQLite when precision doesn't matter. When precision matters, `INT` or `TEXT` are typically used in practice for decimal numbers.
103 |
104 | **Character encodings not supported**: SQLite uses UTF-8 by default.
105 |
106 | **`AUTO_INCREMENT` to `INTEGER PRIMARY KEY`**: As long as a column is a primary key and integer the auto-incrementing effect is automatic.
107 |
108 | **`VISIBLE` is not necessary**: It is the default for SQLite so it is ommitted from the create table statement.
109 |
110 | **`CURRENT_TIMESTAMP` to `datetime('now')`**: Use is exactly the same just the syntax is different.
--------------------------------------------------------------------------------
/chapter_07/dbdiagram.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************************
2 | RDBMS: MySQL
3 | Create Date: 08/03/2024
4 | Author: Qiang Hao
5 | Description: Create all the tables for the scificollective_chapter7 database
6 | corresponding to what's covered in Chapter 7
7 | *************************************************************************************/
8 |
9 | -- drop database scificollective_chapter7 if it exists
10 | DROP DATABASE IF EXISTS scificollective_chapter7;
11 |
12 | -- create database scificollective_chapter7
13 | -- character set utf8
14 | CREATE DATABASE IF NOT EXISTS scificollective_chapter7
15 | CHARACTER SET utf8
16 | COLLATE utf8_general_ci;
17 |
18 | USE scificollective_chapter7;
19 |
20 |
21 | -- Table state
22 | CREATE TABLE IF NOT EXISTS state (
23 | state_id CHAR(2) PRIMARY KEY,
24 | state VARCHAR(20) NOT NULL
25 | );
26 |
27 | -- Table address
28 | CREATE TABLE IF NOT EXISTS address (
29 | address_id INT PRIMARY KEY AUTO_INCREMENT,
30 | street_address VARCHAR(255) NOT NULL,
31 | address_line_optional VARCHAR(100),
32 | city VARCHAR(100) NOT NULL,
33 | postal_code CHAR(5) NOT NULL,
34 | state_id CHAR(2) NOT NULL,
35 | CONSTRAINT fk_address_state
36 | FOREIGN KEY (state_id)
37 | REFERENCES state (state_id)
38 | ON DELETE CASCADE
39 | ON UPDATE CASCADE
40 | );
41 |
42 | -- Table user
43 | DROP TABLE IF EXISTS user;
44 | CREATE TABLE IF NOT EXISTS user (
45 | email VARCHAR(320),
46 | username VARCHAR(30) NOT NULL,
47 | password VARCHAR(20) NOT NULL,
48 | first_name VARCHAR(50) NOT NULL,
49 | last_name VARCHAR(50) NOT NULL,
50 | phone_number VARCHAR(15),
51 | last_login_time TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
52 | address_id INT NULL,
53 | PRIMARY KEY (email),
54 | UNIQUE INDEX unq_username (username ASC) VISIBLE,
55 | UNIQUE INDEX unq_phone_number (phone_number ASC) VISIBLE,
56 | CONSTRAINT fk_user_address
57 | FOREIGN KEY (address_id)
58 | REFERENCES address (address_id)
59 | ON DELETE CASCADE
60 | ON UPDATE CASCADE
61 | );
62 |
63 |
64 | -- Table product
65 | DROP TABLE IF EXISTS product;
66 | CREATE TABLE product (
67 | code CHAR(12),
68 | name VARCHAR(100) NOT NULL,
69 | description TEXT NOT NULL,
70 | manufacturer VARCHAR(100) NOT NULL,
71 | photo VARCHAR(1000) NOT NULL,
72 | price DECIMAL(7,2) NOT NULL,
73 | cost DECIMAL(7,2) NOT NULL,
74 | inventory_quantity INT NOT NULL,
75 | PRIMARY KEY (code),
76 | UNIQUE INDEX unq_name_manufacturer (name ASC, manufacturer ASC) VISIBLE,
77 | FULLTEXT INDEX ft_idx_name (name) VISIBLE
78 | );
79 |
80 | -- Table review
81 | DROP TABLE IF EXISTS review;
82 | CREATE TABLE IF NOT EXISTS review (
83 | review_id INT PRIMARY KEY,
84 | review_text TEXT NOT NULL,
85 | review_time TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
86 | email VARCHAR(320) NOT NULL,
87 | code CHAR(12) NOT NULL,
88 | CONSTRAINT fk_review_user
89 | FOREIGN KEY (email)
90 | REFERENCES user (email)
91 | ON DELETE CASCADE
92 | ON UPDATE CASCADE,
93 | CONSTRAINT fk_review_product
94 | FOREIGN KEY (code)
95 | REFERENCES product (code)
96 | ON DELETE CASCADE
97 | ON UPDATE CASCADE,
98 | INDEX idx_code (code)
99 | );
100 |
101 | -- Table payment_method
102 | DROP TABLE IF EXISTS payment_method;
103 | CREATE TABLE payment_method (
104 | payment_id INT PRIMARY KEY,
105 | name VARCHAR(30) NOT NULL,
106 | card_number CHAR(45) NOT NULL,
107 | expiry_date CHAR(45) NOT NULL,
108 | email VARCHAR(320) NOT NULL,
109 | address_id INT NOT NULL,
110 | CONSTRAINT fk_payment_method_user
111 | FOREIGN KEY (email)
112 | REFERENCES user (email),
113 | CONSTRAINT fk_payment_method_address
114 | FOREIGN KEY (address_id)
115 | REFERENCES address (address_id)
116 | ON DELETE CASCADE
117 | ON UPDATE CASCADE
118 | );
119 |
120 |
121 | -- Table purchase
122 | DROP TABLE IF EXISTS purchase;
123 | CREATE TABLE purchase (
124 | purchase_id INT PRIMARY KEY,
125 | total_price DECIMAL(13,2) NOT NULL DEFAULT 0,
126 | purchase_time TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
127 | payment_id INT NOT NULL,
128 | email VARCHAR(320) NOT NULL,
129 | CONSTRAINT fk_purchase_payment_method
130 | FOREIGN KEY (payment_id)
131 | REFERENCES payment_method (payment_id)
132 | ON DELETE CASCADE
133 | ON UPDATE CASCADE,
134 | CONSTRAINT fk_purchase_user
135 | FOREIGN KEY (email)
136 | REFERENCES user (email)
137 | ON DELETE CASCADE
138 | ON UPDATE CASCADE,
139 | INDEX idx_purchase_email (email)
140 | );
141 |
142 | -- Table purchase_product
143 | DROP TABLE IF EXISTS purchase_product;
144 | CREATE TABLE purchase_product (
145 | purchase_id INT NOT NULL,
146 | code CHAR(12) NOT NULL,
147 | product_price DECIMAL(7,2) NOT NULL,
148 | product_quantity INT NOT NULL DEFAULT 1,
149 | product_name VARCHAR(100) NOT NULL,
150 | PRIMARY KEY (code, purchase_id),
151 | CONSTRAINT fk_product_has_purchase_product1
152 | FOREIGN KEY (code)
153 | REFERENCES product (code)
154 | ON DELETE CASCADE
155 | ON UPDATE CASCADE,
156 | CONSTRAINT fk_product_has_purchase_purchase1
157 | FOREIGN KEY (purchase_id)
158 | REFERENCES purchase (purchase_id)
159 | ON DELETE CASCADE
160 | ON UPDATE CASCADE
161 | );
162 |
163 |
--------------------------------------------------------------------------------
/chapter_07/images/dbdiagram.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/chapter_07/images/dbdiagram.png
--------------------------------------------------------------------------------
/chapter_07/images/er-diagram.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/chapter_07/images/er-diagram.png
--------------------------------------------------------------------------------
/chapter_07/workbench.mwb:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/chapter_07/workbench.mwb
--------------------------------------------------------------------------------
/chapter_08/README.md:
--------------------------------------------------------------------------------
1 | # Database Design in the Age of Generative AI
2 |
3 | Practioners use tools such as dbdiagram.io, LucidChart, or MySQL Workbench to create and edit E-R diagrams.
4 |
5 | The corresponding chapter in this book developed the entities and their attributes for the database of The Sci-fi Collective. You can find the developed entities and their relationships, as well as how to load (or check) them using corresponding tools.
6 |
7 | - [View or edit the E-R diagram via dbdiagram](#view-or-edit-the-e-r-diagram-via-dbdiagram)
8 | - [View or edit the E-R diagram via MySQL Workbench](#view-or-edit-the-e-r-diagram-via-mysql-workbench)
9 |
10 | The final state of entities as described in Chapter 8 is as follows:
11 |
12 |
13 |
14 |
15 |
16 | The questions/requests used to generate ChatGPT responses can be found in chatgpt_requests.md.
17 |
18 | ## View or edit the E-R diagram via dbdiagram
19 |
20 | [dbdiagram.io](https://dbdiagram.io) is a free online tool for drawing E-R Diagrams by writing code. You can also generate `SQL CREATE TABLE` statements given a diagram using dbdiagram.io. dbdiagram.io supports three RDBMS: MySQL, PostgreSQL, and SQL Server.
21 |
22 | What we achieved in this chapter is not the end of the E-R diagram that we aim to develop. As a result, we only provide a MySQL script (`dbdiagram.sql`) that correspond to the final state of entities and relationships of this chapter.
23 |
24 |
25 |
26 | When you import the provided script into dbdiagram.io, you will be able to view or edit the corresponding E-R diagram. You can also generate a new SQL script for PostgreSQL or SQL server from the diagram. To import the script, please follow the steps below:
27 |
28 | 1. Visit the [dbdiagram.io](https://dbdiagram.io/home) website, and log into your account.
29 | 2. Click on the "Import Database" button in the top navigation bar.
30 | 3. You can either copy and paste the content of the `dbdiagram.sql` file into the text area or click on the "Upload .sql" button to upload the `dbdiagram.sql` file.
31 | 4. When you are done, click on the "Submit" button.
32 |
33 | You can refer to [the manual of diagram.io](https://dbdiagram.io/docs/) if you have any questions about diagram.io.
34 |
35 | ## View or edit the E-R diagram via MySQL Workbench
36 |
37 | MySQL Workbench is an administration tool for MySQL as much as an E-R diagramming software. Different from dbdiagram.io, MySQL Workbench is a desktop application that you need to install on your computer. Additionally, MySQL only supports MySQL as the RDBMS. However, you can use use MySQL Workbench to generate a MySQL script first, and then convert it to scripts for other RSBMS using SQL converter tools such as [SQLines](https://sqlines.com/online).
38 |
39 | There are extensive tutorials for how to use MySQL Workbench for Database Design, you can use this part of the manual as a reference: [Database Design and Modeling](https://dev.mysql.com/doc/workbench/en/wb-data-modeling.html). MySQL Workbench is available for Windows, Linux, and Mac.
40 |
41 | ### Windows
42 |
43 | 1. Visit the [MySQL Workbench Download Page](https://dev.mysql.com/downloads/workbench/).
44 | 2. Download the `mysql-workbench-community-8.0.33-winx64.msi` file from "Other Downloads" section. The Download button is to the right. Make sure to download this file since if you download the MySQL Installer it will also install MySQL on your system (which we assume you already have installed from previous chapters and do not need to on this one).
45 | 3. Follow the installation instructions from the installer.
46 | 4. Once installed, double-click on the file or use File -> Open Model ... from within MySQL Workbench.
47 | 5. The file (`workbench.mwb`) is a MySQL Workbench Document that allows you to edit entity relationship diagrams and generate SQL CREATE TABLE statements based on these diagrams. The current file contains all entities as described in their final state in Chapter 7.
48 | 6. Once you see the entities you can freely double-click and evaluate them as well as make any necessary changes.
49 |
50 | ### Linux
51 |
52 | 1. Visit the [MySQL Workbench Download Page](https://dev.mysql.com/downloads/workbench/).
53 | 2. Download the `mysql-workbench-community-8.0.33-1.el8.x86_64.rpm` file from "Other Downloads" section. The Download button is to the right. Make sure to download this file since if you download the MySQL Installer it will also install MySQL on your system (which we assume you already have installed from previous chapters and do not need to on this one).
54 | 3. Follow the installation instructions from the installer.
55 | 4. Once installed, double-click on the file or use File -> Open Model ... from within MySQL Workbench.
56 | 5. The file (`workbench.mwb`) is a MySQL Workbench Document that allows you to edit entity relationship diagrams and generate SQL CREATE TABLE statements based on these diagrams. The current file contains all entities as described in their final state in Chapter 7.
57 | 6. Once you see the entities you can freely double-click and evaluate them as well as make any necessary changes.
58 |
59 | ### Mac
60 |
61 | 1. Visit the [MySQL Workbench Download Page](https://dev.mysql.com/downloads/workbench/).
62 | 2. Download the `mysql-workbench-community-8.0.33-macos-x86_64.dmg` file from "Other Downloads" section. The Download button is to the right. Make sure to download this file since if you download the MySQL Installer it will also install MySQL on your system (which we assume you already have installed from previous chapters).
63 | 3. Follow the installation instructions from the installer.
64 | 4. Once installed, double-click on the file or use File -> Open Model ... from within MySQL Workbench.
65 | 5. The file (`workbench.mwb`) is a MySQL Workbench Document that allows you to edit entity relationship diagrams and generate SQL CREATE TABLE statements based on these diagrams. The current file contains all entities as described in their final state in Chapter 7.
66 | 6. Once you see the entities you can freely double-click and evaluate them as well as make any necessary changes.
67 |
68 | ## Modifications to attributes for different RDBMS
69 |
70 | You will need to make some modifications to the attributes for different RDBMS. Considering that this chapter is not the end of the E-R diagram that we are still developing, we won't provide different versions of the E-R diagram tailored to different RDBMS. Instead, we will only describe the necessary modifications for SQL Server, SQLite and Oracle below for your reference.
71 |
72 | ### MySQL, MariaDB, and PostgreSQL
73 |
74 | The entities and attributes depicted in the E-R diagram don't require any modifications for MySQL and MariaDB.
75 |
76 | ### PostgreSQL
77 |
78 | The following changes need to be made for PostgreSQL:
79 |
80 | **Replace `INT AUTO_INCREMENT` with `SERIAL`**: PostgreSQL uses `SERIAL` for auto-incrementing integer columns.
81 |
82 | **Change `YEAR` to `SMALLINT`**: PostgreSQL doesn't have a specific `YEAR` type. `SMALLINT` is typically used for year values.
83 |
84 | **Consider using `TEXT` instead of `VARCHAR`**: While PostgreSQL supports `VARCHAR`, `TEXT` is often preferred as it has no length limit.
85 |
86 | **Replace `NUMERIC` with `DECIMAL`**: PostgreSQL supports both `NUMERIC` and `DECIMAL` as synonyms, but `DECIMAL` is more commonly used.
87 |
88 | **Adjust `CHECK` constraints**: The syntax is slightly different in PostgreSQL, but the concept remains the same.
89 |
90 | **Modify foreign key constraint syntax**: While the concept is the same, the syntax for defining foreign key constraints might need slight adjustments for PostgreSQL.
91 |
92 | ### SQL Server
93 |
94 | The following changes need to be made for SQL Server:
95 |
96 | **Change `INT AUTO_INCREMENT` to `INT IDENTITY(1,1)`**: SQL Server uses `IDENTITY(1,1)` for auto-incrementing columns.
97 |
98 | **Change `VARCHAR` to `NVARCHAR`**: While `VARCHAR` exists in SQL Server, `NVARCHAR` is generally preferred for better Unicode support.
99 |
100 | **Change `CHAR` to `NCHAR`**: For fixed-length character fields, use `NCHAR` in SQL Server for Unicode support.
101 |
102 | **Change `NUMERIC` to `DECIMAL`**: While SQL Server supports both `NUMERIC` and `DECIMAL`, `DECIMAL` is more commonly used.
103 |
104 | **Change `YEAR` to `SMALLINT`**: SQL Server doesn't have a specific `YEAR` type. `SMALLINT` is typically used for year values.
105 |
106 | **Adjust `CHECK` constraints**: The syntax is slightly different in SQL Server, but the concept remains the same.
107 |
108 | **Modify foreign key constraint syntax**: While the concept is the same, the syntax for defining foreign key constraints is slightly different in SQL Server.
109 |
110 | ### SQLite
111 |
112 | The following changes need to be made for SQLite:
113 |
114 | **Character encodings not supported**: SQLite uses UTF-8 by default.
115 |
116 | **Remove `AUTO_INCREMENT`**: SQLite doesn't support `AUTO_INCREMENT`. Instead, you can use `INTEGER PRIMARY KEY` which will auto-increment automatically.
117 |
118 | **Change `INT` to `INTEGER`**: While SQLite will usually accept `INT`, it's best practice to use `INTEGER`.
119 |
120 | **Change `CHAR` to `TEXT`**: SQLite doesn't have a `CHAR` type. Use `TEXT` instead.
121 |
122 | **Change `VARCHAR` to `TEXT`**: SQLite doesn't have a `VARCHAR` type. Use `TEXT` instead.
123 |
124 | **Change `NUMERIC` to `REAL`**: For floating-point numbers, use `REAL` in SQLite.
125 |
126 | **Remove `YEAR` type**: SQLite doesn't have a specific `YEAR` type. Use `INTEGER` instead.
127 |
128 | **Remove size specifications**: SQLite doesn't use size specifications for text fields (e.g., `VARCHAR(100)` becomes just `TEXT`).
129 |
130 | **Adjust `CHECK` constraints**: The syntax is slightly different in SQLite. You'll need to wrap the condition in parentheses.
131 |
132 | **Adjust foreign key constraints**: SQLite supports foreign key constraints, but the syntax is slightly different and you need to enable foreign key support explicitly.
--------------------------------------------------------------------------------
/chapter_08/chatgpt_request.md:
--------------------------------------------------------------------------------
1 | The questions/requests used to generate ChatGPT responses can be found below.
2 |
3 | 1. Entity Identification
4 |
5 | ```
6 | I am designing a database. Help me identify all the entities based on the given requirements.
7 |
8 | Requirements: """
9 | The database needs to maintain records of all spaceship brands and models, manufactured spaceships, dealers, customers, and relationships between dealers and customers.
10 | A spaceship brand is associated with multiple models, and a model is associated with multiple spacecrafts.
11 | A dealer is distributed one or more spaceships, and serves one or more customers.
12 | A customer is served by one or more dealer, and is associated with one or more spaceships that he or she has bought from dealers.
13 | A spaceship is associated with one model, can be associated with no more than one owners, and no more than one dealers.
14 | """
15 | ```
16 |
17 | 2. Attribute Identification
18 |
19 | ```
20 | I am designing a database for a manufacturer of spaceships. I have identified five entities, including brand, model, spaceship, dealer, and customer. Help me identify attributes and the primary key per entity based on the given requirements. Generate output using the desired format.
21 |
22 | Desired format:
23 | Entity name: spaceship
24 | Attributes:
25 | Serial number - CHAR(17)
26 | Recommended price – NUMERIC(8, 2)
27 | Primary key: Serial number
28 |
29 | Requirements: """
30 | A brand has a name. The number of brands is limited and smaller than 5.
31 | A model has a 4-digit number and name. The number is unique per model.
32 | A spaceship has a 17-digit serial number (like a VIN number for a car), a recommended price, and a year number. The serial number is unique per spaceship. The unit for the recommended price is USD. The year number represents the year in which the spaceship is manufactured.
33 | A dealer has a name, address, phone number, email address, and dealer website URL. The dealer may be anywhere on Earth.
34 | A customer has a name, address, phone number, and email address. Multiple customers may share the same address. The customer may live anywhere on Earth.
35 | """
36 | ```
37 |
38 | Add requirements to formatting:
39 |
40 | ```
41 | Regenerate your answer using a new format but the same requirements. Make sure that names of entities and attributes are all snake cased.
42 |
43 | New format:
44 | Entity name of Spaceship: spaceship
45 | Attributes:
46 | Serial number: serial_number - CHAR(17)
47 | Recommended price: recommended_price – NUMERIC(8, 2)
48 | Primary key: serial_number
49 | ```
50 |
51 | 3. Getting the SQL code for entities and attributes
52 |
53 | ```
54 | I am designing a database. Help me generate MySQL code based on the following description of entities and attributes. Keep the entities independent one from another.
55 |
56 | Description: """
57 | Entity name of Brand: brand
58 | Attributes:
59 | Name: name - VARCHAR(100)
60 | Primary key: name
61 |
62 | Entity name of Model: model
63 | Attributes:
64 | Model number: model_number - CHAR(4)
65 | Model name: model_name - VARCHAR(100)
66 | Primary key: model_number
67 |
68 | Entity name of Spaceship: spaceship
69 | Attributes:
70 | Serial number: serial_number - CHAR(17)
71 | Recommended price: recommended_price – NUMERIC(8, 2)
72 | Year: year - year
73 | Primary key: serial_number
74 |
75 | Entity name of Dealer: dealer
76 | Attributes:
77 | Dealer ID: dealer_id – INT
78 | Name: name - VARCHAR(100)
79 | Email address: email_address - VARCHAR(100)
80 | Website URL: website_url – VARCHAR(255)
81 | Phone number:
82 | country_code - CHAR(5)
83 | dealer_phone_number - CHAR(15)
84 | Primary key: dealer_id
85 | Note 1: email_address requires a unique constraint; (country_code, phone_number) requires a unique constraint
86 |
87 | Entity name of Customer: customer
88 | Attributes:
89 | Customer ID: customer_id – INT
90 | Name: name - VARCHAR(100)
91 | Email address: email_address - VARCHAR(100)
92 | Phone number:
93 | country_code - CHAR(5)
94 | customer_phone_number - CHAR(15)
95 | Primary key: customer_id
96 | Note 1: email_address requires a unique constraint; (country_code, phone_number) requires a unique constraint
97 |
98 | Entity name of Address: address
99 | Attributes:
100 | Address ID: address_id - INT
101 | Street address: street_address - VARCHAR(255)
102 | Suburb: suburb - VARCHAR(100)
103 | City: city - VARCHAR(100)
104 | State/Province: state_province - VARCHAR(100)
105 | Postal code: postal_code - VARCHAR(20)
106 | Country: country - CHAR(2)
107 | Primary key: address_id
108 | Note 1: suburb and postal_code are optional
109 | """
110 | ```
111 |
112 | 4. Relationship Identification
113 |
114 | ```
115 | I am designing a database for a manufacturer of spaceships. I have identified six entities, including brand, model, spaceship, dealer, customer and address. Help me identify the relationships between each pair of entities based on the given requirements. Generate output using the desired format.
116 |
117 | Desired format:
118 | brand | model
119 | Relationship: one to many
120 | Note: the side pointing to model is many
121 |
122 | Requirements: """
123 | The database needs to maintain records of all spaceship brands and models, manufactured spaceships, dealers, customers, and relationships between dealers and customers.
124 | A spaceship brand is associated with multiple models, and a model is associated with multiple spacecrafts.
125 | A dealer is distributed one or more spaceships, and serves one or more customers.
126 | A customer is served by one or more dealer, and is associated with one or more spaceships that he or she has bought from dealers.
127 | A spaceship is associated with one model, can be associated with no more than one owner, and no more than one dealer.
128 | A customer is associated with one address. Multiple customers may share the same address. A dealer is associated with one address.
129 | """
130 | ```
131 |
132 | 5. Min cardinality and foreign key identification
133 |
134 | ```
135 | I am designing a database for a manufacturer of spaceships. I have identified some of the characteristics of six entities, including brand, model, spaceship, dealer, customer and address. Help me identify the min cardinality and where the foreign key should be placed between each pair of entities based on the given requirements and the known relationship characteristics. Generate output using the desired format.
136 |
137 | Desired format:
138 | brand | model
139 | Relationship: one to many
140 | Note 1: the side pointing to model is many
141 | Note 2: the foreign is in model
142 | Note 3: the min cardinality close to model is relaxed from 1 to 0
143 |
144 | Requirements: """
145 | The database needs to maintain records of all spaceship brands and models, manufactured spaceships, dealers, customers, and relationships between dealers and customers.
146 | A spaceship brand is associated with multiple models, and a model is associated with multiple spacecrafts.
147 | A dealer is distributed one or more spaceships, and serves one or more customers.
148 | A customer is served by one or more dealer, and is associated with one or more spaceships that he or she has bought from dealers.
149 | A spaceship is associated with one model, can be associated with no more than one owner, and no more than one dealer.
150 | A customer is associated with one address. Multiple customers may share the same address. A dealer is associated with one address.
151 | """
152 |
153 | Characteristics: """
154 | brand | model
155 | Relationship: one to many
156 | Note: the side pointing to model is many
157 |
158 | model | spaceship
159 | Relationship: one to many
160 | Note: the side pointing to spaceship is many
161 |
162 | spaceship | dealer
163 | Relationship: many to one
164 | Note: the side pointing to dealer is one
165 |
166 | spaceship | customer
167 | Relationship: many to one
168 | Note: the side pointing to customer is one
169 |
170 | customer | dealer
171 | Relationship: many to many
172 | Note: both sides are many
173 |
174 | dealer | address
175 | Relationship: one to one
176 | Note: each dealer is associated with exactly one address
177 |
178 | customer | address
179 | Relationship: many to one
180 | Note: the side pointing to address is one
181 | """
182 | ```
183 |
184 | 6. Getting the SQL code for the draft database design:
185 |
186 | ```
187 | I am designing a database. Help me generate MySQL code based on the following description of entities and relationships.
188 |
189 | Description: """
190 | # description of entities starts here
191 | Entity name of Brand: brand
192 | Attributes:
193 | Name: name - VARCHAR(100)
194 | Primary key: name
195 |
196 | Entity name of Model: model
197 | Attributes:
198 | Model number: model_number - CHAR(4)
199 | Model name: model_name - VARCHAR(100)
200 | Primary key: model_number
201 |
202 | Entity name of Spaceship: spaceship
203 | Attributes:
204 | Serial number: serial_number - CHAR(17)
205 | Recommended price: recommended_price – NUMERIC(8, 2)
206 | Year: year - year
207 | Primary key: serial_number
208 |
209 | Entity name of Dealer: dealer
210 | Attributes:
211 | Dealer ID: dealer_id – INT
212 | Name: name - VARCHAR(100)
213 | Email address: email_address - VARCHAR(100)
214 | Website URL: website_url – VARCHAR(255)
215 | Phone number:
216 | country_code - CHAR(5)
217 | dealer_phone_number - CHAR(15)
218 | Primary key: dealer_id
219 | Note 1: email_address requires a unique constraint; (country_code, phone_number) requires a unique constraint
220 |
221 | Entity name of Customer: customer
222 | Attributes:
223 | Customer ID: customer_id – INT
224 | Name: name - VARCHAR(100)
225 | Email address: email_address - VARCHAR(100)
226 | Phone number:
227 | country_code - CHAR(5)
228 | customer_phone_number - CHAR(15)
229 | Primary key: customer_id
230 | Note 1: email_address requires a unique constraint; (country_code, phone_number) requires a unique constraint
231 |
232 | Entity name of Address: address
233 | Attributes:
234 | Address ID: address_id - INT
235 | Street address: street_address - VARCHAR(255)
236 | Suburb: suburb - VARCHAR(100)
237 | City: city - VARCHAR(100)
238 | State/Province: state_province - VARCHAR(100)
239 | Postal code: postal_code - VARCHAR(20)
240 | Country: country - CHAR(2)
241 | Primary key: address_id
242 | Note 1: suburb and postal_code are optional
243 |
244 | # description of relationships starts here
245 | brand | model
246 | Relationship: one to many
247 | Note 1: The side pointing to model is many
248 | Note 2: The foreign key is in model
249 | Note 3: The minimum cardinality close to model is relaxed from 1 to 0
250 |
251 | model | spaceship
252 | Relationship: one to many
253 | Note 1: The side pointing to spaceship is many
254 | Note 2: The foreign key is in spaceship
255 | Note 3: The minimum cardinality close to spaceship is relaxed from 1 to 0
256 |
257 | customer | dealer
258 | Relationship: many to many
259 | Note 1: A junction table customer_dealer is needed
260 | Note 2: The foreign keys are in customer_dealer
261 | Note 3: The minimum cardinalities close to customer_dealer are relaxed from 1 to 0
262 |
263 | spaceship | dealer
264 | Relationship: many to one
265 | Note 1: The side pointing to dealer is one
266 | Note 2: The foreign key is in spaceship
267 | Note 3: The minimum cardinality close to dealer is relaxed from 1 to 0
268 |
269 | spaceship | customer
270 | Relationship: many to one
271 | Note 1: The side pointing to customer is one
272 | Note 2: The foreign key is in spaceship
273 | Note 3: The minimum cardinality close to spaceship is relaxed from 1 to 0
274 |
275 | dealer | address
276 | Relationship: one to one
277 | Note 1: Each dealer is associated with exactly one address
278 | Note 2: The foreign key is in dealer
279 | Note 3: The minimum cardinality close to dealer is 1
280 |
281 | customer | address
282 | Relationship: many to one
283 | Note 1: The side pointing to address is one
284 | Note 2: The foreign key is in customer
285 | Note 3: The minimum cardinality close to customer is relaxed from 1 to 0
286 | """
287 | ```
288 |
289 |
290 | 7. Constraints Identification:
291 |
292 | ```
293 | I am designing a database. Help me identify the attributes that need constraints, and the type of constraints using the desired format, based on the given requirements, entity and attributes, and relationships among entities.
294 |
295 | Desired formats:
296 | Entity name: brand
297 | Attribute in focus:
298 | * model_number: primary key
299 | * model_name: NOT NULL
300 | * brand_name: foreign key
301 |
302 | Requirements: """
303 | A brand has a name. The number of brands is limited and smaller than 5.
304 | A model has a 4-digit number and name. The number is unique per model.
305 | A spaceship has a 17-digit serial number (like a VIN number for a car), a recommended price, and a year number. The serial number is unique per spaceship. The unit for the recommended price is USD. The year number represents the year in which the spaceship is manufactured.
306 | A dealer has a name, address, phone number, email address, and dealer website URL. The dealer may be anywhere on Earth.
307 | A customer has a name, address, phone number, and email address. Multiple customers may share the same address. The customer may live anywhere on Earth.
308 | """
309 |
310 | Entity and attributes: """
311 | Entity name of Brand: brand
312 | Attributes:
313 | Name: name - VARCHAR(100)
314 | Primary key: name
315 |
316 | Entity name of Model: model
317 | Attributes:
318 | Model number: model_number - CHAR(4)
319 | Model name: model_name - VARCHAR(100)
320 | Primary key: model_number
321 |
322 | Entity name of Spaceship: spaceship
323 | Attributes:
324 | Serial number: serial_number - CHAR(17)
325 | Recommended price: recommended_price – NUMERIC(8, 2)
326 | Year: year - year
327 | Primary key: serial_number
328 |
329 | Entity name of Dealer: dealer
330 | Attributes:
331 | Dealer ID: dealer_id – INT
332 | Name: name - VARCHAR(100)
333 | Email address: email_address - VARCHAR(100)
334 | Website URL: website_url – VARCHAR(255)
335 | Phone number:
336 | country_code - CHAR(5)
337 | dealer_phone_number - CHAR(15)
338 | Primary key: dealer_id
339 | Note 1: email_address requires a unique constraint; (country_code, phone_number) requires a unique constraint
340 |
341 | Entity name of Customer: customer
342 | Attributes:
343 | Customer ID: customer_id – INT
344 | Name: name - VARCHAR(100)
345 | Email address: email_address - VARCHAR(100)
346 | Phone number:
347 | country_code - CHAR(5)
348 | customer_phone_number - CHAR(15)
349 | Primary key: customer_id
350 | Note 1: email_address requires a unique constraint; (country_code, phone_number) requires a unique constraint
351 |
352 | Entity name of Address: address
353 | Attributes:
354 | Address ID: address_id - INT
355 | Street address: street_address - VARCHAR(255)
356 | Suburb: suburb - VARCHAR(100)
357 | City: city - VARCHAR(100)
358 | State/Province: state_province - VARCHAR(100)
359 | Postal code: postal_code - VARCHAR(20)
360 | Country: country - CHAR(2)
361 | Primary key: address_id
362 | Note 1: suburb and postal_code are optional
363 | """
364 |
365 | Relationships: """
366 | brand | model
367 | Relationship: one to many
368 | Note 1: The side pointing to model is many
369 | Note 2: The foreign key is in model
370 | Note 3: The minimum cardinality close to model is relaxed from 1 to 0
371 |
372 | model | spaceship
373 | Relationship: one to many
374 | Note 1: The side pointing to spaceship is many
375 | Note 2: The foreign key is in spaceship
376 | Note 3: The minimum cardinality close to spaceship is relaxed from 1 to 0
377 |
378 | customer | dealer
379 | Relationship: many to many
380 | Note 1: A junction table customer_dealer is needed
381 | Note 2: The foreign keys are in customer_dealer
382 | Note 3: The minimum cardinalities close to customer_dealer are relaxed from 1 to 0
383 |
384 | spaceship | dealer
385 | Relationship: many to one
386 | Note 1: The side pointing to dealer is one
387 | Note 2: The foreign key is in spaceship
388 | Note 3: The minimum cardinality close to dealer is relaxed from 1 to 0
389 |
390 | spaceship | customer
391 | Relationship: many to one
392 | Note 1: The side pointing to customer is one
393 | Note 2: The foreign key is in spaceship
394 | Note 3: The minimum cardinality close to spaceship is relaxed from 1 to 0
395 |
396 | dealer | address
397 | Relationship: one to one
398 | Note 1: Each dealer is associated with exactly one address
399 | Note 2: The foreign key is in dealer
400 | Note 3: The minimum cardinality close to dealer is 1
401 |
402 | customer | address
403 | Relationship: many to one
404 | Note 1: The side pointing to address is one
405 | Note 2: The foreign key is in customer
406 | Note 3: The minimum cardinality close to customer is relaxed from 1 to 0
407 | """
408 | ```
409 |
410 | 8. Optimization
411 |
412 | Q1:
413 |
414 | ```
415 | Applying a check constraint to country attribute in the address table is painful because there are about 200 countries in the world. what's a common and recommended approach to store such information without this constraint but still retains the data validity check?
416 | ```
417 |
418 | Q2:
419 |
420 | ```
421 | To ensure the validity of the country code of phone numbers in the customer/address tables, what's a common and recommended approach to store such information?
422 | ```
423 |
424 | 9. Generate SQL code for the final database design:
425 |
426 | ```
427 | I am designing a database. Generate MySQL code based on the given entity, attributes, and relationships, and constraints.
428 |
429 | Entity and attributes: """
430 | Entity name of Brand: brand
431 | Attributes:
432 | Name: name - VARCHAR(100)
433 |
434 | Entity name of Model: model
435 | Attributes:
436 | Model number: model_number - CHAR(4)
437 | Model name: model_name - VARCHAR(100)
438 |
439 | Entity name of Spaceship: spaceship
440 | Attributes:
441 | Serial number: serial_number - CHAR(17)
442 | Recommended price: recommended_price – NUMERIC(8, 2)
443 | Year: year - year
444 |
445 | Entity name of Brand: country
446 | Attributes:
447 | Country ID: country_id - INT
448 | Country Abbreviation: country_abbr - CHAR(2)
449 | Country code: country_code - CHAR(5)
450 | Country name: country_name - VARCHAR(100)
451 |
452 | Entity name of Dealer: dealer
453 | Attributes:
454 | Dealer ID: dealer_id – INT
455 | Name: name - VARCHAR(100)
456 | Email address: email_address - VARCHAR(100)
457 | Website URL: website_url – VARCHAR(255)
458 | Phone number: dealer_phone_number - CHAR(15)
459 |
460 | Entity name of Customer: customer
461 | Attributes:
462 | Customer ID: customer_id – INT
463 | Name: name - VARCHAR(100)
464 | Email address: email_address - VARCHAR(100)
465 | Phone number: customer_phone_number - CHAR(15)
466 |
467 | Entity name of Address: address
468 | Attributes:
469 | Address ID: address_id - INT
470 | Street address: street_address - VARCHAR(255)
471 | Suburb: suburb - VARCHAR(100)
472 | City: city - VARCHAR(100)
473 | State/Province: state_province - VARCHAR(100)
474 | Postal code: postal_code - VARCHAR(20)
475 | """
476 |
477 | Relationships: """
478 | brand | model
479 | Relationship: one to many
480 | Note 1: The side pointing to model is many
481 | Note 2: The foreign key is in model
482 | Note 3: The minimum cardinality close to model is relaxed from 1 to 0
483 |
484 | model | spaceship
485 | Relationship: one to many
486 | Note 1: The side pointing to spaceship is many
487 | Note 2: The foreign key is in spaceship
488 | Note 3: The minimum cardinality close to spaceship is relaxed from 1 to 0
489 |
490 | customer | dealer
491 | Relationship: many to many
492 | Note 1: A junction table customer_dealer is needed
493 | Note 2: The foreign keys are in customer_dealer
494 | Note 3: The minimum cardinalities close to customer_dealer are relaxed from 1 to 0
495 |
496 | spaceship | dealer
497 | Relationship: many to one
498 | Note 1: The side pointing to dealer is one
499 | Note 2: The foreign key is in spaceship
500 | Note 3: The minimum cardinality close to dealer is relaxed from 1 to 0
501 |
502 | spaceship | customer
503 | Relationship: many to one
504 | Note 1: The side pointing to customer is one
505 | Note 2: The foreign key is in spaceship
506 | Note 3: The minimum cardinality close to spaceship is relaxed from 1 to 0
507 |
508 | dealer | address
509 | Relationship: one to one
510 | Note 1: Each dealer is associated with exactly one address
511 | Note 2: The foreign key is in dealer
512 | Note 3: The minimum cardinality close to dealer is 1
513 |
514 | customer | address
515 | Relationship: many to one
516 | Note 1: The side pointing to address is one
517 | Note 2: The foreign key is in customer
518 | Note 3: The minimum cardinality close to customer is relaxed from 1 to 0
519 | """
520 |
521 | Constraints: """
522 | Entity: brand
523 | Attribute in focus:
524 | name: primary key
525 |
526 | Entity: model
527 | Attributes in focus:
528 | model_number: primary key constraint
529 | model_name: NOT NULL
530 | brand_name: foreign key constraint (references brand.name)
531 |
532 | Entity: spaceship
533 | Attributes in focus:
534 | serial_number: primary key
535 | recommended_price: CHECK (e.g., CHECK (recommended_price >= 0))
536 | year: CHECK (e.g., CHECK (year >= 1900))
537 | model_number: foreign key (references model.model_number)
538 | dealer_id: foreign key (references dealer.dealer_id)
539 | customer_id: foreign key (references customer.customer_id)
540 |
541 | Entity: dealer
542 | Attributes in focus:
543 | dealer_id: primary key
544 | name: NOT NULL
545 | email_address: UNIQUE
546 | website_url: NOT NULL
547 | (country_code, dealer_phone_number): UNIQUE
548 | address_id: foreign key (references address.address_id)
549 | country_id: foreign key (references country.country_id)
550 |
551 | Entity: customer
552 | Attributes in focus:
553 | customer_id: primary key
554 | name: NOT NULL
555 | email_address: UNIQUE
556 | (country_code, customer_phone_number): UNIQUE
557 | address_id: foreign key (references address.address_id)
558 | country_id: foreign key (references country.country_id)
559 |
560 | Entity: customer_dealer
561 | Attributes in focus:
562 | (customer_id, deaer_id): primary key
563 | customer_id: foreign key (references customer. customer_id)
564 | dealer_id: foreign key (references dealer.dealer_id)
565 |
566 | Entity: address
567 | Attributes in focus:
568 | address_id: primary key
569 | country_id: foreign key (references country.country_id)
570 | """
571 | ```
572 |
573 | 10. Generate testing data for the implemented database:
574 |
575 | ```
576 | I am designing a database. Generate sample data that can be used for testing based on the given SQL code that implements the database.
577 |
578 | SQL Code:
579 | -- Create country table for address validation
580 | CREATE TABLE country (
581 | country_id INT PRIMARY KEY AUTO_INCREMENT,
582 | country_abbr VARCHAR(2) NOT NULL,
583 | country_code CHAR(5) NOT NULL,
584 | country_name VARCHAR(100) NOT NULL
585 | );
586 |
587 | -- Create brand table
588 | CREATE TABLE brand (name VARCHAR(100) PRIMARY KEY);
589 |
590 | -- Create model table
591 | CREATE TABLE model (
592 | model_number CHAR(4) PRIMARY KEY,
593 | model_name VARCHAR(100) NOT NULL,
594 | brand_name VARCHAR(100) NOT NULL,
595 | CONSTRAINT fk_brand_model
596 | FOREIGN KEY (brand_name)
597 | REFERENCES brand(name)
598 | ON DELETE CASCADE
599 | ON UPDATE CASCADE
600 | );
601 |
602 | -- Create spaceship table
603 | CREATE TABLE spaceship (
604 | serial_number CHAR(17) PRIMARY KEY,
605 | recommended_price NUMERIC(8, 2) CHECK (recommended_price >= 0) NOT NULL,
606 | year YEAR CHECK (year >= 1900) NOT NULL,
607 | model_number CHAR(4) NOT NULL,
608 | dealer_id INT,
609 | customer_id INT,
610 | CONSTRAINT fk_model_spaceship
611 | FOREIGN KEY (model_number)
612 | REFERENCES model(model_number)
613 | ON DELETE NO ACTION
614 | ON UPDATE CASCADE,
615 | CONSTRAINT fk_dealer_spaceship
616 | FOREIGN KEY (dealer_id)
617 | REFERENCES dealer(dealer_id)
618 | ON DELETE SET NULL
619 | ON UPDATE CASCADE,
620 | CONSTRAINT fk_customer_spaceship
621 | FOREIGN KEY (customer_id)
622 | REFERENCES customer(customer_id)
623 | ON DELETE SET NULL
624 | ON UPDATE CASCADE
625 | );
626 |
627 | -- Create address table
628 | CREATE TABLE address (
629 | address_id INT PRIMARY KEY AUTO_INCREMENT,
630 | street_address VARCHAR(255) NOT NULL,
631 | suburb VARCHAR(100),
632 | city VARCHAR(100) NOT NULL,
633 | state_province VARCHAR(100) NOT NULL,
634 | postal_code VARCHAR(20),
635 | country_id INT NOT NULL,
636 | CONSTRAINT fk_address_country
637 | FOREIGN KEY (country_id)
638 | REFERENCES country(country_id)
639 | ON DELETE NO ACTION
640 | ON UPDATE CASCADE
641 | );
642 |
643 | -- Create dealer table
644 | CREATE TABLE dealer (
645 | dealer_id INT PRIMARY KEY,
646 | name VARCHAR(100) NOT NULL,
647 | email_address VARCHAR(100) UNIQUE NOT NULL,
648 | website_url VARCHAR(255) NOT NULL,
649 | dealer_phone_number CHAR(15) NOT NULL,
650 | country_id INT NOT NULL,
651 | address_id INT NOT NULL,
652 | CONSTRAINT unique_dealer_phone_number
653 | UNIQUE (country_id, dealer_phone_number),
654 | CONSTRAINT fk_dealer_country_id
655 | FOREIGN KEY (country_id)
656 | REFERENCES country(country_id)
657 | ON DELETE NO ACTION
658 | ON UPDATE CASCADE,
659 | CONSTRAINT fk_dealer_address
660 | FOREIGN KEY (address_id)
661 | REFERENCES address(address_id)
662 | ON DELETE NO ACTION
663 | ON UPDATE CASCADE
664 | );
665 |
666 | -- Create customer table
667 | CREATE TABLE customer (
668 | customer_id INT PRIMARY KEY AUTO_INCREMENT,
669 | name VARCHAR(100) NOT NULL,
670 | email_address VARCHAR(100) UNIQUE NOT NULL,
671 | customer_phone_number CHAR(15) NOT NULL,
672 | country_id INT NOT NULL,
673 | address_id INT NOT NULL,
674 | CONSTRAINT unique_customer_phone_number
675 | UNIQUE (country_id, customer_phone_number),
676 | CONSTRAINT fk_customer_country_id
677 | FOREIGN KEY (country_id)
678 | REFERENCES country(country_id)
679 | ON DELETE NO ACTION
680 | ON UPDATE CASCADE,
681 | CONSTRAINT fk_customer_address
682 | FOREIGN KEY (address_id)
683 | REFERENCES address(address_id)
684 | ON DELETE NO ACTION
685 | ON UPDATE CASCADE
686 | );
687 |
688 | -- Create customer_dealer table
689 | CREATE TABLE customer_dealer (
690 | customer_id INT NOT NULL,
691 | dealer_id INT NOT NULL,
692 | CONSTRAINT pk_customer_dealer
693 | PRIMARY KEY (customer_id, dealer_id),
694 | CONSTRAINT fk_customer_dealer_customer
695 | FOREIGN KEY (customer_id)
696 | REFERENCES customer(customer_id)
697 | ON DELETE CASCADE
698 | ON UPDATE CASCADE,
699 | CONSTRAINT fk_customer_dealer_dealer
700 | FOREIGN KEY (dealer_id)
701 | REFERENCES dealer(dealer_id)
702 | ON DELETE CASCADE
703 | ON UPDATE CASCADE
704 | );
705 | ```
--------------------------------------------------------------------------------
/chapter_08/dbdiagram.sql:
--------------------------------------------------------------------------------
1 | /*****************************************************************************
2 | RDBMS: MySQL
3 | Create Date: 08/27/2024
4 | Author: Qiang Hao
5 | Description: Create all the tables for the shipsrus_chapter8 database
6 | corresponding to what's covered in Chapter 8
7 | *************************************************************************************/
8 | -- drop database shipsrus_chapter8 if it exists
9 | DROP DATABASE IF EXISTS shipsrus_chapter8;
10 |
11 | -- create database shipsrus_chapter8
12 | -- character set utf8
13 | CREATE DATABASE IF NOT EXISTS shipsrus_chapter8 CHARACTER SET utf8 COLLATE utf8_general_ci;
14 |
15 | USE shipsrus_chapter8;
16 |
17 | -- Create country table for address validation
18 | CREATE TABLE country (
19 | country_id INT PRIMARY KEY AUTO_INCREMENT,
20 | country_abbr VARCHAR(2) NOT NULL,
21 | country_code CHAR(5) NOT NULL,
22 | country_name VARCHAR(100) NOT NULL
23 | );
24 |
25 | -- Create brand table
26 | CREATE TABLE brand (name VARCHAR(100) PRIMARY KEY);
27 |
28 | -- Create model table
29 | CREATE TABLE model (
30 | model_number CHAR(4) PRIMARY KEY,
31 | model_name VARCHAR(100) NOT NULL,
32 | brand_name VARCHAR(100) NOT NULL,
33 | CONSTRAINT fk_brand_model
34 | FOREIGN KEY (brand_name)
35 | REFERENCES brand(name)
36 | ON DELETE CASCADE
37 | ON UPDATE CASCADE
38 | );
39 |
40 | -- Create address table
41 | CREATE TABLE address (
42 | address_id INT PRIMARY KEY AUTO_INCREMENT,
43 | street_address VARCHAR(255) NOT NULL,
44 | suburb VARCHAR(100),
45 | city VARCHAR(100) NOT NULL,
46 | state_province VARCHAR(100) NOT NULL,
47 | postal_code VARCHAR(20),
48 | country_id INT NOT NULL,
49 | CONSTRAINT fk_address_country
50 | FOREIGN KEY (country_id)
51 | REFERENCES country(country_id)
52 | ON DELETE NO ACTION
53 | ON UPDATE CASCADE
54 | );
55 |
56 | -- Create dealer table
57 | CREATE TABLE dealer (
58 | dealer_id INT PRIMARY KEY,
59 | name VARCHAR(100) NOT NULL,
60 | email_address VARCHAR(100) UNIQUE NOT NULL,
61 | website_url VARCHAR(255) NOT NULL,
62 | dealer_phone_number CHAR(15) NOT NULL,
63 | country_id INT NOT NULL,
64 | address_id INT NOT NULL,
65 | CONSTRAINT unique_dealer_phone_number
66 | UNIQUE (country_id, dealer_phone_number),
67 | CONSTRAINT fk_dealer_country_id
68 | FOREIGN KEY (country_id)
69 | REFERENCES country(country_id)
70 | ON DELETE NO ACTION
71 | ON UPDATE CASCADE,
72 | CONSTRAINT fk_dealer_address
73 | FOREIGN KEY (address_id)
74 | REFERENCES address(address_id)
75 | ON DELETE NO ACTION
76 | ON UPDATE CASCADE
77 | );
78 |
79 | -- Create customer table
80 | CREATE TABLE customer (
81 | customer_id INT PRIMARY KEY AUTO_INCREMENT,
82 | name VARCHAR(100) NOT NULL,
83 | email_address VARCHAR(100) UNIQUE NOT NULL,
84 | customer_phone_number CHAR(15) NOT NULL,
85 | country_id INT NOT NULL,
86 | address_id INT NOT NULL,
87 | CONSTRAINT unique_customer_phone_number
88 | UNIQUE (country_id, customer_phone_number),
89 | CONSTRAINT fk_customer_country_id
90 | FOREIGN KEY (country_id)
91 | REFERENCES country(country_id)
92 | ON DELETE NO ACTION
93 | ON UPDATE CASCADE,
94 | CONSTRAINT fk_customer_address
95 | FOREIGN KEY (address_id)
96 | REFERENCES address(address_id)
97 | ON DELETE NO ACTION
98 | ON UPDATE CASCADE
99 | );
100 |
101 | -- Create spaceship table
102 | CREATE TABLE spaceship (
103 | serial_number CHAR(17) PRIMARY KEY,
104 | recommended_price NUMERIC(8, 2) CHECK (recommended_price >= 0) NOT NULL,
105 | year YEAR CHECK (year >= 1900) NOT NULL,
106 | model_number CHAR(4) NOT NULL,
107 | dealer_id INT,
108 | customer_id INT,
109 | CONSTRAINT fk_model_spaceship
110 | FOREIGN KEY (model_number)
111 | REFERENCES model(model_number)
112 | ON DELETE NO ACTION
113 | ON UPDATE CASCADE,
114 | CONSTRAINT fk_dealer_spaceship
115 | FOREIGN KEY (dealer_id)
116 | REFERENCES dealer(dealer_id)
117 | ON DELETE SET NULL
118 | ON UPDATE CASCADE,
119 | CONSTRAINT fk_customer_spaceship
120 | FOREIGN KEY (customer_id)
121 | REFERENCES customer(customer_id)
122 | ON DELETE SET NULL
123 | ON UPDATE CASCADE
124 | );
125 |
126 | -- Create customer_dealer table
127 | CREATE TABLE customer_dealer (
128 | customer_id INT NOT NULL,
129 | dealer_id INT NOT NULL,
130 | CONSTRAINT pk_customer_dealer
131 | PRIMARY KEY (customer_id, dealer_id),
132 | CONSTRAINT fk_customer_dealer_customer
133 | FOREIGN KEY (customer_id)
134 | REFERENCES customer(customer_id)
135 | ON DELETE CASCADE
136 | ON UPDATE CASCADE,
137 | CONSTRAINT fk_customer_dealer_dealer
138 | FOREIGN KEY (dealer_id)
139 | REFERENCES dealer(dealer_id)
140 | ON DELETE CASCADE
141 | ON UPDATE CASCADE
142 | );
--------------------------------------------------------------------------------
/chapter_08/images/dbdiagram.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/chapter_08/images/dbdiagram.png
--------------------------------------------------------------------------------
/chapter_08/images/er-diagram.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/chapter_08/images/er-diagram.png
--------------------------------------------------------------------------------
/chapter_08/workbench.mwb:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/chapter_08/workbench.mwb
--------------------------------------------------------------------------------
/images/Hao-Hi.png:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Neo-Hao/grokking-relational-database-design/3c9d8324b5b3293513b8ebd316ec8fcfcd92769d/images/Hao-Hi.png
--------------------------------------------------------------------------------