16 KiB
		
	
	
	
	
	
	
	
			
		
		
	
	
			16 KiB
		
	
	
	
	
	
	
	
Writeup
Table Creation
Student Table Creation - RegNo is the primary key as defined by the question.
SQL> create table STUDENT(regno varchar(20),name varchar(50),major varchar(20),bdate date,constraint pkeySTUDENT primary key(regno));
Table created.
Course Table Creation
SQL> create table COURSE(course# int,cname varchar(30),dept varchar(30));
Table created.
Verifying, we get
SQL> desc STUDENT;
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 REGNO                                     NOT NULL VARCHAR2(20)
 NAME                                               VARCHAR2(50)
 MAJOR                                              VARCHAR2(20)
 BDATE                                              DATE
SQL> desc COURSE;
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 COURSE#                                            NUMBER(38)
 CNAME                                              VARCHAR2(30)
 DEPT                                               VARCHAR2(30)
Adding the textbook table:
SQL> create table text(book_isbn int primary key,booktitle varchar(20),publisher varchar(50),author varchar(50));
Table created.
SQL> desc TEXT;
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 BOOK_ISBN                                 NOT NULL NUMBER(38)
 BOOKTITLE                                          VARCHAR2(20)
 PUBLISHER                                          VARCHAR2(50)
 AUTHOR                                             VARCHAR2(50)
For the ENROLL table, we'll have
SQL> ALTER TABLE COURSE
  2  ADD CONSTRAINT pk_course PRIMARY KEY (course#);
Table altered.
SQL> CREATE TABLE ENROLL (
  2      regno VARCHAR2(20),
  3      course# NUMBER(38),
  4      sem INT,
  5      book_isbn NUMBER(38),
  6      PRIMARY KEY (regno, course#),
  7      CONSTRAINT fkey1course FOREIGN KEY (regno) REFERENCES STUDENT (regno),
  8      CONSTRAINT fkey2course FOREIGN KEY (course#) REFERENCES COURSE (course#),
  9      CONSTRAINT fkey3book FOREIGN KEY (book_isbn) REFERENCES TEXT (book_isbn)
 10  );
Table created.
SQL>
SQL> create table BOOK_ADOPTION(course# int,sem int,book_isbn int,primary key(course#,book_isbn),constraint fkey1book_adoption foreign key(course#)references course(course#));
Table created.
SQL> desc ENROLL;
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 REGNO                                     NOT NULL VARCHAR2(20)
 COURSE#                                   NOT NULL NUMBER(38)
 SEM                                                NUMBER(38)
 BOOK_ISBN                                          NUMBER(38)
SQL> desc BOOK_ADOPTION;
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 COURSE#                                   NOT NULL NUMBER(38)
 SEM                                                NUMBER(38)
 BOOK_ISBN                                 NOT NULL NUMBER(38)
Now, defining the foreign key nature of BOOK_ISBN, we have:
SQL> alter table BOOK_ADOPTION add constraint fkey2book_adoption foreign key(book_isbn) references text(book_isbn);
Table altered.
SQL> alter table enroll add constraint fkey3enroll foreign key(book_isbn) references text(book_isbn);
Table altered.
Verifying status so far, we have
SQL> desc ENROLL;
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 REGNO                                     NOT NULL VARCHAR2(20)
 COURSE#                                   NOT NULL NUMBER(38)
 SEM                                                NUMBER(38)
 BOOK_ISBN                                          NUMBER(38)
SQL> desc BOOK_ADOPTION;
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 COURSE#                                   NOT NULL NUMBER(38)
 SEM                                                NUMBER(38)
 BOOK_ISBN                                 NOT NULL NUMBER(38)
SQL> descc TEXT;
SP2-0042: unknown command "descc TEXT" - rest of line ignored.
SQL> desc TEXT;
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 BOOK_ISBN                                 NOT NULL NUMBER(38)
 BOOKTITLE                                          VARCHAR2(20)
 PUBLISHER                                          VARCHAR2(50)
 AUTHOR                                             VARCHAR2(50)
POPULATING TUPPLES
Insertion into student:
SQL> insert into student values('123','Ashwin','CCE','17-oct-2003');
1 row created.
SQL> insert into student values('456','Aadit','CCE','03-feb-2005');
1 row created.
SQL> insert into student values('789','Shrikanth','Environment','01-jan-2023');
1 row created.
SQL> insert into student values('101','Aarav','Environment','23-sep-2004');
1 row created.
SQL> insert into student values('567','Amogh','CSE','03-mar-2004');
1 row created.
SQL> insert into student values('890','Saarthak','CSE','03-jul-2004');
1 row created.
Insertion into COURSE:
SQL> insert into COURSE values(1101,'DBMS','ICT');
1 row created.
SQL> insert into COURSE values(1102,'DAA','ICT');
1 row created.
SQL> insert into COURSE values(2201,'COA','CS');
1 row created.
SQL> insert into COURSE values(2202,'DSD','CS');
1 row created.
SQL> insert into COURSE values(3301,'MATH','EVS');
1 row created.
SQL> insert into COURSE values(3302,'POETRY','EVS');
1 row created.
SQL> insert into COURSE values(3303,'Random','EVS');
1 row created.
Insertion in TEXT:
SQL> insert into TEXT values(1234,'DBMS vol 1','Pearson','SS');
1 row created.
SQL> insert into TEXT values(4123,'DBMS vol 2','Pearson','SS');
1 row created.
SQL> insert into TEXT values(5678,'DAA vol 2','Pearson','Ramanujan');
1 row created.
SQL> insert into TEXT values(9012,'COA vol 666','Cengage','Satan');
1 row created.
SQL> insert into TEXT values(3456,'DSD vol 99','Penguin','Panda');
1 row created.
SQL> insert into TEXT values(7890,'Math vol 66','U-Like','R S Aggrwal');
1 row created.
SQL> insert into TEXT values(1123,'Poetry vol 0','OML','Yahya Bootwaala');
1 row created.
Insertion into ENROLL:
SQL> insert into enroll values('123',1101,1,1234);
1 row created.
SQL> insert into enroll values('123',1102,2,5678);
1 row created.
SQL> insert into enroll values('456',1101,3,4123);
1 row created.
SQL> insert into enroll values('456',2201,4,9012);
1 row created.
SQL> insert into enroll values('789',3301,5,7890);
1 row created.
SQL> insert into enroll values('789',3302,6,1123);
1 row created.
SQL> insert into enroll values('101',3302,7,7890);
1 row created.
SQL> insert into enroll values('567',2201,8,9012);
1 row created.
SQL> insert into enroll values('890',2202,1,3456);
1 row created.
Insertion into BOOK_ADOPTION:
SQL> insert into BOOK_ADOPTION values(1101,1,1234);
1 row created.
SQL> insert into BOOK_ADOPTION values(1102,2,4123);
1 row created.
SQL> insert into BOOK_ADOPTION values(1102,2,5678);
1 row created.
SQL> insert into BOOK_ADOPTION values(2201,3,9012);
1 row created.
SQL> insert into BOOK_ADOPTION values(2202,4,3456);
1 row created.
SQL> insert into BOOK_ADOPTION values(3301,5,7890);
1 row created.
SQL> insert into BOOK_ADOPTION values(3302,6,1123);
1 row created.
We also create a book that has not been
SQL> insert into text values(8901,'Random vol 66','Classmate','R D Sharma');
1 row created.
SQL> insert into BOOK_ADOPTION values(3303,7,8901);
1 row created.
Resizing the tables to look good in preview...
SQL> alter table student modify name varchar(20);
Table altered.
SQL> alter table student modify regno varchar(10);
Table altered.
SQL> alter table text modify (booktitle varchar(20),publisher varchar(20),author varchar(20));
Table altered.
ENTRY VALIDATION
SQL> select * from STUDENT;
REGNO      NAME                 MAJOR                BDATE
---------- -------------------- -------------------- ---------
123        Ashwin               CCE                  17-OCT-03
456        Aadit                CCE                  03-FEB-05
789        Shrikanth            Environment          01-JAN-23
101        Aarav                Environment          23-SEP-04
567        Amogh                CSE                  03-MAR-04
890        Saarthak             CSE                  03-JUL-04
6 rows selected.
SQL> select * from COURSE;
   COURSE# CNAME                          DEPT
---------- ------------------------------ ------------------------------
      1101 DBMS                           ICT
      1102 DAA                            ICT
      2201 COA                            CS
      2202 DSD                            CS
      3301 MATH                           EVS
      3302 POETRY                         EVS
      3303 Random                         EVS
7 rows selected.
SQL> select * from TEXT;
 BOOK_ISBN BOOKTITLE            PUBLISHER            AUTHOR
---------- -------------------- -------------------- --------------------
      1234 DBMS vol 1           Pearson              SS
      4123 DBMS vol 2           Pearson              SS
      5678 DAA vol 2            Pearson              Ramanujan
      9012 COA vol 666          Cengage              Satan
      3456 DSD vol 99           Penguin              Panda
      7890 Math vol 66          U-Like               R S Aggrwal
      1123 Poetry vol 0         OML                  Yahya Bootwaala
      8901 Random vol 66        Classmate            R D Sharma
8 rows selected.
SQL> select * from BOOK_ADOPTION;
   COURSE#        SEM  BOOK_ISBN
---------- ---------- ----------
      1101          1       1234
      1102          2       4123
      1102          2       5678
      2201          3       9012
      2202          4       3456
      3301          5       7890
      3302          6       1123
      3303          7       8901
8 rows selected.
SQL> select * from ENROLL;
REGNO                   COURSE#        SEM  BOOK_ISBN
-------------------- ---------- ---------- ----------
123                        1101          1       1234
123                        1102          2       5678
456                        1101          3       4123
456                        2201          4       9012
789                        3301          5       7890
789                        3302          6       1123
101                        3302          7       7890
567                        2201          8       9012
890                        2202          1       3456
9 rows selected.
Listing courses with more than 1 TEXT BOX
SQL> select CNAME,count(COURSE#) as NUM_TB
  2      from COURSE natural join BOOK_ADOPTION
  3      group by CNAME
  4      having count(COURSE#) > 1;
CNAME                              NUM_TB
------------------------------ ----------
DAA                                     2
List the departments whose all course text books are published by a particular publisher.
SQL> select distinct dept
  2  from course
  3  where not exists(
  4  select *
  5  from text natural join book_adoption
  6  where book_adoption.course# = course.course#
  7  and publisher!='Pearson');
DEPT
------------------------------
ICT
Find the students who have enrolled for course of more than one department
SQL> select name
  2  from student
  3  where regno in(
  4  select regno
  5  from enroll natural join course
  6  group by regno
  7  having count(distinct dept)>1);
NAME
--------------------
Aadit
To create a list, we use
SQL> select regno,count(distinct dept)
  2  from enroll natural join course
  3  group by regno;
REGNO                COUNT(DISTINCTDEPT)
-------------------- -------------------
456                                    2
101                                    1
890                                    1
567                                    1
123                                    1
789                                    1
6 rows selected.
Produce a list of students who are not enrolled.
SQL> select regno,name
  2  from student
  3  where regno not in(
  4  select regno from enroll);
REGNO      NAME
---------- --------------------
234        Vansh
SQL>
SQL> select regno,name
  2  from student
  3  where not exists(
  4  select regno from enroll
  5  where student.regno=enroll.regno);
REGNO      NAME
---------- --------------------
234        Vansh
List the department which adopts all the books from the particular publisher
SQL>  select distinct dept
  2      from course natural join Book_Adoption
  3      where book_isbn not in
  4      (select book_isbn
  5      from course natural join book_adoption join text using(book_isbn)
  6      where publisher !='Pearson'
  7      );
DEPT
------------------------------
ICT
SQL>   select distinct dept
  2      from course
  3      where not exists
  4      (
  5     select *
  6     from book_adoption natural join text
  7     where publisher !='Cengage'
  8     and course.course# =book_adoption.course#
  9      );
DEPT
------------------------------
EVS
CS
List the books which are adopted by the course as well as enrolled by the student
SQL> select booktitle
  2  from text
  3  where book_isbn in
  4  (
  5     select distinct book_isbn
  6  from book_adoption join enroll using(book_isbn)
  7  );
BOOKTITLE
--------------------
DBMS vol 1
DBMS vol 2
DAA vol 2
COA vol 666
DSD vol 99
Math vol 66
Poetry vol 0
7 rows selected.
List the courses which has adapted at least two books from a specific publisher
SQL> select course#,cname
  2  from text natural join book_adoption join course using(course#)
  3  where publisher='Pearson'
  4  group by (course#,cname)
  5  having count(book_isbn)>=2;
   COURSE# CNAME
---------- ------------------------------
      1102 DAA
Identify the students who are enrolled for maximum number of books.
SQL> select regno,name,count(book_isbn)
  2  from enroll natural join student
  3  group by regno,name having count(book_isbn)>= all
  4  (select count(book_isbn)
  5  from enroll natural join student
  6  group by regno);
REGNO      NAME                 COUNT(BOOK_ISBN)
---------- -------------------- ----------------
456        Aadit                               2
123        Ashwin                              2
789        Shrikanth                           2
List the publishers along with the number of books published by them.
SQL> select publisher,count(book_isbn)
  2  from (select * from text)
  3  group by publisher;
PUBLISHER            COUNT(BOOK_ISBN)
-------------------- ----------------
Penguin                             1
Cengage                             2
OML                                 1
Pearson                             3
Classmate                           1
SQL>
SQL> select publisher,count(book_isbn)
  2  from text
  3  group by publisher;
PUBLISHER            COUNT(BOOK_ISBN)
-------------------- ----------------
Penguin                             1
Cengage                             2
OML                                 1
Pearson                             3
Classmate                           1
List the students who enrolled for all the books adopted by their course
SQL> select distinct regno
  2  from enroll natural join student
  3  where exists
  4  (select book_isbn
  5  from book_adoption
  6  where book_adoption.course#=enroll.course#);
REGNO
--------------------
456
101
890
123
567
789
6 rows selected.
