GSD Questions
You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

81 lines
5.5 KiB

6 years ago
  1. SET FEEDBACK OFF
  2. DROP TABLE STUDENT CASCADE CONSTRAINTS;
  3. DROP TABLE EXAM CASCADE CONSTRAINTS;
  4. CREATE TABLE STUDENT (
  5. STUDENT_ID INT PRIMARY KEY,
  6. LASTNAME VARCHAR(40) NOT NULL,
  7. FIRSTNAME VARCHAR(40) NOT NULL,
  8. GENDER VARCHAR(1) NOT NULL,
  9. CONSTRAINT CHK_STUDENT_ID
  10. CHECK (STUDENT_ID>=100000 AND STUDENT_ID<=999999),
  11. CONSTRAINT CHK_GENDER
  12. CHECK (GENDER='m' OR GENDER='f')
  13. );
  14. CREATE TABLE EXAM (
  15. STUDENT_ID INT,
  16. COURSE VARCHAR(40),
  17. GRADE DECIMAL(2,1),
  18. ATTEMPT INT,
  19. CONSTRAINT PK PRIMARY KEY(STUDENT_ID, ATTEMPT, COURSE),
  20. CONSTRAINT CHK_ATTEMPT CHECK (ATTEMPT IN (1,2,3)),
  21. CONSTRAINT CHK_GRADE CHECK (
  22. GRADE IN (1.0,1.3,1.7,2.0,2.3,2.7,3.0,3.3,3.7,4.0,5.0)
  23. ),
  24. CONSTRAINT FK_STUDENT_ID FOREIGN KEY (STUDENT_ID)
  25. REFERENCES STUDENT(STUDENT_ID) ON DELETE CASCADE
  26. );
  27. INSERT INTO STUDENT (STUDENT_ID, FIRSTNAME, LASTNAME, GENDER) VALUES (100000, 'Joffrey', 'Baratheon', 'm');
  28. INSERT INTO STUDENT (STUDENT_ID, FIRSTNAME, LASTNAME, GENDER) VALUES (100001, 'Jorah', 'Mormont', 'm');
  29. INSERT INTO STUDENT (STUDENT_ID, FIRSTNAME, LASTNAME, GENDER) VALUES (100002, 'Daenerys', 'Targaryen', 'f');
  30. INSERT INTO STUDENT (STUDENT_ID, FIRSTNAME, LASTNAME, GENDER) VALUES (100003, 'Theon', 'Graufreud', 'm');
  31. INSERT INTO STUDENT (STUDENT_ID, FIRSTNAME, LASTNAME, GENDER) VALUES (100004, 'Tyrion', 'Lennister', 'm');
  32. INSERT INTO STUDENT (STUDENT_ID, FIRSTNAME, LASTNAME, GENDER) VALUES (100005, 'Jon', 'Snow', 'm');
  33. INSERT INTO STUDENT (STUDENT_ID, FIRSTNAME, LASTNAME, GENDER) VALUES (100006, 'Arya', 'Stark', 'f');
  34. INSERT INTO STUDENT (STUDENT_ID, FIRSTNAME, LASTNAME, GENDER) VALUES (100007, 'Jaime', 'Lennister', 'm');
  35. INSERT INTO STUDENT (STUDENT_ID, FIRSTNAME, LASTNAME, GENDER) VALUES (100008, 'Brienne', 'of Tarth', 'f');
  36. INSERT INTO STUDENT (STUDENT_ID, FIRSTNAME, LASTNAME, GENDER) VALUES (100009, 'Sansa', 'Stark', 'f');
  37. INSERT INTO STUDENT (STUDENT_ID, FIRSTNAME, LASTNAME, GENDER) VALUES (100010, 'Petyr', 'Baelish', 'm');
  38. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100000, 'Database Management Systems', 1, 5.0);
  39. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100001, 'Database Management Systems', 1, 5);
  40. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100001, 'Database Management Systems', 2, 3.3);
  41. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100001, 'Programming I', 1, 2.3);
  42. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100002, 'Database Management Systems', 1, 5);
  43. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100002, 'Database Management Systems', 2, 1.7);
  44. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100002, 'Programming I', 1, 4);
  45. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100003, 'Database Management Systems', 1, 2.3);
  46. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100003, 'Programming I', 1, 5);
  47. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100003, 'Programming I', 2, 3.3);
  48. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100004, 'Database Management Systems', 1, 1.0);
  49. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100004, 'Programming I', 1, 1.3);
  50. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100005, 'Database Management Systems', 1, 5);
  51. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100005, 'Database Management Systems', 2, 1.3);
  52. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100005, 'Programming I', 1, 5);
  53. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100005, 'Programming I', 2, 2);
  54. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100006, 'Database Management Systems', 1, 1);
  55. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100006, 'Programming I', 1, 1);
  56. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100007, 'Database Management Systems', 1, 2.3);
  57. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100007, 'Programming I', 1, 5);
  58. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100007, 'Programming I', 2, 1.7);
  59. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100008, 'Database Management Systems', 1, 5);
  60. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100008, 'Database Management Systems', 2, 1.3);
  61. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100008, 'Programming I', 1, 5);
  62. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100008, 'Programming I', 2, 5);
  63. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100008, 'Programming I', 3, 3.3);
  64. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100009, 'Database Management Systems', 1, 2.3);
  65. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100009, 'Programming I', 1, 1.3);
  66. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100010, 'Database Management Systems', 1, 5);
  67. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100010, 'Database Management Systems', 2, 2.3);
  68. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100010, 'Programming I', 1, 5);
  69. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100010, 'Programming I', 2, 5);
  70. INSERT INTO EXAM (STUDENT_ID, COURSE, ATTEMPT, GRADE) VALUES (100010, 'Programming I', 3, 5);
  71. SET FEEDBACK ON
  72. -- c.)
  73. SELECT S.STUDENT_ID, S.LASTNAME, E.COURSE FROM STUDENT S, EXAM E WHERE S.STUDENT_ID=E.STUDENT_ID AND ATTEMPT=3 AND GRADE=5;
  74. -- d.)
  75. SELECT S.GENDER, AVG(ATTEMPT) FROM STUDENT S, EXAM E WHERE S.STUDENT_ID=E.STUDENT_ID AND NOT GRADE=5 GROUP BY S.GENDER;