├── create.sh ├── drop.sh ├── insert.sh ├── university.png ├── drop-table.sql ├── ddl.sql ├── Database System Concepts - 6th edition.html └── smallRelationsInsertFile.sql /create.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | mysql -u root -p university < ddl.sql 3 | -------------------------------------------------------------------------------- /drop.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | mysql -u root -p university < drop-table.sql 3 | -------------------------------------------------------------------------------- /insert.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | mysql -u root -p university < largeRelationsInsertFile.sql 3 | -------------------------------------------------------------------------------- /university.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/w32zhong/sql-sample-data/HEAD/university.png -------------------------------------------------------------------------------- /drop-table.sql: -------------------------------------------------------------------------------- 1 | drop table prereq; 2 | drop table time_slot; 3 | drop table advisor; 4 | drop table takes; 5 | drop table student; 6 | drop table teaches; 7 | drop table section; 8 | drop table instructor; 9 | drop table course; 10 | drop table department; 11 | drop table classroom; 12 | -------------------------------------------------------------------------------- /ddl.sql: -------------------------------------------------------------------------------- 1 | create table classroom 2 | (building varchar(15), 3 | room_number varchar(7), 4 | capacity numeric(4,0), 5 | primary key (building, room_number) 6 | ); 7 | 8 | create table department 9 | (dept_name varchar(20), 10 | building varchar(15), 11 | budget numeric(12,2) check (budget > 0), 12 | primary key (dept_name) 13 | ); 14 | 15 | create table course 16 | (course_id varchar(8), 17 | title varchar(50), 18 | dept_name varchar(20), 19 | credits numeric(2,0) check (credits > 0), 20 | primary key (course_id), 21 | foreign key (dept_name) references department (dept_name) 22 | on delete set null 23 | ); 24 | 25 | create table instructor 26 | (ID varchar(5), 27 | name varchar(20) not null, 28 | dept_name varchar(20), 29 | salary numeric(8,2) check (salary > 29000), 30 | primary key (ID), 31 | foreign key (dept_name) references department (dept_name) 32 | on delete set null 33 | ); 34 | 35 | create table section 36 | (course_id varchar(8), 37 | sec_id varchar(8), 38 | semester varchar(6) 39 | check (semester in ('Fall', 'Winter', 'Spring', 'Summer')), 40 | year numeric(4,0) check (year > 1701 and year < 2100), 41 | building varchar(15), 42 | room_number varchar(7), 43 | time_slot_id varchar(4), 44 | primary key (course_id, sec_id, semester, year), 45 | foreign key (course_id) references course (course_id) 46 | on delete cascade, 47 | foreign key (building, room_number) references 48 | classroom (building, room_number) 49 | on delete set null 50 | ); 51 | 52 | create table teaches 53 | (ID varchar(5), 54 | course_id varchar(8), 55 | sec_id varchar(8), 56 | semester varchar(6), 57 | year numeric(4,0), 58 | primary key (ID, course_id, sec_id, semester, year), 59 | foreign key (course_id, sec_id, semester, year) references 60 | section (course_id, sec_id, semester, year) 61 | on delete cascade, 62 | foreign key (ID) references instructor (ID) 63 | on delete cascade 64 | ); 65 | 66 | create table student 67 | (ID varchar(5), 68 | name varchar(20) not null, 69 | dept_name varchar(20), 70 | tot_cred numeric(3,0) check (tot_cred >= 0), 71 | primary key (ID), 72 | foreign key (dept_name) references department (dept_name) 73 | on delete set null 74 | ); 75 | 76 | create table takes 77 | (ID varchar(5), 78 | course_id varchar(8), 79 | sec_id varchar(8), 80 | semester varchar(6), 81 | year numeric(4,0), 82 | grade varchar(2), 83 | primary key (ID, course_id, sec_id, semester, year), 84 | foreign key (course_id, sec_id, semester, year) references 85 | section (course_id, sec_id, semester, year) 86 | on delete cascade, 87 | foreign key (ID) references student (ID) 88 | on delete cascade 89 | ); 90 | 91 | create table advisor 92 | (s_ID varchar(5), 93 | i_ID varchar(5), 94 | primary key (s_ID), 95 | foreign key (i_ID) references instructor (ID) 96 | on delete set null, 97 | foreign key (s_ID) references student (ID) 98 | on delete cascade 99 | ); 100 | 101 | create table time_slot 102 | (time_slot_id varchar(4), 103 | day varchar(1), 104 | start_hr numeric(2) check (start_hr >= 0 and start_hr < 24), 105 | start_min numeric(2) check (start_min >= 0 and start_min < 60), 106 | end_hr numeric(2) check (end_hr >= 0 and end_hr < 24), 107 | end_min numeric(2) check (end_min >= 0 and end_min < 60), 108 | primary key (time_slot_id, day, start_hr, start_min) 109 | ); 110 | 111 | create table prereq 112 | (course_id varchar(8), 113 | prereq_id varchar(8), 114 | primary key (course_id, prereq_id), 115 | foreign key (course_id) references course (course_id) 116 | on delete cascade, 117 | foreign key (prereq_id) references course (course_id) 118 | ); 119 | -------------------------------------------------------------------------------- /Database System Concepts - 6th edition.html: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | 5 | Database System Concepts - 6th edition 6 | 7 | 8 | ------- book cover ------- 9 | 10 | Database System Concepts
Sixth Edition 11 |
12 |
Avi Silberschatz 13 |
Henry F. Korth 14 |
S. Sudarshan 15 |

