├── README.md ├── company.sql ├── enrollment.sql ├── insurance.sql ├── order_processing.sql ├── sailors.sql └── student.sql /README.md: -------------------------------------------------------------------------------- 1 | # JSSSTU DBMS Lab (Database Management System) 2 | 3 | ## Sailors Database 4 | 5 | 1. Find the colours of boats reserved by Albert 6 | 2. Find all sailor id’s of sailors who have a rating of at least 8 or reserved boat 103 7 | 3. Find the names of sailors who have not reserved a boat whose name contains the string “storm”. Order the names in ascending order. 8 | 4. Find the names of sailors who have reserved all boats. 9 | 5. Find the name and age of the oldest sailor. 10 | 6. For each boat which was reserved by at least 5 sailors with age >= 40, find the boat id and the average age of such sailors. 11 | 7. A view that shows names and ratings of all sailors sorted by rating in descending order. 12 | 8. Create a view that shows the names of the sailors who have reserved a boat on a given date. 13 | 9. Create a view that shows the names and colours of all the boats that have been reserved by a sailor with a specific rating. 14 | 10. A trigger that prevents boats from being deleted If they have active reservations. 15 | 11. A trigger that prevents sailors with rating less than 3 from reserving a boat. 16 | 12. A trigger that deletes all expired reservations. 17 | 18 | ## Insurance Database 19 | 20 | 1. Find the total number of people who owned cars that were involved in accidents in 2021. 21 | 2. Find the number of accidents in which the cars belonging to “Smith” were involved. 22 | 3. Add a new accident to the database; assume any values for required attributes. 23 | 4. Delete the Mazda belonging to “Smith”. 24 | 5. Update the damage amount for the car with license number “KA09MA1234” in the accident with report. 25 | 6. A view that shows models and year of cars that are involved in accident. 26 | 7. Create a view that shows name and address of drivers who own a car. 27 | 8. Create a view that shows the names of the drivers who a participated in a accident in a specific place. 28 | 9. A trigger that prevents driver with total damage amount >rs.50,000 from owning a car. 29 | 10. A trigger that prevents a driver from participating in more than 3 accidents in a given year. 30 | 31 | ## Order Processing Database 32 | 33 | 1. List the Order# and Ship\_date for all orders shipped from Warehouse# "W2". 34 | 2. List the Warehouse information from which the Customer named "Kumar" was supplied his orders. Produce a listing of Order#, Warehouse#. 35 | 3. Produce a listing: Cname, #ofOrders, Avg\_Order\_Amt, where the middle column is the total number of orders by the customer and the last column is the average order amount for that customer. (Use aggregate functions) 36 | 4. Delete all orders for customer named "Kumar". 37 | 5. Find the item with the maximum unit price. 38 | 6. A trigger that prevents warehouse details from being deleted if any item has to be shipped from that warehouse. 39 | 7. Create a view to display orderID and shipment date of all orders shipped from a warehouse 2. 40 | 8. A view that shows the warehouse name from where the kumar’s order is been shipped. 41 | 9. A tigger that updates order\_amount based on quantity and unit price of order\_item . 42 | 43 | ## Enrollment Database 44 | 45 | 1. Demonstrate how you add a new text book to the database and make this book be adopted by some department. 46 | 2. Produce a list of text books (include Course #, Book-ISBN, Book-title) in the alphabetical order for courses offered by the ‘CS’ department that use more than two books. 47 | 3. List any department that has all its adopted books published by a specific publisher. 48 | 4. List the students who have scored maximum marks in ‘DBMS’ course. 49 | 5. Create a view to display all the courses opted by a student along with marks obtained. 50 | 6. Create a view to show the enrolled details of a student. 51 | 7. Create a view to display course related books from course\_adoption and text book table using book\_ISBN. 52 | 8. Create a trigger such that it Deletes all records from enroll table when course is deleted . 53 | 9. Create a trigger that prevents a student from enrolling in a course if the marks pre\_requisit is less than the given threshold . 54 | 55 | ## Company Database 56 | 57 | 1. Make a list of all project numbers for projects that involve an employee whose last name is ‘Scott’, either as a worker or as a manager of the department that controls the project. 58 | 2. Show the resulting salaries if every employee working on the ‘IoT’ project is given a 10 percent raise. 59 | 3. Find the sum of the salaries of all employees of the ‘Accounts’ department, as well as the maximum salary, the minimum salary, and the average salary in this department 60 | 4. Retrieve the name of each employee who works on all the projects controlled by department number 5 (use NOT EXISTS operator). 61 | 5. For each department that has more than five employees, retrieve the department number and the number of its employees who are making more than Rs. 6,00,000. 62 | 6. Create a view that shows name, dept name and location of all employees. 63 | 7. Create a view that shows project name, location and dept. 64 | 8. A trigger that automatically updates manager’s start date when he is assigned . 65 | 9. Create a trigger that prevents a project from being deleted if it is currently being worked by any employee. 66 | 67 | 68 | -------------------------------------------------------------------------------- /company.sql: -------------------------------------------------------------------------------- 1 | drop database if exists company; 2 | create database company; 3 | use company; 4 | 5 | create table if not exists Employee( 6 | ssn varchar(35) primary key, 7 | name varchar(35) not null, 8 | address varchar(255) not null, 9 | sex varchar(7) not null, 10 | salary int not null, 11 | super_ssn varchar(35), 12 | d_no int, 13 | foreign key (super_ssn) references Employee(ssn) on delete set null 14 | ); 15 | 16 | create table if not exists Department( 17 | d_no int primary key, 18 | dname varchar(100) not null, 19 | mgr_ssn varchar(35), 20 | mgr_start_date date, 21 | foreign key (mgr_ssn) references Employee(ssn) on delete cascade 22 | ); 23 | 24 | create table if not exists DLocation( 25 | d_no int not null, 26 | d_loc varchar(100) not null, 27 | foreign key (d_no) references Department(d_no) on delete cascade 28 | ); 29 | 30 | create table if not exists Project( 31 | p_no int primary key, 32 | p_name varchar(25) not null, 33 | p_loc varchar(25) not null, 34 | d_no int not null, 35 | foreign key (d_no) references Department(d_no) on delete cascade 36 | ); 37 | 38 | create table if not exists WorksOn( 39 | ssn varchar(35) not null, 40 | p_no int not null, 41 | hours int not null default 0, 42 | foreign key (ssn) references Employee(ssn) on delete cascade, 43 | foreign key (p_no) references Project(p_no) on delete cascade 44 | ); 45 | 46 | INSERT INTO Employee VALUES 47 | ("01NB235", "Chandan_Krishna","Siddartha Nagar, Mysuru", "Male", 1500000, "01NB235", 5), 48 | ("01NB354", "Employee_2", "Lakshmipuram, Mysuru", "Female", 1200000,"01NB235", 2), 49 | ("02NB254", "Employee_3", "Pune, Maharashtra", "Male", 1000000,"01NB235", 4), 50 | ("03NB653", "Employee_4", "Hyderabad, Telangana", "Male", 2500000, "01NB354", 5), 51 | ("04NB234", "Employee_5", "JP Nagar, Bengaluru", "Female", 1700000, "01NB354", 1); 52 | 53 | 54 | INSERT INTO Department VALUES 55 | (001, "Human Resources", "01NB235", "2020-10-21"), 56 | (002, "Quality Assesment", "03NB653", "2020-10-19"), 57 | (003,"System assesment","04NB234","2020-10-27"), 58 | (005,"Production","02NB254","2020-08-16"), 59 | (004,"Accounts","01NB354","2020-09-4"); 60 | 61 | 62 | INSERT INTO DLocation VALUES 63 | (001, "Jaynagar, Bengaluru"), 64 | (002, "Vijaynagar, Mysuru"), 65 | (003, "Chennai, Tamil Nadu"), 66 | (004, "Mumbai, Maharashtra"), 67 | (005, "Kuvempunagar, Mysuru"); 68 | 69 | INSERT INTO Project VALUES 70 | (241563, "System Testing", "Mumbai, Maharashtra", 004), 71 | (532678, "IOT", "JP Nagar, Bengaluru", 001), 72 | (453723, "Product Optimization", "Hyderabad, Telangana", 005), 73 | (278345, "Yeild Increase", "Kuvempunagar, Mysuru", 005), 74 | (426784, "Product Refinement", "Saraswatipuram, Mysuru", 002); 75 | 76 | INSERT INTO WorksOn VALUES 77 | ("01NB235", 278345, 5), 78 | ("01NB354", 426784, 6), 79 | ("04NB234", 532678, 3), 80 | ("02NB254", 241563, 3), 81 | ("03NB653", 453723, 6); 82 | 83 | alter table Employee add constraint foreign key (d_no) references Department(d_no) on delete cascade; 84 | 85 | SELECT * FROM Department; 86 | SELECT * FROM Employee; 87 | SELECT * FROM DLocation; 88 | SELECT * FROM Project; 89 | SELECT * FROM WorksOn; 90 | 91 | 92 | -- Make a list of all project numbers for projects that involve an employee whose last name is ‘Scott’, either as a worker or as a manager of the department that controls the project. 93 | 94 | select p_no,p_name,name from Project p, Employee e where p.d_no=e.d_no and e.name like "%Krishna"; 95 | 96 | 97 | -- Show the resulting salaries if every employee working on the ‘IoT’ project is given a 10 percent raise 98 | select w.ssn,name,salary as old_salary,salary*1.1 as new_salary from WorksOn w join Employee e where w.ssn=e.ssn and w.p_no=(select p_no from Project where p_name="IOT") ; 99 | 100 | 101 | -- Find the sum of the salaries of all employees of the ‘Accounts’ department, as well as the maximum salary, the minimum salary, and the average salary in this department 102 | select sum(salary) as sal_sum, max(salary) as sal_max,min(salary) as sal_min,avg(salary) as sal_avg from Employee e join Department d on e.d_no=d.d_no where d.dname="Accounts"; 103 | 104 | 105 | -- Retrieve the name of each employee who works on all the projects controlled by department number 1 (use NOT EXISTS operator). 106 | select Employee.ssn,name,d_no from Employee where not exists 107 | (select p_no from Project p where p.d_no=1 and p_no not in 108 | (select p_no from WorksOn w where w.ssn=Employee.ssn)); 109 | 110 | 111 | -- For each department that has more than one employees, retrieve the department number and the number of its employees who are making more than Rs. 6,00,000. 112 | select d.d_no, count(*) from Department d join Employee e on e.d_no=d.d_no where salary>600000 group by d.d_no having count(*) >1; 113 | 114 | 115 | -- Create a view that shows name, dept name and location of all employees 116 | create view emp_details as 117 | select name,dname,d_loc from Employee e join Department d on e.d_no=d.d_no join DLocation dl on d.d_no=dl.d_no; 118 | 119 | select * from emp_details; 120 | 121 | -- Create a view that shows project name, location and dept. 122 | create view ProjectDetails as 123 | select p_name, p_loc, dname 124 | from Project p NATURAL JOIN Department d; 125 | 126 | select * from ProjectDetails; 127 | 128 | -- A trigger that automatically updates manager’s start date when he is assigned . 129 | 130 | DELIMITER // 131 | create trigger UpdateManagerStartDate 132 | before insert on Department 133 | for each row 134 | BEGIN 135 | SET NEW.mgr_start_date=curdate(); 136 | END;// 137 | 138 | DELIMITER ; 139 | 140 | insert into Department (d_no, dname, mgr_ssn) values 141 | (006,"R&D","01NB354"); -- This will automatically set mgr_start_date to today's date 142 | 143 | -- Create a trigger that prevents a project from being deleted if it is currently being worked by any employee. 144 | 145 | DELIMITER // 146 | create trigger PreventDelete 147 | before delete on Project 148 | for each row 149 | BEGIN 150 | IF EXISTS (select * from WorksOn where p_no=old.p_no) THEN 151 | signal sqlstate '45000' set message_text='This project has an employee assigned'; 152 | END IF; 153 | END; // 154 | 155 | DELIMITER ; 156 | 157 | delete from Project where p_no=241563; -- Will give error 158 | 159 | 160 | -------------------------------------------------------------------------------- /enrollment.sql: -------------------------------------------------------------------------------- 1 | drop database if exists enrollment; 2 | create database enrollment; 3 | use enrollment; 4 | 5 | create table Student( 6 | regno varchar(13) primary key, 7 | name varchar(25) not null, 8 | major varchar(25) not null, 9 | bdate date not null 10 | ); 11 | 12 | create table Course( 13 | course int primary key, 14 | cname varchar(30) not null, 15 | dept varchar(100) not null 16 | ); 17 | 18 | create table Enroll( 19 | regno varchar(13), 20 | course int, 21 | sem int not null, 22 | marks int not null, 23 | foreign key(regno) references Student(regno) on delete cascade, 24 | foreign key(course) references Course(course) on delete cascade 25 | ); 26 | 27 | create table TextBook( 28 | bookIsbn int not null, 29 | book_title varchar(40) not null, 30 | publisher varchar(25) not null, 31 | author varchar(25) not null, 32 | primary key(bookIsbn) 33 | ); 34 | 35 | create table BookAdoption( 36 | course int not null, 37 | sem int not null, 38 | bookIsbn int not null, 39 | foreign key(bookIsbn) references TextBook(bookIsbn) on delete cascade, 40 | foreign key(course) references Course(course) on delete cascade 41 | ); 42 | 43 | INSERT INTO Student VALUES 44 | ("01HF235", "Student_1", "CSE", "2001-05-15"), 45 | ("01HF354", "Student_2", "Literature", "2002-06-10"), 46 | ("01HF254", "Student_3", "Philosophy", "2000-04-04"), 47 | ("01HF653", "Student_4", "History", "2003-10-12"), 48 | ("01HF234", "Student_5", "Computer Economics", "2001-10-10"); 49 | 50 | INSERT INTO Course VALUES 51 | (001, "DBMS", "CS"), 52 | (002, "Literature", "English"), 53 | (003, "Philosophy", "Philosphy"), 54 | (004, "History", "Social Science"), 55 | (005, "Computer Economics", "CS"); 56 | 57 | INSERT INTO Enroll VALUES 58 | ("01HF235", 001, 5, 85), 59 | ("01HF354", 002, 6, 87), 60 | ("01HF254", 003, 3, 95), 61 | ("01HF653", 004, 3, 80), 62 | ("01HF234", 005, 5, 75); 63 | 64 | INSERT INTO TextBook VALUES 65 | (241563, "Operating Systems", "Pearson", "Silberschatz"), 66 | (532678, "Complete Works of Shakesphere", "Oxford", "Shakesphere"), 67 | (453723, "Immanuel Kant", "Delphi Classics", "Immanuel Kant"), 68 | (278345, "History of the world", "The Times", "Richard Overy"), 69 | (426784, "Behavioural Economics", "Pearson", "David Orrel"); 70 | 71 | INSERT INTO BookAdoption VALUES 72 | (001, 5, 241563), 73 | (002, 6, 532678), 74 | (003, 3, 453723), 75 | (004, 3, 278345), 76 | (001, 6, 426784); 77 | 78 | select * from Student; 79 | select * from Course; 80 | select * from Enroll; 81 | select * from BookAdoption; 82 | select * from TextBook; 83 | 84 | 85 | 86 | -- Demonstrate how you add a new text book to the database and make this book be adopted by some department. 87 | insert into TextBook values 88 | (123456, "Chandan The Autobiography", "Pearson", "Chandan"); 89 | 90 | insert into BookAdoption values 91 | (001, 5, 123456); 92 | 93 | 94 | -- Produce a list of text books (include Course #, Book-ISBN, Book-title) in the alphabetical order for courses offered by the ‘CS’ department that use more than two books. 95 | SELECT c.course,t.bookIsbn,t.book_title 96 | FROM Course c,BookAdoption ba,TextBook t 97 | WHERE c.course=ba.course 98 | AND ba.bookIsbn=t.bookIsbn 99 | AND c.dept='CS' 100 | AND 2<( 101 | SELECT COUNT(bookIsbn) 102 | FROM BookAdoption b 103 | WHERE c.course=b.course) 104 | ORDER BY t.book_title; 105 | 106 | 107 | -- List any department that has all its adopted books published by a specific publisher. 108 | SELECT DISTINCT c.dept 109 | FROM Course c 110 | WHERE c.dept IN 111 | ( SELECT c.dept 112 | FROM Course c,BookAdoption b,TextBook t 113 | WHERE c.course=b.course 114 | AND t.bookIsbn=b.bookIsbn 115 | AND t.publisher='PEARSON') 116 | AND c.dept NOT IN 117 | ( SELECT c.dept 118 | FROM Course c, BookAdoption b, TextBook t 119 | WHERE c.course=b.course 120 | AND t.bookIsbn=b.bookIsbn 121 | AND t.publisher!='PEARSON'); 122 | 123 | 124 | -- List the students who have scored maximum marks in ‘DBMS’ course. 125 | 126 | select name from Student s, Enroll e, Course c 127 | where s.regno=e.regno and e.course=c.course and c.cname="DBMS" and e.marks in (select max(marks) from Enroll e1, Course c1 where c1.cname="DBMS" and c1.course=e1.course); 128 | 129 | 130 | -- Create a view to display all the courses opted by a student along with marks obtained. 131 | create view CoursesOptedByStudent as 132 | select c.cname, e.marks from Course c, Enroll e 133 | where e.course=c.course and e.regno="01HF235"; 134 | 135 | select * from CoursesOptedByStudent; 136 | 137 | 138 | -- Create a view to show the enrolled details of a student. 139 | create view StudentEnrollmentDetails as 140 | select * from Enroll 141 | where regno="01HF235"; 142 | 143 | select * from StudentEnrollmentDetails; 144 | 145 | -- Create a view to display course related books from course_adoption and text book table using book_ISBN. 146 | create view CourseRelatedBooks as 147 | select cname, book_title 148 | from Course c, TextBook tb, BookAdoption ba 149 | where c.course=ba.course and tb.bookIsbn=ba.bookIsbn; 150 | 151 | select * from CourseRelatedBooks; 152 | 153 | -- Create a trigger such that it Deletes all records from enroll table when course is deleted 154 | DELIMITER // 155 | create or replace trigger DeleteRecords 156 | after delete on Course 157 | for each row 158 | BEGIN 159 | DELETE FROM Enroll where Enroll.course=OLD.course; 160 | END;// 161 | 162 | DELIMITER ; 163 | 164 | delete from Course where course=2; -- Will also delete records from Enroll table 165 | 166 | -- Create a trigger that prevents a student from enrolling in a course if the marks pre_requisit is less than the given threshold 167 | DELIMITER // 168 | create or replace trigger PreventEnrollment 169 | before insert on Enroll 170 | for each row 171 | BEGIN 172 | IF (new.marks<10) THEN 173 | signal sqlstate '45000' set message_text='Marks below threshold'; 174 | END IF; 175 | END;// 176 | 177 | DELIMITER ; 178 | 179 | INSERT INTO Enroll VALUES 180 | ("01HF235", 002, 5, 5); -- Gives error since marks is less than 10 181 | -------------------------------------------------------------------------------- /insurance.sql: -------------------------------------------------------------------------------- 1 | DROP DATABASE IF EXISTS insurance; 2 | CREATE DATABASE insurance; 3 | USE insurance; 4 | 5 | CREATE TABLE IF NOT EXISTS person ( 6 | driver_id VARCHAR(255) NOT NULL, 7 | driver_name TEXT NOT NULL, 8 | address TEXT NOT NULL, 9 | PRIMARY KEY (driver_id) 10 | ); 11 | 12 | CREATE TABLE IF NOT EXISTS car ( 13 | reg_no VARCHAR(255) NOT NULL, 14 | model TEXT NOT NULL, 15 | c_year INTEGER, 16 | PRIMARY KEY (reg_no) 17 | ); 18 | 19 | CREATE TABLE IF NOT EXISTS accident ( 20 | report_no INTEGER NOT NULL, 21 | accident_date DATE, 22 | location TEXT, 23 | PRIMARY KEY (report_no) 24 | ); 25 | 26 | CREATE TABLE IF NOT EXISTS owns ( 27 | driver_id VARCHAR(255) NOT NULL, 28 | reg_no VARCHAR(255) NOT NULL, 29 | FOREIGN KEY (driver_id) REFERENCES person(driver_id) ON DELETE CASCADE, 30 | FOREIGN KEY (reg_no) REFERENCES car(reg_no) ON DELETE CASCADE 31 | ); 32 | 33 | CREATE TABLE IF NOT EXISTS participated ( 34 | driver_id VARCHAR(255) NOT NULL, 35 | reg_no VARCHAR(255) NOT NULL, 36 | report_no INTEGER NOT NULL, 37 | damage_amount FLOAT NOT NULL, 38 | FOREIGN KEY (driver_id) REFERENCES person(driver_id) ON DELETE CASCADE, 39 | FOREIGN KEY (reg_no) REFERENCES car(reg_no) ON DELETE CASCADE, 40 | FOREIGN KEY (report_no) REFERENCES accident(report_no) 41 | ); 42 | 43 | INSERT INTO person VALUES 44 | ("D111", "Driver_1", "Kuvempunagar, Mysuru"), 45 | ("D222", "Smith", "JP Nagar, Mysuru"), 46 | ("D333", "Driver_3", "Udaygiri, Mysuru"), 47 | ("D444", "Driver_4", "Rajivnagar, Mysuru"), 48 | ("D555", "Driver_5", "Vijayanagar, Mysore"); 49 | 50 | INSERT INTO car VALUES 51 | ("KA-20-AB-4223", "Swift", 2020), 52 | ("KA-20-BC-5674", "Mazda", 2017), 53 | ("KA-21-AC-5473", "Alto", 2015), 54 | ("KA-21-BD-4728", "Triber", 2019), 55 | ("KA-09-MA-1234", "Tiago", 2018); 56 | 57 | INSERT INTO accident VALUES 58 | (43627, "2020-04-05", "Nazarbad, Mysuru"), 59 | (56345, "2019-12-16", "Gokulam, Mysuru"), 60 | (63744, "2020-05-14", "Vijaynagar, Mysuru"), 61 | (54634, "2019-08-30", "Kuvempunagar, Mysuru"), 62 | (65738, "2021-01-21", "JSS Layout, Mysuru"), 63 | (66666, "2021-01-21", "JSS Layout, Mysuru"); 64 | 65 | INSERT INTO owns VALUES 66 | ("D111", "KA-20-AB-4223"), 67 | ("D222", "KA-20-BC-5674"), 68 | ("D333", "KA-21-AC-5473"), 69 | ("D444", "KA-21-BD-4728"), 70 | ("D222", "KA-09-MA-1234"); 71 | 72 | INSERT INTO participated VALUES 73 | ("D111", "KA-20-AB-4223", 43627, 20000), 74 | ("D222", "KA-20-BC-5674", 56345, 49500), 75 | ("D333", "KA-21-AC-5473", 63744, 15000), 76 | ("D444", "KA-21-BD-4728", 54634, 5000), 77 | ("D222", "KA-09-MA-1234", 65738, 25000); 78 | 79 | 80 | 81 | -- Find the total number of people who owned a car that were involved in accidents in 2021 82 | 83 | select COUNT(driver_id) 84 | from participated p, accident a 85 | where p.report_no=a.report_no and a.accident_date like "2021%"; 86 | 87 | -- Find the number of accident in which cars belonging to smith were involved 88 | 89 | select COUNT(distinct a.report_no) 90 | from accident a 91 | where exists 92 | (select * from person p, participated ptd where p.driver_id=ptd.driver_id and p.driver_name="Smith" and a.report_no=ptd.report_no); 93 | 94 | -- Add a new accident to the database 95 | 96 | insert into accident values 97 | (45562, "2024-04-05", "Mandya"); 98 | 99 | insert into participated values 100 | ("D222", "KA-21-BD-4728", 45562, 50000); 101 | 102 | 103 | -- Delete the Mazda belonging to Smith 104 | 105 | delete from car 106 | where model="Mazda" and reg_no in 107 | (select car.reg_no from person p, owns o where p.driver_id=o.driver_id and o.reg_no=car.reg_no and p.driver_name="Smith"); 108 | 109 | 110 | -- Update the damage amount for the car with reg_no of KA-09-MA-1234 in the accident with report_no 65738 111 | 112 | update participated set damage_amount=10000 where report_no=65738 and reg_no="KA-09-MA-1234"; 113 | 114 | -- View that shows models and years of car that are involved in accident 115 | 116 | create view CarsInAccident as 117 | select distinct model, c_year 118 | from car c, participated p 119 | where c.reg_no=p.reg_no; 120 | 121 | select * from CarsInAccident; 122 | 123 | -- Create a view that shows name and address of drivers who own a car. 124 | 125 | create view DriversWithCar as 126 | select driver_name, address 127 | from person p, owns o 128 | where p.driver_id=o.driver_id; 129 | 130 | select * from DriversWithCar; 131 | 132 | 133 | -- Create a view that shows the names of the drivers who a participated in a accident in a specific place. 134 | 135 | create view DriversWithAccidentInPlace as 136 | select driver_name 137 | from person p, accident a, participated ptd 138 | where p.driver_id = ptd.driver_id and a.report_no = ptd.report_no and a.location="Vijaynagar, Mysuru"; 139 | 140 | select * from DriversWithAccidentInPlace; 141 | 142 | -- Trigger that prevents a driver with total_damage_amount greater than Rs. 50,000 from owning a car 143 | 144 | delimiter // 145 | create or replace trigger PreventOwnership 146 | before insert on owns 147 | for each row 148 | begin 149 | if new.driver_id in (select driver_id from participated group by driver_id 150 | having sum(damage_amount) >= 50000) then 151 | signal sqlstate '45000' set message_text = 'Damage Greater than Rs.50,000'; 152 | end if; 153 | end;// 154 | 155 | delimiter ; 156 | 157 | insert into owns VALUES 158 | ("D222", "KA-21-AC-5473"); -- Will give error since total damage amount of D222 exceeds 50k 159 | 160 | -- A trigger that prevents a driver from participating in more than 2 accidents in a given year. 161 | 162 | DELIMITER // 163 | create trigger PreventParticipation 164 | before insert on participated 165 | for each row 166 | BEGIN 167 | IF 2<=(select count(*) from participated where driver_id=new.driver_id) THEN 168 | signal sqlstate '45000' set message_text='Driver has already participated in 2 accidents'; 169 | END IF; 170 | END;// 171 | DELIMITER ; 172 | 173 | INSERT INTO participated VALUES 174 | ("D222", "KA-20-AB-4223", 66666, 20000); 175 | 176 | 177 | 178 | 179 | 180 | 181 | 182 | 183 | 184 | 185 | 186 | 187 | 188 | 189 | 190 | -------------------------------------------------------------------------------- /order_processing.sql: -------------------------------------------------------------------------------- 1 | drop database if exists order_processing; 2 | create database order_processing; 3 | use order_processing; 4 | 5 | create table if not exists Customers ( 6 | cust_id int primary key, 7 | cname varchar(35) not null, 8 | city varchar(35) not null 9 | ); 10 | 11 | create table if not exists Orders ( 12 | order_id int primary key, 13 | odate date not null, 14 | cust_id int, 15 | order_amt int not null, 16 | foreign key (cust_id) references Customers(cust_id) on delete cascade 17 | ); 18 | 19 | create table if not exists Items ( 20 | item_id int primary key, 21 | unitprice int not null 22 | ); 23 | 24 | create table if not exists OrderItems ( 25 | order_id int not null, 26 | item_id int not null, 27 | qty int not null, 28 | foreign key (order_id) references Orders(order_id) on delete cascade, 29 | foreign key (item_id) references Items(item_id) on delete cascade 30 | ); 31 | 32 | create table if not exists Warehouses ( 33 | warehouse_id int primary key, 34 | city varchar(35) not null 35 | ); 36 | 37 | create table if not exists Shipments ( 38 | order_id int not null, 39 | warehouse_id int not null, 40 | ship_date date not null, 41 | foreign key (order_id) references Orders(order_id) on delete cascade, 42 | foreign key (warehouse_id) references Warehouses(warehouse_id) on delete cascade 43 | ); 44 | 45 | INSERT INTO Customers VALUES 46 | (0001, "Customer_1", "Mysuru"), 47 | (0002, "Customer_2", "Bengaluru"), 48 | (0003, "Kumar", "Mumbai"), 49 | (0004, "Customer_4", "Dehli"), 50 | (0005, "Customer_5", "Bengaluru"); 51 | 52 | INSERT INTO Orders VALUES 53 | (001, "2020-01-14", 0001, 2000), 54 | (002, "2021-04-13", 0002, 500), 55 | (003, "2019-10-02", 0003, 2500), 56 | (004, "2019-05-12", 0005, 1000), 57 | (005, "2020-12-23", 0004, 1200); 58 | 59 | INSERT INTO Items VALUES 60 | (0001, 400), 61 | (0002, 200), 62 | (0003, 1000), 63 | (0004, 100), 64 | (0005, 500); 65 | 66 | INSERT INTO Warehouses VALUES 67 | (0001, "Mysuru"), 68 | (0002, "Bengaluru"), 69 | (0003, "Mumbai"), 70 | (0004, "Dehli"), 71 | (0005, "Chennai"); 72 | 73 | INSERT INTO OrderItems VALUES 74 | (001, 0001, 5), 75 | (002, 0005, 1), 76 | (003, 0005, 5), 77 | (004, 0003, 1), 78 | (005, 0004, 12); 79 | 80 | INSERT INTO Shipments VALUES 81 | (001, 0002, "2020-01-16"), 82 | (002, 0001, "2021-04-14"), 83 | (003, 0004, "2019-10-07"), 84 | (004, 0003, "2019-05-16"), 85 | (005, 0005, "2020-12-23"); 86 | 87 | 88 | SELECT * FROM Customers; 89 | SELECT * FROM Orders; 90 | SELECT * FROM OrderItems; 91 | SELECT * FROM Items; 92 | SELECT * FROM Shipments; 93 | SELECT * FROM Warehouses; 94 | 95 | 96 | -- List the Order# and Ship_date for all orders shipped from Warehouse# "0001". 97 | select order_id,ship_date from Shipments where warehouse_id=0001; 98 | 99 | -- List the Warehouse information from which the Customer named "Kumar" was supplied his orders. Produce a listing of Order#, Warehouse# 100 | select order_id,warehouse_id from Warehouses natural join Shipments where order_id in (select order_id from Orders where cust_id in (Select cust_id from Customers where cname like "%Kumar%")); 101 | 102 | -- Produce a listing: Cname, #ofOrders, Avg_Order_Amt, where the middle column is the total number of orders by the customer and the last column is the average order amount for that customer. (Use aggregate functions) 103 | select cname, COUNT(*) as no_of_orders, AVG(order_amt) as avg_order_amt 104 | from Customers c, Orders o 105 | where c.cust_id=o.cust_id 106 | group by cname; 107 | 108 | -- Find the item with the maximum unit price. 109 | select max(unitprice) from Items; 110 | 111 | -- Create a view to display orderID and shipment date of all orders shipped from a warehouse 2. 112 | 113 | create view ShipmentDatesFromWarehouse2 as 114 | select order_id, ship_date 115 | from Shipments 116 | where warehouse_id=2; 117 | 118 | select * from ShipmentDatesFromWarehouse2; 119 | 120 | -- A view that shows the warehouse ids from where the kumar’s orders are being shipped. 121 | 122 | create view WharehouseWithKumarOrders as 123 | select s.warehouse_id 124 | from Warehouses w, Customers c, Orders o, Shipments s 125 | where w.warehouse_id = s.warehouse_id and s.order_id=o.order_id and o.cust_id=c.cust_id and c.cname="Kumar"; 126 | 127 | select * from WharehouseWithKumarOrders; 128 | 129 | -- Delete all orders for customer named "Kumar". 130 | delete from Orders where cust_id = (select cust_id from Customers where cname like "%Kumar%"); 131 | 132 | 133 | -- Trigger that prevents warehouse details from being deleted if any item has to be shipped from that warehouse 134 | 135 | DELIMITER $$ 136 | CREATE TRIGGER PreventWarehouseDelete 137 | BEFORE DELETE ON Warehouses 138 | FOR EACH ROW 139 | BEGIN 140 | IF OLD.warehouse_id IN (SELECT warehouse_id FROM Shipments NATURAL JOIN Warehouses) THEN 141 | SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = 'An item has to be shipped from this warehouse!'; 142 | END IF; 143 | END; 144 | $$ 145 | DELIMITER ; 146 | 147 | 148 | DELETE FROM Warehouses WHERE warehouse_id = 2; -- Will give error since an item has to be shipped from warehouse 2 149 | 150 | 151 | -- A tigger that updates order_amount based on quantity and unit price of order_item 152 | 153 | DELIMITER $$ 154 | create trigger UpdateOrderAmt 155 | after insert on OrderItems 156 | for each row 157 | BEGIN 158 | update Orders set order_amt=(new.qty*(select distinct unitprice from Items NATURAL JOIN OrderItems where item_id=new.item_id)) where Orders.order_id=new.order_id; 159 | END; $$ 160 | DELIMITER ; 161 | 162 | INSERT INTO Orders VALUES 163 | (006, "2020-12-23", 0004, 1200); 164 | 165 | INSERT INTO OrderItems VALUES 166 | (006, 0001, 5); -- This will automatically update the Orders Table also 167 | 168 | select * from Orders; 169 | -------------------------------------------------------------------------------- /sailors.sql: -------------------------------------------------------------------------------- 1 | drop database if exists sailors; 2 | 3 | create database sailors; 4 | use sailors; 5 | 6 | create table if not exists Sailors( 7 | sid int primary key, 8 | sname varchar(35) not null, 9 | rating float not null, 10 | age int not null 11 | ); 12 | 13 | create table if not exists Boat( 14 | bid int primary key, 15 | bname varchar(35) not null, 16 | color varchar(25) not null 17 | ); 18 | 19 | create table if not exists reserves( 20 | sid int not null, 21 | bid int not null, 22 | sdate date not null, 23 | foreign key (sid) references Sailors(sid) on delete cascade, 24 | foreign key (bid) references Boat(bid) on delete cascade 25 | ); 26 | 27 | insert into Sailors values 28 | (1,"Albert", 5.0, 40), 29 | (2, "Nakul", 5.0, 49), 30 | (3, "Darshan", 9, 18), 31 | (4, "Astorm Gowda", 2, 68), 32 | (5, "Armstormin", 7, 19); 33 | 34 | 35 | insert into Boat values 36 | (1,"Boat_1", "Green"), 37 | (2,"Boat_2", "Red"), 38 | (103,"Boat_3", "Blue"); 39 | 40 | insert into reserves values 41 | (1,103,"2023-01-01"), 42 | (1,2,"2023-02-01"), 43 | (2,1,"2023-02-05"), 44 | (3,2,"2023-03-06"), 45 | (5,103,"2023-03-06"), 46 | (1,1,"2023-03-06"); 47 | 48 | select * from Sailors; 49 | select * from Boat; 50 | select * from reserves; 51 | 52 | -- Find the colours of the boats reserved by Albert 53 | select color 54 | from Sailors s, Boat b, reserves r 55 | where s.sid=r.sid and b.bid=r.bid and s.sname="Albert"; 56 | 57 | -- Find all the sailor sids who have rating atleast 8 or reserved boat 103 58 | 59 | (select sid 60 | from Sailors 61 | where Sailors.rating>=8) 62 | UNION 63 | (select sid 64 | from reserves 65 | where reserves.bid=103); 66 | 67 | 68 | -- Find the names of the sailor who have not reserved a boat whose name contains the string "storm". Order the name in the ascending order 69 | 70 | select s.sname 71 | from Sailors s 72 | where s.sid not in 73 | (select s1.sid from Sailors s1, reserves r1 where r1.sid=s1.sid and s1.sname like "%storm%") 74 | and s.sname like "%storm%" 75 | order by s.sname ASC; 76 | 77 | -- Find the name of the sailors who have reserved all boats 78 | 79 | select sname from Sailors s where not exists 80 | (select * from Boat b where not exists 81 | (select * from reserves r where r.sid=s.sid and b.bid=r.bid)); 82 | 83 | 84 | -- Find the name and age of the oldest sailor 85 | 86 | select sname, age 87 | from Sailors where age in (select max(age) from Sailors); 88 | 89 | -- For each boat which was reserved by atleast 2 sailors with age >= 40, find the bid and average age of such sailors 90 | 91 | select b.bid, avg(s.age) as average_age 92 | from Sailors s, Boat b, reserves r 93 | where r.sid=s.sid and r.bid=b.bid and s.age>=40 94 | group by bid 95 | having 2<=count(distinct r.sid); 96 | 97 | -- A view that shows names and ratings of all sailors sorted by rating in descending order\ 98 | 99 | create view NamesAndRating as 100 | select sname, rating 101 | from Sailors 102 | order by rating DESC; 103 | 104 | select * from NamesAndRating; 105 | 106 | -- Create a view that shows the names of the sailors who have reserved a boat on a given date. 107 | 108 | create view SailorsWithReservation as 109 | select sname 110 | from Sailors s, reserves r 111 | where r.sid=s.sid and r.sdate="2023-03-06"; 112 | 113 | select * from SailorsWithReservation; 114 | 115 | -- Create a view that shows the names and colours of all the boats that have been reserved by a sailor with a specific rating. 116 | 117 | create view ReservedBoatsWithRatedSailor as 118 | select distinct bname, color 119 | from Sailors s, Boat b, reserves r 120 | where s.sid=r.sid and b.bid=r.bid and s.rating=5; 121 | 122 | select * from ReservedBoatsWithRatedSailor; 123 | 124 | 125 | -- Trigger that prevents boats from being deleted if they have active reservation 126 | 127 | DELIMITER // 128 | create or replace trigger CheckAndDelete 129 | before delete on Boat 130 | for each row 131 | BEGIN 132 | IF EXISTS (select * from reserves where reserves.bid=old.bid) THEN 133 | SIGNAL SQLSTATE '45000' SET message_text='Boat is reserved and hence cannot be deleted'; 134 | END IF; 135 | END;// 136 | 137 | DELIMITER ; 138 | 139 | delete from Boat where bid=103; -- This gives error since boat 103 is reserved 140 | 141 | 142 | -- A trigger that prevents sailors with rating less than 3 from reserving a boat. 143 | 144 | 145 | DELIMITER // 146 | create trigger BlockReservation 147 | before insert on reserves 148 | for each row 149 | BEGIN 150 | IF EXISTS (select * from Sailors where sid=new.sid and rating<3) THEN 151 | signal sqlstate '45000' set message_text='Sailor rating less than 3'; 152 | END IF; 153 | END;// 154 | 155 | DELIMITER ; 156 | 157 | insert into reserves values 158 | (4,2,"2023-10-01"); -- Will give error since sailor rating is less than 3 159 | 160 | 161 | -- A trigger that deletes all expired reservations. 162 | 163 | create table TempTable ( 164 | last_deleted_date date primary key 165 | ); -- Temporary table to be used in DeleteExpiredReservations Table 166 | 167 | DELIMITER // 168 | create trigger DeleteExpiredReservations 169 | before insert on TempTable 170 | for each row 171 | BEGIN 172 | delete from reserves where sdate