145 lines
		
	
	
		
			No EOL
		
	
	
		
			3.8 KiB
		
	
	
	
		
			Markdown
		
	
	
	
	
	
			
		
		
	
	
			145 lines
		
	
	
		
			No EOL
		
	
	
		
			3.8 KiB
		
	
	
	
		
			Markdown
		
	
	
	
	
	
| ### 1. Create a function to return total number of accidents happened in a particular year.
 | |
| 
 | |
| ```SQL
 | |
| 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.
 | |
| ```SQL
 | |
| CREATE OR REPLACE PROCEDURE tot_damage
 | |
|     (driver IN VARCHAR2, year IN NUMBER) IS
 | |
|     damage NUMBER := 0;
 | |
| BEGIN
 | |
|     SELECT NVL(SUM(pa.DAMAGE_AMOUNT), 0) INTO damage
 | |
|     FROM participated pa
 | |
|     JOIN accident ac ON pa.REPORT_NUMBER = ac.REPORT_NUMBER
 | |
|     WHERE pa.DRIVER_ID# = driver
 | |
|       AND EXTRACT(YEAR FROM ac.ACCD_DATE) = year;
 | |
| 
 | |
|     DBMS_OUTPUT.PUT_LINE('Total damage: ' || damage);
 | |
| 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
 | |
| 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
 | |
| SQL> CREATE OR REPLACE PROCEDURE accident_info(location_value IN VARCHAR2) 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: ' || TO_CHAR(accident_rec.ACCD_DATE, 'DD-MON-YYYY') || 
 | |
|                              ', Location: ' || accident_rec.LOCATION);
 | |
|     END LOOP;
 | |
| END;
 | |
| /
 | |
| 
 | |
| ```
 | |
| ```sql
 | |
| 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
 | |
| SQL> 
 | |
| CREATE OR REPLACE PROCEDURE GetDriversWithoutAccidents AS
 | |
| BEGIN
 | |
|     FOR rec IN (
 | |
|         SELECT p.driver_id#, p.name, p.address
 | |
|         FROM person p
 | |
|         LEFT JOIN participated pa ON p.driver_id# = pa.driver_id#
 | |
|         WHERE pa.report_number IS NULL
 | |
|     ) LOOP
 | |
|         DBMS_OUTPUT.PUT_LINE('driver id: ' || rec.driver_id# ||
 | |
|                              ', name: ' || rec.name ||
 | |
|                              ', address: ' || rec.address);
 | |
|     END LOOP;
 | |
| END;
 | |
| /
 | |
| 
 | |
| ```
 | |
| ```SQL
 | |
| SQL> EXEC GetDriversWithoutAccidents;
 | |
| Driver ID: 1237, Name: Saarthak, Address: Manipal India
 | |
| Driver ID: 1235, Name: Rohit, Address: Banglalore India
 | |
| 
 | |
| PL/SQL procedure successfully completed.
 | |
| ```
 | |
| 
 | |
| Q5. Write a function that takes a REGNO as input and returns the total number of accidents in which the car was involved
 | |
| ```sql
 | |
| SQL> 
 | |
| CREATE OR REPLACE FUNCTION gettotalaccidentsbyregno(p_regno IN VARCHAR2)
 | |
| RETURN NUMBER
 | |
| IS
 | |
|     v_total_accidents NUMBER := 0; -- Initialize to 0
 | |
| BEGIN
 | |
|     SELECT COUNT(*)
 | |
|     INTO v_total_accidents
 | |
|     FROM participated
 | |
|     WHERE REGNO = p_regno;
 | |
| 
 | |
|     RETURN v_total_accidents;
 | |
| EXCEPTION
 | |
|     WHEN OTHERS THEN
 | |
|         RETURN 0; -- Return 0 for any error
 | |
| END;
 | |
| /
 | |
| 
 | |
| ```
 | |
| ```SQL
 | |
| SQL> SELECT GetTotalAccidentsByRegno('ABCD0001') AS Total_Accidents
 | |
|     FROM dual;
 | |
| 
 | |
| TOTAL_ACCIDENTS
 | |
| ---------------
 | |
|               1
 | |
| ```
 | |
| ```SQL
 | |
| SQL> SELECT c.REGNO, GetTotalAccidentsByRegno(c.REGNO) AS Total_Accidents
 | |
|     FROM car c;
 | |
| 
 | |
| REGNO                TOTAL_ACCIDENTS
 | |
| -------------------- ---------------
 | |
| ABCD0001                           1
 | |
| ABCD4001                           0
 | |
| DSDS0001                           1
 | |
| EFGH2001                           0
 | |
| HFSP5601                           2
 | |
| ``` | 
