Table Names and Fields(MySQL)
Student Table
Student(s_id, s_name, s_birth, s_sex)
Student ID, Student Name, Date of Birth, Student GenderCourse Table
Course(c_id, c_name, t_id)
Course ID, Course Name, Teacher IDTeacher Table
Teacher(t_id, t_name)
Teacher ID, Teacher NameScore Table
Score(s_id, c_id, s_score)
Student ID, Course ID, Score
Test Data - Creating Tables
Student Table
1
2
3
4
5
6
7CREATE TABLE `Student`(
`s_id` VARCHAR(20),
`s_name` VARCHAR(20) NOT NULL DEFAULT '',
`s_birth` VARCHAR(20) NOT NULL DEFAULT '',
`s_sex` VARCHAR(10) NOT NULL DEFAULT '',
PRIMARY KEY(`s_id`)
);Course Table
1
2
3
4
5
6CREATE TABLE `Course`(
`c_id` VARCHAR(20),
`c_name` VARCHAR(20) NOT NULL DEFAULT '',
`t_id` VARCHAR(20) NOT NULL,
PRIMARY KEY(`c_id`)
);Teacher Table
1
2
3
4
5CREATE TABLE `Teacher`(
`t_id` VARCHAR(20),
`t_name` VARCHAR(20) NOT NULL DEFAULT '',
PRIMARY KEY(`t_id`)
);Score Table
1
2
3
4
5
6CREATE TABLE `Score`(
`s_id` VARCHAR(20),
`c_id` VARCHAR(20),
`s_score` INT(3),
PRIMARY KEY(`s_id`,`c_id`)
);Inserting Test Data into Student Table
1
2
3
4
5
6
7
8INSERT INTO Student VALUES('01', 'John Doe', '1990-01-01', 'Male');
INSERT INTO Student VALUES('02', 'Jane Smith', '1990-12-21', 'Male');
INSERT INTO Student VALUES('03', 'Michael Brown', '1990-05-20', 'Male');
INSERT INTO Student VALUES('04', 'Emily Davis', '1990-08-06', 'Male');
INSERT INTO Student VALUES('05', 'Lucy Johnson', '1991-12-01', 'Female');
INSERT INTO Student VALUES('06', 'Sophia Williams', '1992-03-01', 'Female');
INSERT INTO Student VALUES('07', 'Olivia Taylor', '1989-07-01', 'Female');
INSERT INTO Student VALUES('08', 'Victoria King', '1990-01-20', 'Female');Inserting Test Data into Course Table
1
2
3INSERT INTO Course VALUES('01', 'Literature', '02');
INSERT INTO Course VALUES('02', 'Mathematics', '01');
INSERT INTO Course VALUES('03', 'English', '03');Inserting Test Data into Teacher Table
1
2
3INSERT INTO Teacher VALUES('01', 'Andrew');
INSERT INTO Teacher VALUES('02', 'Bethany');
INSERT INTO Teacher VALUES('03', 'Charlie');Transcript Test Data
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18insert into Score values('01' , '01' , 80);
insert into Score values('01' , '02' , 90);
insert into Score values('01' , '03' , 99);
insert into Score values('02' , '01' , 70);
insert into Score values('02' , '02' , 60);
insert into Score values('02' , '03' , 80);
insert into Score values('03' , '01' , 80);
insert into Score values('03' , '02' , 80);
insert into Score values('03' , '03' , 80);
insert into Score values('04' , '01' , 50);
insert into Score values('04' , '02' , 30);
insert into Score values('04' , '03' , 20);
insert into Score values('05' , '01' , 76);
insert into Score values('05' , '02' , 87);
insert into Score values('06' , '01' , 31);
insert into Score values('06' , '03' , 34);
insert into Score values('07' , '02' , 89);
insert into Score values('07' , '03' , 98);
Exercise questions and SQL statements
- Retrieve the information and course scores of students who have a higher score in course ‘01’ than in course ‘02’
1 | SELECT a.*, b.s_score AS '01_score', c.s_score AS '02_score' |
- Retrieve the information and course scores of students who have a lower score in course ‘01’ than in course ‘02’
1 | SELECT a.*, b.s_score AS '01_score', c.s_score AS '02_score' |
- Retrieve student IDs, names, and average scores for students with an average score of 60 or above
1 | SELECT b.s_id, b.s_name, ROUND(AVG(a.s_score), 2) AS avg_score |
- Retrieve student IDs, names, and average scores for students with an average score below 60 (including those with no scores)
1 | SELECT b.s_id, b.s_name, ROUND(AVG(a.s_score), 2) AS avg_score |
- Retrieve student IDs, names, total courses selected, and total scores across all courses
1 | SELECT a.s_id, a.s_name, COUNT(b.c_id) AS sum_course, SUM(b.s_score) AS sum_score |
- Query the number of teachers with the surname “Smith”
1 | SELECT COUNT(t_id) FROM teacher WHERE t_name LIKE 'Smith%'; |
- Query the information of students who have taken classes taught by Teacher “John Doe”
1 | SELECT a.* |
- Query the information of students who have not taken classes taught by Teacher “John Doe”
1 | SELECT * |
- Query the information of students who have taken both courses with IDs “Math101” and “Science101”
1 | SELECT a.* |
- Query the information of students who have taken the course with ID “Math101” but have not taken the course with ID “Science101”
1 | SELECT a.* |
- Query information of students who have not taken all courses
1 | -- @wendiepei's approach |
- Query information of students who have taken at least one course in common with student ID ‘01’
1 | SELECT * |
- Query information of students who have taken exactly the same courses as student ID ‘01’
1 | SELECT |
- Query the names of students who have not taken any course taught by Teacher “Tom”
1 | select a.s_name from student a where a.s_id not in ( |
- Query student IDs, names, and average scores of students who have failed two or more courses
1 | SELECT a.s_id, a.s_name, ROUND(AVG(b.s_score), 2) AS average_score |
- Retrieve student information for students who scored less than 60 on course “01”, ordered by score in descending order.
1 | SELECT a.*, b.c_id, b.s_score |
- Display the scores of all courses and the average score for each student, ordered by their average score from highest to lowest.
1 | SELECT |
- Query the highest score, lowest score, average score, pass rate, medium rate, good rate, and excellent rate for each course. Display in the following format: Course ID, Course Name, Highest Score, Lowest Score, Average Score, Pass Rate, Medium Rate, Good Rate, Excellent Rate.
– Pass is >=60, Medium is 70-80, Good is 80-90, Excellent is >=90
1 | SELECT |
- Sort scores by course and display rankings. MySQL does not have a built-in
RANK()
function, so we’ll use variables to simulate it.
1 | SELECT |
- Query the total score of each student and rank them
1 | SELECT |
- Query the average score of different courses taught by different teachers, sorted from highest to lowest
1 | SELECT |
- Query the information of students who rank second and third in all courses along with their scores
1 | (SELECT |
Count the number of students in each score range for each subject:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31select distinct f.c_name, a.c_id,
b.`85-100`, b.Percentage as `[85-100] Percentage`,
c.`70-85`, c.Percentage as `[70-85] Percentage`,
d.`60-70`, d.Percentage as `[60-70] Percentage`,
e.`0-60`, e.Percentage as `[0-60] Percentage`
from score a
left join (
select c_id,
SUM(case when s_score > 85 and s_score <= 100 then 1 else 0 end) as `85-100`,
ROUND(100*(SUM(case when s_score > 85 and s_score <= 100 then 1 else 0 end)/count(*)),2) as Percentage
from score GROUP BY c_id
) b on a.c_id = b.c_id
left join (
select c_id,
SUM(case when s_score > 70 and s_score <= 85 then 1 else 0 end) as `70-85`,
ROUND(100*(SUM(case when s_score > 70 and s_score <= 85 then 1 else 0 end)/count(*)),2) as Percentage
from score GROUP BY c_id
) c on a.c_id = c.c_id
left join (
select c_id,
SUM(case when s_score > 60 and s_score <= 70 then 1 else 0 end) as `60-70`,
ROUND(100*(SUM(case when s_score > 60 and s_score <= 70 then 1 else 0 end)/count(*)),2) as Percentage
from score GROUP BY c_id
) d on a.c_id = d.c_id
left join (
select c_id,
SUM(case when s_score >= 0 and s_score <= 60 then 1 else 0 end) as `0-60`,
ROUND(100*(SUM(case when s_score >= 0 and s_score <= 60 then 1 else 0 end)/count(*)),2) as Percentage
from score GROUP BY c_id
) e on a.c_id = e.c_id
left join course f on a.c_id = f.c_id;Query average scores and their ranks for students:
1
2
3
4
5
6select a.s_id,
@i:=@i+1 as 'No Gaps in Ranking',
@k:=(case when @avg_score=a.avg_s then @k else @i end) as 'With Gaps in Ranking',
@avg_score:=avg_s as 'Average Score'
from (select s_id, ROUND(AVG(s_score),2) as avg_s from score GROUP BY s_id ORDER BY avg_s DESC) a,
(select @avg_score:=0, @i:=0, @k:=0) b;Query records of the top three students in each subject:
1
2
3
4
5select a.s_id, a.c_id, a.s_score from score a
left join score b on a.c_id = b.c_id and a.s_score < b.s_score
group by a.s_id, a.c_id, a.s_score
having count(b.s_id) < 3
order by a.c_id, a.s_score desc;Query the number of students enrolled in each course:
1
select c_id, count(s_id) from score group by c_id;
Query the student ID and name of students who have taken exactly two courses:
1
2select s_id, s_name from student
where s_id in (select s_id from score group by s_id having count(c_id) = 2);Query the number of male and female students:
1
select s_sex, count(s_sex) as Count from student group by s_sex;
Query student information whose name contains the character “Tom”:
1
select * from student where s_name like '%Tom%';
Query list of students with the same name and gender, and count of such names:
1
2
3select a.s_name, a.s_sex, count(*) as Count from student a
join student b on a.s_id != b.s_id and a.s_name = b.s_name and a.s_sex = b.s_sex
group by a.s_name, a.s_sex;Query list of students born in 1990:
1
select s_name from student where s_birth like '1990%';
Query average scores for each course, ordered by average score descending, and course ID ascending if average scores are the same:
1
select c_id, round(avg(s_score), 2) as avg_score from score group by c_id order by avg_score desc, c_id asc;
Query student ID, name, and average score of students with average score >= 85:
1
2select a.s_id, b.s_name, round(avg(a.s_score), 2) as avg_score from score a
left join student b on a.s_id = b.s_id group by s_id having avg_score >= 85;Query names and scores of students who scored less than 60 in the course “mathematics”:
1
2
3
4select a.s_name, b.s_score from student a
join score b on a.s_id = b.s_id
where b.c_id = (select c_id from course where c_name = 'mathematics')
and b.s_score < 60;Query course-wise scores and total scores of all students:
1
2
3
4
5
6
7
8
9select a.s_id, a.s_name,
sum(case c.c_name when 'history' then b.s_score else 0 end) as 'history',
sum(case c.c_name when 'mathematics' then b.s_score else 0 end) as 'mathematics',
sum(case c.c_name when 'Politics' then b.s_score else 0 end) as 'Politics',
sum(b.s_score) as 'Total score'
from student a
left join score b on a.s_id = b.s_id
left join course c on b.c_id = c.c_id
group by a.s_id, a.s_name;Query names, course names, and scores of students scoring above 70 in any course:
1
2
3
4select a.s_name, b.c_name, c.s_score from student a
left join score c on a.s_id = c.s_id
left join course b on c.c_id = b.c_id
where c.s_score >= 70;Query courses where students failed:
1
2
3select a.s_id, a.c_id, b.c_name, a.s_score from score a
left join course b on a.c_id = b.c_id
where a.s_score < 60;Query student ID and name of students who scored above 80 in course ‘01’:
1
2
3select a.s_id, b.s_name from score a
left join student b on a.s_id = b.s_id
where a.c_id = '01' and a.s_score > 80;Count number of students in each course:
1
select count(*) from score group by c_id;
Query information of the highest scoring student in courses taught by teacher “Tom”:
– Get teacher ID1
select c_id from course c, teacher d where c.t_id = d.t_id and d.t_name = 'Tom';
– Get maximum score (could have ties)
1
select max(s_score) from score where c_id = '02';
– Get information
1
2
3
4
5select a.*, b.s_score, b.c_id, c.c_name from student a
left join score b on a.s_id = b.s_id
left join course c on b.c_id = c.c_id
where b.c_id = (select c_id from course c, teacher d where c.t_id = d.t_id and d.t_name = 'Tom')
and b.s_score in (select max(s_score) from score where c_id = '02');Query student ID, course ID, and score where different courses have the same score:
1
2select distinct b.s_id, b.c_id, b.s_score from score a, score b
where a.c_id != b.c_id and a.s_score = b.s_score;Query top two scores for each course:
1
2select a.s_id, a.c_id, a.s_score from score a
where (select count(1) from score b where b.c_id = a.c_id and b.s_score >= a.s_score) <= 2 order by a.c_id;Count number of students enrolled in each course (courses with more than 5 students):
1
select c_id, count(*) as total from score group by c_id having total > 5 order by total, c_id asc;
Query student IDs who have enrolled in at least two courses:
1
select s_id, count(*) as sel from score group by s_id having sel >= 2;
Query information of students who have enrolled in all courses:
1
select * from student where s_id in (select s_id from score group by s_id having count(*) = (select count(*) from course));
Query age of each student:
– Calculate age based on birthdate; subtract one if current month/day is before birthdate’s month/day1
2
3select s_birth, (date_format(now(), '%Y') - date_format(s_birth, '%Y') -
(case when date_format(now(), '%m%d') > date_format(s_birth, '%m%d') then 0 else 1 end)) as age
from student;Query students whose birthday is this week:
1
select * from student where week(date_format(now(), '%Y%m%d')) = week(s_birth);
Query students whose birthday is next week:
1
select * from student where week(date_format(now(), '%Y%m%d')) + 1 = week(s_birth);
Query students whose birthday is this month:
1
select * from student where month(date_format(now(), '%Y%m%d')) = month(s_birth);
Query students whose birthday is next month:
1
select * from student where month(date_format(now(), '%Y%m%d')) + 1 = month(s_birth);
OK,If you find this article helpful, feel free to share it with more people.
If you want to find a SQL tool to practice, you can try our sqlynx, which has a simple interface and is easy to use. https://www.sqlynx.com/download/ Free download