2.8 KiB

1. Create a function to return total number of accidents happened in a particular year.

SQL> create or replace function total_accd
    (year in int)
    return int
    as
    total int;
    begin
    select count(report_number)
    into total
    from accident
    where extract(year from accd_date)=year;
    return total;
    end;
    /

Function created.

SQL> select total_accd(2024) from dual;

TOTAL_ACCD(2024)
----------------
               2

2. Create a procedure to display total damage caused due to an accident for a particular driver on a specific year.

create or replace procedure tot_damage
  (driver in varchar2, year in number) is
  damage number := 0;  
begin
  select sum(damage_amount) into damage
  from participated pa
  natural join accident ac
  where pa."driver_id#" = driver  
  with quotes
    and extract(year from ac.accd_date) = year;

  dbms_output.put_line('total damage: ' || nvl(damage, 0));
exception
  when no_data_found then
    dbms_output.put_line('no data found for the given driver and year.');
  when others then
    dbms_output.put_line('an error occurred: ' || sqlerrm);
end;
/
SQL> execute tot_damage('1236',2024);
Total damage: 150

PL/SQL procedure successfully completed.

3. Create a procedure to display accident information which took place in a particular location.

SQL> create or replace procedure accident_info(location_value in varchar) IS
  begin
        for accident_rec in
       (select * from accident where location = location_value) loop
            dbms_output.put_line('Report Number: ' || accident_rec.report_number || ', Date: ' || accident_rec.accd_date || ', Location: ' || accident_rec.location);
       end loop;
    end;
    /
SQL> execute accident_info('Delhi India');
Report Number: 1, Date: 01-JAN-24, Location: Delhi India

PL/SQL procedure successfully completed.

4. Create a procedure to identify all drivers who have never been involved in any accidents. The procedure should return their driver-id, name, and address.

SQL> CREATE OR REPLACE PROCEDURE GetDriversWithoutAccidents AS
  2  BEGIN
  3      FOR rec IN (
  4          SELECT p.DRIVER_ID#, p.NAME, p.ADDRESS
  5          FROM person p
  6          LEFT JOIN participated pa ON p.DRIVER_ID# = pa.DRIVER_ID#
  7          WHERE pa.REPORT_NUMBER IS NULL
  8      ) LOOP
  9          DBMS_OUTPUT.PUT_LINE('Driver ID: ' || rec.DRIVER_ID# ||

 10                               ', Name: ' || rec.NAME ||
 11                               ', Address: ' || rec.ADDRESS);
 12      END LOOP;
 13  END;
 14  /

Procedure created.
SQL> EXEC GetDriversWithoutAccidents;
Driver ID: 1237, Name: Saarthak, Address: Manipal India
Driver ID: 1235, Name: Rohit, Address: Banglalore India

PL/SQL procedure successfully completed.