## Week 7 - DBMS Lab - PL SQL & Triggers ### Q1. Generate a trigger displaying driver information, on participating in an accident. Trigger: ```sql CREATE OR REPLACE TRIGGER trg_display_driver_info AFTER INSERT ON participated FOR EACH ROW DECLARE v_driver_name VARCHAR2(100); v_driver_address VARCHAR2(255); BEGIN SELECT NAME, ADDRESS INTO v_driver_name, v_driver_address FROM person WHERE DRIVER_ID# = :NEW.DRIVER_ID#; DBMS_OUTPUT.PUT_LINE('Driver ID: ' || :NEW.DRIVER_ID#); DBMS_OUTPUT.PUT_LINE('Driver Name: ' || v_driver_name); DBMS_OUTPUT.PUT_LINE('Driver Address: ' || v_driver_address); DBMS_OUTPUT.PUT_LINE('Car Registration Number: ' || :NEW.REGNO); DBMS_OUTPUT.PUT_LINE('Report Number: ' || :NEW.REPORT_NUMBER); DBMS_OUTPUT.PUT_LINE('Damage Amount: ' || :NEW.DAMAGE_AMOUNT); END; / ``` Demo: ```sql SQL> INSERT INTO participated (DRIVER_ID#, REGNO, REPORT_NUMBER, DAMAGE_AMOUNT) 2 VALUES (1235, 'EFGH2001', 3, 5000); Driver ID: 1235 Driver Name: Rohit Driver Address: Banglalore India Car Registration Number: EFGH2001 Report Number: 3 Damage Amount: 5000 Driver_id: 1235 Name: Rohit Address: Banglalore India 1 row created. ``` ### Q2. Create a trigger that updates a `total_damage` column in the `accident` table whenever a new entry is added to or removed from the participated field.` Trigger: ```SQL SQL> CREATE OR REPLACE TRIGGER update_total_damage 2 AFTER 3 INSERT OR DELETE ON PARTICIPATED 4 BEGIN 5 UPDATE ACCIDENT 6 SET 7 total_damage = ( 8 SELECT 9 SUM(damage_amount) 10 FROM PARTICIPATED p 11 WHERE 12 p.report_number = ACCIDENT.report_number 13 ); 14 END; 15 / Trigger created. ``` Adding an identifier `total_damage`: ```sql SQL> ALTER TABLE ACCIDENT ADD total_damage NUMBER; ``` Test case with Insertion: ```sql SQL> INSERT INTO PARTICIPATED (driver_id#, regno, report_number, damage_amount) VALUES ('1235', 'EFGH2001', 1, 5000); Driver_id: 1235 Name: Rohit Address: Banglalore India 1 row created. SQL> SELECT report_number, total_damage FROM ACCIDENT WHERE report_number = 1; REPORT_NUMBER TOTAL_DAMAGE ------------- ------------ 1 15000 ``` Test case with Deletion: ```sql SQL> DELETE FROM PARTICIPATED WHERE driver_id# = '1235' AND regno = 'EFGH2001' AND report_number = 1; 1 row deleted. SQL> SELECT report_number, total_damage FROM ACCIDENT WHERE report_number = 1; REPORT_NUMBER TOTAL_DAMAGE ------------- ------------ 1 10000 ``` ### Q3. List cars involved in accidents with cumulative damage exceeding a specific amount. Checking for damage amount > 10000, we have ```SQL SQL> SELECT p.driver_id#, o.regno, SUM(pa.damage_amount) AS total_damage FROM PARTICIPATED pa JOIN OWNS o ON pa.driver_id# = o.driver_id# JOIN PERSON p ON o.driver_id# = p.driver_id# GROUP BY p.driver_id#, o.regno HAVING SUM(pa.damage_amount) > 10000; DRIVER_ID# REGNO TOTAL_DAMAGE ------------------------------ -------------------- ------------ 1238 HFSP5601 26500 ``` ### Q4. Identify cars that have been involved in more than one accident and calculate the total damage for each car. ```SQL SQL> SELECT o.regno, COUNT(DISTINCT pa.report_number) AS accident_count, SUM(pa.damage_amount) AS total_damage FROM PARTICIPATED pa JOIN OWNS o ON pa.driver_id# = o.driver_id# GROUP BY o.regno HAVING COUNT(DISTINCT pa.report_number) > 1; REGNO ACCIDENT_COUNT TOTAL_DAMAGE -------------------- -------------- ------------ HFSP5601 2 26500 ``` ### Q5. Calculate the average damage amount for accidents at each location. ```sql SQL> SELECT a.location, AVG(pa.damage_amount) AS average_damage FROM ACCIDENT a JOIN PARTICIPATED pa ON a.report_number = pa.report_number GROUP BY a.location; LOCATION AVERAGE_DAMAGE -------------------------------------------------- -------------- karnataka India 25000 Delhi India 10000 India 2575 Gujrat India 1500 ```