16 | 17 | 18 |

19 | line separator 20 |

21 | 22 | We provide below the DDL and sample data for the tables in the university that we use in our text, 23 | with one change: instead of using the time data type, which is not supported on some databases 24 | such as Oracle, we split start_time into start_hr and start_min, and end_time 25 | into end_hr and end_min, which are integer types. 26 | If the database you use supports the time type, and you wish to use it, 27 | you can modify the DDL and the sample data files accordingly. 28 | 29 |

30 |

31 |
- 32 | DDL (use this the first time), 33 | DDL with drop table (use this if you wish to recreate the database after dropping 34 | existing tables) 35 | 36 |

37 |

- 38 | SQL code for creating small relations 39 |
The file smallRelationsInsertFile.sql contains data that matches Appendix A exactly. The file contains SQL 40 | insert statements to load data into all the tables, after first deleting any data that the tables currently 41 | contain.
42 | The data include students taking courses outside their department, and instructors teaching courses outside 43 | their department; this helps detect errors in natural join specifications that accidentally equate department names of students 44 | or instructors with department names of courses. 45 |
46 |

47 |

- 48 | SQL code for 49 | creating large relations 50 |
The file largeRelationsInsertFile.sql contains 51 | SQL insert statements for larger, randomly created relations for a 52 | truly strange university (since course titles and department names are 53 | chosen randomly). 54 |
55 | 56 |
57 | The sizes of the relations are as follows: 58 | 59 | 60 | 61 | 62 | 63 | 64 | 65 | 66 | 67 | 68 | 69 |
department 20
instructor 50
student 2000
course 200
prereq 100
section 100
time_slot 20
teaches 100
takes 30000
advisor 2000
70 | 71 |
72 | 73 |

74 |

- 75 | tableGen.java 76 |
77 | The file tableGen.java contains a Java program for generating the 78 | largeRelations data. Be warned that some versions of the eclipse 79 | Java compiler lack the java.util.Scanner class that this program uses; 80 | if you run into a problem compiling this program, 81 | we suggest you upgrade to the latest version of the eclipse 82 | Java compiler, or use the Sun Java compiler instead. 83 |
84 |
85 | line separator 86 | 87 | 88 |
-------------------------------------------------------------------------------- /smallRelationsInsertFile.sql: -------------------------------------------------------------------------------- 1 | delete from prereq; 2 | delete from time_slot; 3 | delete from advisor; 4 | delete from takes; 5 | delete from student; 6 | delete from teaches; 7 | delete from section; 8 | delete from instructor; 9 | delete from course; 10 | delete from department; 11 | delete from classroom; 12 | insert into classroom values ('Packard', '101', '500'); 13 | insert into classroom values ('Painter', '514', '10'); 14 | insert into classroom values ('Taylor', '3128', '70'); 15 | insert into classroom values ('Watson', '100', '30'); 16 | insert into classroom values ('Watson', '120', '50'); 17 | insert into department values ('Biology', 'Watson', '90000'); 18 | insert into department values ('Comp. Sci.', 'Taylor', '100000'); 19 | insert into department values ('Elec. Eng.', 'Taylor', '85000'); 20 | insert into department values ('Finance', 'Painter', '120000'); 21 | insert into department values ('History', 'Painter', '50000'); 22 | insert into department values ('Music', 'Packard', '80000'); 23 | insert into department values ('Physics', 'Watson', '70000'); 24 | insert into course values ('BIO-101', 'Intro. to Biology', 'Biology', '4'); 25 | insert into course values ('BIO-301', 'Genetics', 'Biology', '4'); 26 | insert into course values ('BIO-399', 'Computational Biology', 'Biology', '3'); 27 | insert into course values ('CS-101', 'Intro. to Computer Science', 'Comp. Sci.', '4'); 28 | insert into course values ('CS-190', 'Game Design', 'Comp. Sci.', '4'); 29 | insert into course values ('CS-315', 'Robotics', 'Comp. Sci.', '3'); 30 | insert into course values ('CS-319', 'Image Processing', 'Comp. Sci.', '3'); 31 | insert into course values ('CS-347', 'Database System Concepts', 'Comp. Sci.', '3'); 32 | insert into course values ('EE-181', 'Intro. to Digital Systems', 'Elec. Eng.', '3'); 33 | insert into course values ('FIN-201', 'Investment Banking', 'Finance', '3'); 34 | insert into course values ('HIS-351', 'World History', 'History', '3'); 35 | insert into course values ('MU-199', 'Music Video Production', 'Music', '3'); 36 | insert into course values ('PHY-101', 'Physical Principles', 'Physics', '4'); 37 | insert into instructor values ('10101', 'Srinivasan', 'Comp. Sci.', '65000'); 38 | insert into instructor values ('12121', 'Wu', 'Finance', '90000'); 39 | insert into instructor values ('15151', 'Mozart', 'Music', '40000'); 40 | insert into instructor values ('22222', 'Einstein', 'Physics', '95000'); 41 | insert into instructor values ('32343', 'El Said', 'History', '60000'); 42 | insert into instructor values ('33456', 'Gold', 'Physics', '87000'); 43 | insert into instructor values ('45565', 'Katz', 'Comp. Sci.', '75000'); 44 | insert into instructor values ('58583', 'Califieri', 'History', '62000'); 45 | insert into instructor values ('76543', 'Singh', 'Finance', '80000'); 46 | insert into instructor values ('76766', 'Crick', 'Biology', '72000'); 47 | insert into instructor values ('83821', 'Brandt', 'Comp. Sci.', '92000'); 48 | insert into instructor values ('98345', 'Kim', 'Elec. Eng.', '80000'); 49 | insert into section values ('BIO-101', '1', 'Summer', '2009', 'Painter', '514', 'B'); 50 | insert into section values ('BIO-301', '1', 'Summer', '2010', 'Painter', '514', 'A'); 51 | insert into section values ('CS-101', '1', 'Fall', '2009', 'Packard', '101', 'H'); 52 | insert into section values ('CS-101', '1', 'Spring', '2010', 'Packard', '101', 'F'); 53 | insert into section values ('CS-190', '1', 'Spring', '2009', 'Taylor', '3128', 'E'); 54 | insert into section values ('CS-190', '2', 'Spring', '2009', 'Taylor', '3128', 'A'); 55 | insert into section values ('CS-315', '1', 'Spring', '2010', 'Watson', '120', 'D'); 56 | insert into section values ('CS-319', '1', 'Spring', '2010', 'Watson', '100', 'B'); 57 | insert into section values ('CS-319', '2', 'Spring', '2010', 'Taylor', '3128', 'C'); 58 | insert into section values ('CS-347', '1', 'Fall', '2009', 'Taylor', '3128', 'A'); 59 | insert into section values ('EE-181', '1', 'Spring', '2009', 'Taylor', '3128', 'C'); 60 | insert into section values ('FIN-201', '1', 'Spring', '2010', 'Packard', '101', 'B'); 61 | insert into section values ('HIS-351', '1', 'Spring', '2010', 'Painter', '514', 'C'); 62 | insert into section values ('MU-199', '1', 'Spring', '2010', 'Packard', '101', 'D'); 63 | insert into section values ('PHY-101', '1', 'Fall', '2009', 'Watson', '100', 'A'); 64 | insert into teaches values ('10101', 'CS-101', '1', 'Fall', '2009'); 65 | insert into teaches values ('10101', 'CS-315', '1', 'Spring', '2010'); 66 | insert into teaches values ('10101', 'CS-347', '1', 'Fall', '2009'); 67 | insert into teaches values ('12121', 'FIN-201', '1', 'Spring', '2010'); 68 | insert into teaches values ('15151', 'MU-199', '1', 'Spring', '2010'); 69 | insert into teaches values ('22222', 'PHY-101', '1', 'Fall', '2009'); 70 | insert into teaches values ('32343', 'HIS-351', '1', 'Spring', '2010'); 71 | insert into teaches values ('45565', 'CS-101', '1', 'Spring', '2010'); 72 | insert into teaches values ('45565', 'CS-319', '1', 'Spring', '2010'); 73 | insert into teaches values ('76766', 'BIO-101', '1', 'Summer', '2009'); 74 | insert into teaches values ('76766', 'BIO-301', '1', 'Summer', '2010'); 75 | insert into teaches values ('83821', 'CS-190', '1', 'Spring', '2009'); 76 | insert into teaches values ('83821', 'CS-190', '2', 'Spring', '2009'); 77 | insert into teaches values ('83821', 'CS-319', '2', 'Spring', '2010'); 78 | insert into teaches values ('98345', 'EE-181', '1', 'Spring', '2009'); 79 | insert into student values ('00128', 'Zhang', 'Comp. Sci.', '102'); 80 | insert into student values ('12345', 'Shankar', 'Comp. Sci.', '32'); 81 | insert into student values ('19991', 'Brandt', 'History', '80'); 82 | insert into student values ('23121', 'Chavez', 'Finance', '110'); 83 | insert into student values ('44553', 'Peltier', 'Physics', '56'); 84 | insert into student values ('45678', 'Levy', 'Physics', '46'); 85 | insert into student values ('54321', 'Williams', 'Comp. Sci.', '54'); 86 | insert into student values ('55739', 'Sanchez', 'Music', '38'); 87 | insert into student values ('70557', 'Snow', 'Physics', '0'); 88 | insert into student values ('76543', 'Brown', 'Comp. Sci.', '58'); 89 | insert into student values ('76653', 'Aoi', 'Elec. Eng.', '60'); 90 | insert into student values ('98765', 'Bourikas', 'Elec. Eng.', '98'); 91 | insert into student values ('98988', 'Tanaka', 'Biology', '120'); 92 | insert into takes values ('00128', 'CS-101', '1', 'Fall', '2009', 'A'); 93 | insert into takes values ('00128', 'CS-347', '1', 'Fall', '2009', 'A-'); 94 | insert into takes values ('12345', 'CS-101', '1', 'Fall', '2009', 'C'); 95 | insert into takes values ('12345', 'CS-190', '2', 'Spring', '2009', 'A'); 96 | insert into takes values ('12345', 'CS-315', '1', 'Spring', '2010', 'A'); 97 | insert into takes values ('12345', 'CS-347', '1', 'Fall', '2009', 'A'); 98 | insert into takes values ('19991', 'HIS-351', '1', 'Spring', '2010', 'B'); 99 | insert into takes values ('23121', 'FIN-201', '1', 'Spring', '2010', 'C+'); 100 | insert into takes values ('44553', 'PHY-101', '1', 'Fall', '2009', 'B-'); 101 | insert into takes values ('45678', 'CS-101', '1', 'Fall', '2009', 'F'); 102 | insert into takes values ('45678', 'CS-101', '1', 'Spring', '2010', 'B+'); 103 | insert into takes values ('45678', 'CS-319', '1', 'Spring', '2010', 'B'); 104 | insert into takes values ('54321', 'CS-101', '1', 'Fall', '2009', 'A-'); 105 | insert into takes values ('54321', 'CS-190', '2', 'Spring', '2009', 'B+'); 106 | insert into takes values ('55739', 'MU-199', '1', 'Spring', '2010', 'A-'); 107 | insert into takes values ('76543', 'CS-101', '1', 'Fall', '2009', 'A'); 108 | insert into takes values ('76543', 'CS-319', '2', 'Spring', '2010', 'A'); 109 | insert into takes values ('76653', 'EE-181', '1', 'Spring', '2009', 'C'); 110 | insert into takes values ('98765', 'CS-101', '1', 'Fall', '2009', 'C-'); 111 | insert into takes values ('98765', 'CS-315', '1', 'Spring', '2010', 'B'); 112 | insert into takes values ('98988', 'BIO-101', '1', 'Summer', '2009', 'A'); 113 | insert into takes values ('98988', 'BIO-301', '1', 'Summer', '2010', null); 114 | insert into advisor values ('00128', '45565'); 115 | insert into advisor values ('12345', '10101'); 116 | insert into advisor values ('23121', '76543'); 117 | insert into advisor values ('44553', '22222'); 118 | insert into advisor values ('45678', '22222'); 119 | insert into advisor values ('76543', '45565'); 120 | insert into advisor values ('76653', '98345'); 121 | insert into advisor values ('98765', '98345'); 122 | insert into advisor values ('98988', '76766'); 123 | insert into time_slot values ('A', 'M', '8', '0', '8', '50'); 124 | insert into time_slot values ('A', 'W', '8', '0', '8', '50'); 125 | insert into time_slot values ('A', 'F', '8', '0', '8', '50'); 126 | insert into time_slot values ('B', 'M', '9', '0', '9', '50'); 127 | insert into time_slot values ('B', 'W', '9', '0', '9', '50'); 128 | insert into time_slot values ('B', 'F', '9', '0', '9', '50'); 129 | insert into time_slot values ('C', 'M', '11', '0', '11', '50'); 130 | insert into time_slot values ('C', 'W', '11', '0', '11', '50'); 131 | insert into time_slot values ('C', 'F', '11', '0', '11', '50'); 132 | insert into time_slot values ('D', 'M', '13', '0', '13', '50'); 133 | insert into time_slot values ('D', 'W', '13', '0', '13', '50'); 134 | insert into time_slot values ('D', 'F', '13', '0', '13', '50'); 135 | insert into time_slot values ('E', 'T', '10', '30', '11', '45 '); 136 | insert into time_slot values ('E', 'R', '10', '30', '11', '45 '); 137 | insert into time_slot values ('F', 'T', '14', '30', '15', '45 '); 138 | insert into time_slot values ('F', 'R', '14', '30', '15', '45 '); 139 | insert into time_slot values ('G', 'M', '16', '0', '16', '50'); 140 | insert into time_slot values ('G', 'W', '16', '0', '16', '50'); 141 | insert into time_slot values ('G', 'F', '16', '0', '16', '50'); 142 | insert into time_slot values ('H', 'W', '10', '0', '12', '30'); 143 | insert into prereq values ('BIO-301', 'BIO-101'); 144 | insert into prereq values ('BIO-399', 'BIO-101'); 145 | insert into prereq values ('CS-190', 'CS-101'); 146 | insert into prereq values ('CS-315', 'CS-101'); 147 | insert into prereq values ('CS-319', 'CS-101'); 148 | insert into prereq values ('CS-347', 'CS-101'); 149 | insert into prereq values ('EE-181', 'PHY-101'); 150 | --------------------------------------------------------------------------------