├── Oracle-SQL-PL-SQL - A Brief Introduction.pdf └── README.md /Oracle-SQL-PL-SQL - A Brief Introduction.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/sihatafnan/Solutions-to-Exercises-of-A-Brief-Introduction-to-Oracle-SQL-PL-SQL/HEAD/Oracle-SQL-PL-SQL - A Brief Introduction.pdf -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | A brief Introduction to Oracle-SQL-PL SQL,taught in our CSE216 Database Sessional course, is a SQL practice book written by [Prof. Sukarna Barua](https://cse.buet.ac.bd/faculty/facdetail.php?id=sukarnabarua).The book contains most of the fundamental sql queries using join,subquery,group by,set operation,pl-sql etc.There are 11 chapters in total and several exercises follows.All the exercises are based on HR schema of `ORACLE`. 2 | 3 | First , Let's look at the overview of HR schema 4 | 5 | ![hr_schema](https://static.webucator.com/materials/manuals/courseware-oracle/hr-ed-with-labels.png) 6 | 7 | In this repository,You won't find solutions to all the exercises but you will find what you need.I have left out those ones which are too easy or similar to the ones I listed here or is easily doable by looking at the examples of this book. 8 | 9 | ## Chapter 3: Use of Oracle Single Row Functions 10 | ### 3.3b 11 | ``` 12 | Suppose you need to find the number of days each employee worked during the first 13 | month of his joining. Write an SQL query to find this information for all employees 14 | ``` 15 | ```sql 16 | SELECT 30+MOD(EXTRACT(MONTH FROM HIRE_DATE),2) 17 | - 18 | EXTRACT(DAY FROM HIRE_DATE) as day_worked_join_month from EMPLOYEES; 19 | ``` 20 | ### 3.5 21 | ``` 22 | Print hire dates of all employees in the following formats: 23 | (i) 13th February, 1998 (ii) 13 February, 1998. 24 | ``` 25 | ```sql 26 | SELECT TO_CHAR(HIRE_DATE,'DD MON,YYYY'), CONCAT(CONCAT(SUBSTR(HIRE_DATE,1, 2), 'th'), 27 | SUBSTR(TO_CHAR(HIRE_DATE,'DD MON,YYYY'),3,9)) FROM EMPLOYEES; 28 | ``` 29 | ## Chapter 4: Aggregate Functions 30 | ### 4.1c 31 | ``` 32 | Find the minimum, maximum, and average salary of all departments except DEPARTMENT_ID 80. 33 | Print DEPARTMENT_ID, minimum, maximum, and average salary.Sort the results in descending order 34 | of average salary first, then maximum salary, then minimum salary. Use column alias to rename 35 | column names in output for better display. 36 | ``` 37 | ```sql 38 | SELECT DEPARTMENT_ID,MAX(SALARY) as mx,min(SALARY) as mn, avg(SALARY) as avg 39 | from EMPLOYEES 40 | where DEPARTMENT_ID <>80 41 | GROUP BY DEPARTMENT_ID 42 | order by avg desc,mx,mn; 43 | ``` 44 | ### 4.3a 45 | ``` 46 | Find number of employees in each salary group. Salary groups are considered as follows. 47 | Group 1: 0k to <5K, 5k to <10k, 10k to <15k, and so on. 48 | ``` 49 | ```sql 50 | SELECT TRUNC(SALARY/5000 , 0)+1 salary_grp_no , TRUNC(SALARY/5000 , 0)*5000 lower_limit , 51 | TRUNC(SALARY/5000, 0)*5000+5000-1 upper_limit , COUNT(*) 52 | FROM EMPLOYEES 53 | GROUP BY TRUNC(SALARY/5000 , 0) 54 | ORDER BY salary_grp_no; 55 | ``` 56 | ### 4.3b 57 | ``` 58 | Find the number of employees that were hired in each year in each job type. Print year, job id, 59 | and total employees hired. 60 | ``` 61 | ```sql 62 | SELECT TO_CHAR(HIRE_DATE , 'YYYY') YEAR , JOB_ID , COUNT(*) Frequency 63 | from EMPLOYEES 64 | GROUP BY TO_CHAR(HIRE_DATE , 'YYYY'),JOB_ID 65 | ORDER BY YEAR ASC ; 66 | ``` 67 | ## Chapter 5: Query Multiple Tables – Joins 68 | ### 5.1 69 | ### a 70 | ``` 71 | For each employee print last name, salary, and job title 72 | ``` 73 | ```sql 74 | SELECT E.LAST_NAME , E.SALARY , J.JOB_TITLE 75 | from EMPLOYEES E LEFT JOIN JOBS J 76 | ON(E.JOB_ID = J.JOB_ID) 77 | ORDER BY E.LAST_NAME; 78 | ``` 79 | ### b 80 | ``` 81 | For each department, print department name and country name it is situated in 82 | ``` 83 | ```sql 84 | SELECT D.DEPARTMENT_NAME , C.COUNTRY_NAME 85 | FROM DEPARTMENTS D LEFT JOIN LOCATIONS L 86 | ON(D.LOCATION_ID = L.LOCATION_ID) 87 | LEFT JOIN COUNTRIES C 88 | ON(L.COUNTRY_ID = C.COUNTRY_ID) 89 | ORDER BY D.DEPARTMENT_NAME; 90 | ``` 91 | ### c 92 | ``` 93 | For each country, finds total number of departments situated in the country 94 | ``` 95 | ```sql 96 | SELECT C.COUNTRY_NAME , COUNT(D.DEPARTMENT_NAME) 97 | from COUNTRIES C LEFT JOIN LOCATIONS L 98 | ON(C.COUNTRY_ID = L.COUNTRY_ID) 99 | LEFT JOIN DEPARTMENTS D 100 | ON(D.LOCATION_ID = L.LOCATION_ID) 101 | GROUP BY C.COUNTRY_NAME 102 | ORDER BY COUNTRY_NAME; 103 | ``` 104 | ### d 105 | ``` 106 | For each employee, finds the number of job switches of the employee. 107 | ``` 108 | ```sql 109 | SELECT e.EMPLOYEE_ID , COUNT(jh.JOB_ID) 110 | from EMPLOYEES e 111 | JOIN JOB_HISTORY jh 112 | ON( e.EMPLOYEE_ID = jh.EMPLOYEE_ID ) 113 | GROUP BY e.EMPLOYEE_ID 114 | ORDER BY e.EMPLOYEE_ID; 115 | ``` 116 | ### e 117 | ``` 118 | For each department and job types, find the total number of employees working. Print 119 | department names, job titles, and total employees working. 120 | ``` 121 | ```sql 122 | SELECT D.DEPARTMENT_NAME , J.JOB_TITLE , COUNT(EMPLOYEE_ID) 123 | from EMPLOYEES E LEFT JOIN JOBS J 124 | ON(E.JOB_ID = J.JOB_ID) 125 | JOIN DEPARTMENTS D 126 | ON(E.DEPARTMENT_ID = D.DEPARTMENT_ID) 127 | GROUP BY D.DEPARTMENT_NAME,J.JOB_TITLE 128 | ORDER BY DEPARTMENT_NAME; 129 | ``` 130 | ### f 131 | ``` 132 | For each employee, finds the total number of employees those were hired before him/her. 133 | Print employee last name and total employees. 134 | ``` 135 | ```sql 136 | SELECT E1.LAST_NAME , COUNT(E2.EMPLOYEE_ID) Hired_Before 137 | FROM EMPLOYEES E1 JOIN EMPLOYEES E2 138 | ON(E1.HIRE_DATE>E2.HIRE_DATE) 139 | GROUP BY E1.EMPLOYEE_ID,E1.LAST_NAME 140 | ORDER BY E1.LAST_NAME; 141 | ``` 142 | ### g 143 | ``` 144 | For each employee, finds the total number of employees those were hired before him/her and 145 | those were hired after him/her. Print employee last name, total employees hired before him, 146 | and total employees hired after him 147 | ``` 148 | ```sql 149 | SELECT t1.last_name , t1.hired_before , t2.hired_after 150 | from( 151 | SELECT E1.EMPLOYEE_ID id, E1.LAST_NAME as last_name , COUNT(E2.EMPLOYEE_ID) hired_before 152 | FROM EMPLOYEES E1 JOIN EMPLOYEES E2 153 | ON(E1.HIRE_DATE>E2.HIRE_DATE) 154 | GROUP BY E1.EMPLOYEE_ID,E1.LAST_NAME 155 | ) t1 156 | JOIN ( 157 | SELECT E1.EMPLOYEE_ID id, E1.LAST_NAME as last_name,COUNT(E3.EMPLOYEE_ID) hired_after 158 | FROM EMPLOYEES E1 JOIN EMPLOYEES E3 159 | ON(E1.HIRE_DATEe2.SALARY) 174 | ) 175 | ORDER BY e1.SALARY; 176 | ``` 177 | ### i 178 | ``` 179 | For each employee, find his rank, i.e., position with respect to salary. The highest 180 | salaried employee should get rank 1 and lowest salaried employee should get the last 181 | rank. Employees with same salary should get same rank value. Print employee last names 182 | and his/he rank. 183 | ``` 184 | ```sql 185 | SELECT e1.LAST_NAME , COUNT(DISTINCT e2.SALARY)+1 as Rank 186 | FROM EMPLOYEES e1 left join EMPLOYEES e2 187 | on (e1.SALARY < e2.SALARY) 188 | GROUP BY e1.EMPLOYEE_ID , e1.LAST_NAME 189 | ORDER BY Rank asc; 190 | ``` 191 | ### j 192 | ``` 193 | Find the names of employees and their salaries for the top three highest salaried employees. 194 | The number of employees in your output should be more than three if there are employees with 195 | same salary. 196 | ``` 197 | ```sql 198 | SELECT e1.LAST_NAME , e1.SALARY 199 | FROM EMPLOYEES e1 200 | WHERE((SELECT COUNT(e2.EMPLOYEE_ID) FROM EMPLOYEES e2 WHERE e2.SALARY>e1.SALARY) <= 3) 201 | AND e1.SALARY is not null 202 | ORDER BY e1.SALARY desc; 203 | ``` 204 | ## Chapter 6: Query Multiple Tables – Sub-query 205 | ### 6.1 206 | ## a 207 | ``` 208 | Find the last names of all employees that work in the SALES department. 209 | ``` 210 | ```sql 211 | SELECT LAST_NAME FROM EMPLOYEES 212 | WHERE DEPARTMENT_ID = ( 213 | SELECT DEPARTMENT_ID from DEPARTMENTS WHERE DEPARTMENT_NAME='Sales' 214 | ); 215 | ``` 216 | ### b 217 | ``` 218 | Find the last names and salaries of those employees who get higher salary than at 219 | least one employee of SALES department 220 | ``` 221 | 222 | ```sql 223 | SELECT LAST_NAME, SALARY 224 | FROM EMPLOYEES 225 | WHERE SALARY > ANY 226 | ( 227 | SELECT SALARY 228 | FROM EMPLOYEES 229 | WHERE DEPARTMENT_ID = ( 230 | SELECT DEPARTMENT_ID from DEPARTMENTS WHERE DEPARTMENT_NAME='Sales' 231 | ) ); 232 | ``` 233 | ### c 234 | ``` 235 | Find the last names and salaries of those employees whose salary is higher than all 236 | employees of SALES department. 237 | ``` 238 | ```sql 239 | SELECT LAST_NAME, SALARY 240 | FROM EMPLOYEES 241 | WHERE SALARY > ALL 242 | ( 243 | SELECT SALARY 244 | FROM EMPLOYEES 245 | WHERE DEPARTMENT_ID = ( 246 | SELECT DEPARTMENT_ID from DEPARTMENTS WHERE DEPARTMENT_NAME='Sales' 247 | ) ); 248 | ``` 249 | ### d 250 | ``` 251 | Find the last names and salaries of those employees whose salary is within ± 5k of 252 | the average salary of SALES department. 253 | ``` 254 | ```sql 255 | SELECT LAST_NAME,SALARY 256 | FROM EMPLOYEES 257 | WHERE SALARY 258 | <=(SELECT 5000 + round(avg(SALARY)) 259 | FROM EMPLOYEES 260 | WHERE DEPARTMENT_ID = ( 261 | SELECT DEPARTMENT_ID from DEPARTMENTS WHERE DEPARTMENT_NAME='Sales' 262 | )) 263 | AND 264 | SALARY>=(SELECT -5000 + round(avg(SALARY)) 265 | FROM EMPLOYEES 266 | WHERE DEPARTMENT_ID = ( 267 | SELECT DEPARTMENT_ID from DEPARTMENTS WHERE DEPARTMENT_NAME='Sales' 268 | ) ) 269 | ; 270 | ``` 271 | ### 6.2 272 | ### a 273 | ``` 274 | Find those employees whose salary is higher than at least three other employees. Print 275 | last names and salary of each employee. You cannot use join in the main query. Use sub-query 276 | in WHERE clause only. You can use join in the sub-queries. 277 | ``` 278 | ```sql 279 | SELECT e1.LAST_NAME,e1.SALARY 280 | FROM EMPLOYEES e1 281 | WHERE 282 | 3<=( 283 | SELECT COUNT(e2.EMPLOYEE_ID) 284 | FROM EMPLOYEES e2 285 | WHERE (e2.SALARY 299 | (SELECT MAX(minsal) FROM (SELECT min(SALARY) minsal FROM EMPLOYEES GROUP BY DEPARTMENT_ID)); 300 | ``` 301 | ### c 302 | ``` 303 | Find those department names which have the highest number of employees in service. Print 304 | department names. Use sub-query. You can use join in the sub-queries. 305 | ``` 306 | ```sql 307 | SELECT d.DEPARTMENT_NAME,e.No_Of_Employee 308 | FROM DEPARTMENTS d,(SELECT DEPARTMENT_ID, COUNT(EMPLOYEE_ID ) No_Of_Employee 309 | FROM EMPLOYEES GROUP BY DEPARTMENT_ID) e 310 | WHERE d.DEPARTMENT_ID = e.DEPARTMENT_ID 311 | ORDER BY e.No_Of_Employee desc; 312 | ``` 313 | ### d 314 | ``` 315 | Find those employees who worked in more than one department in the company. Print employee 316 | last names. You cannot use join in the main query. Use sub-query. You can use join 317 | in the sub-queries 318 | ``` 319 | ```sql 320 | SELECT e.LAST_NAME ,e.EMPLOYEE_ID 321 | FROM EMPLOYEES e 322 | WHERE e.DEPARTMENT_ID <> ( SELECT DISTINCT j.DEPARTMENT_ID FROM JOB_HISTORY j WHERE 323 | e.EMPLOYEE_ID = j.EMPLOYEE_ID ); 324 | ``` 325 | ### e 326 | ``` 327 | For each employee, find the minimum and maximum salary of his/her department. Print 328 | employee last name, minimum salary, and maximum salary. Do not use sub-query in WHERE 329 | clause. Use sub-query in FROM clause. 330 | ``` 331 | ```sql 332 | SELECT E.LAST_NAME, D.MINSAL, D.MAXSAL 333 | FROM EMPLOYEES E, 334 | ( 335 | SELECT DEPARTMENT_ID AS DEPT, MIN(SALARY) MINSAL, MAX(SALARY) MAXSAL 336 | FROM EMPLOYEES 337 | GROUP BY DEPARTMENT_ID 338 | ) D 339 | WHERE (E.DEPARTMENT_ID = D.DEPT) 340 | ; 341 | ``` 342 | ### f 343 | ``` 344 | For each job type, find the employee who gets the highest salary. Print job title and 345 | last name of the employee. Assume that there is one and only one such employee for every 346 | job type. 347 | ``` 348 | ```sql 349 | SELECT ln , jt 350 | FROM 351 | ( 352 | SELECT 353 | ROW_NUMBER() OVER( 354 | PARTITION BY j.JOB_TITLE 355 | ORDER BY e.SALARY desc 356 | ) row_num, 357 | e.LAST_NAME ln, j.JOB_TITLE jt 358 | FROM EMPLOYEES e JOIN JOBS j ON( e.JOB_ID = j.JOB_ID ) 359 | ) t 360 | WHERE row_num=1; 361 | ``` 362 | ## Chapter 7: Set operations 363 | ### 7.1 364 | ### a 365 | ``` 366 | Find EMPLOYEE_ID of those employees who are not managers. Use minus operator to perform 367 | this. 368 | ``` 369 | ```sql 370 | SELECT EMPLOYEE_ID FROM EMPLOYEES 371 | MINUS 372 | (SELECT MANAGER_ID FROM EMPLOYEES); 373 | ``` 374 | ### b 375 | ``` 376 | Find last names of those employees who are not managers. Use minus operator to perform this. 377 | ``` 378 | ```sql 379 | SELECT LAST_NAME FROM EMPLOYEES WHERE EMPLOYEE_ID 380 | IN 381 | ( 382 | SELECT EMPLOYEE_ID FROM EMPLOYEES 383 | MINUS 384 | (SELECT MANAGER_ID FROM EMPLOYEES) 385 | ) 386 | ``` 387 | ### c 388 | ``` 389 | Find the LOCATION_ID of those locations having no departments. 390 | ``` 391 | ```sql 392 | SELECT LOCATION_ID FROM LOCATIONS 393 | MINUS 394 | (SELECT LOCATION_ID FROM DEPARTMENTS); 395 | ``` 396 | ## Chapter 8: Data Manipulation Language (DML) 397 | ### 8.2 398 | ### b 399 | ``` 400 | Update salary of all employees to the maximum salary of the department in which he/she works. 401 | ``` 402 | ```sql 403 | UPDATE EMPLOYEES e 404 | SET e.SALARY = (SELECT max(SALARY) FROM EMPLOYEES x WHERE x.DEPARTMENT_ID=e.DEPARTMENT_ID); 405 | ``` 406 | ### c 407 | ``` 408 | Update COMMISSION_PCT to N times for each employee where N is the number of employees he/she 409 | manages. When N = 0, keep the old value of COMMISSION_PCT column. 410 | ``` 411 | ```sql 412 | UPDATE EMPLOYEES e 413 | SET e.COMMISSION_PCT = e.COMMISSION_PCT*(SELECT COUNT(MANAGER_ID) 414 | FROM EMPLOYEES x WHERE e.DEPARTMENT_ID=x.MANAGER_ID) 415 | WHERE (SELECT COUNT(MANAGER_ID) 416 | FROM EMPLOYEES x WHERE e.DEPARTMENT_ID=x.MANAGER_ID)>0; 417 | ``` 418 | ### d 419 | ``` 420 | Update the hiring dates of all employees to the first day of the same year. 421 | Do not change this for those employees who joined on or after year 2000. 422 | ``` 423 | ```sql 424 | UPDATE EMPLOYEES e 425 | SET HIRE_DATE = (TO_DATE(concat('01/01/' , (EXTRACT(YEAR FROM HIRE_DATE ))), 'DD/MM/YYYY')) 426 | WHERE EXTRACT(YEAR from HIRE_DATE ) <2000; 427 | ``` 428 | ### 8.3 429 | ### b 430 | ``` 431 | Delete those locations having no departments. 432 | ``` 433 | ```sql 434 | DELETE FROM LOCATIONS 435 | WHERE LOCATION_ID NOT IN(SELECT LOCATION_ID FROM DEPARTMENTS); 436 | ``` 437 | ## Chapter 11: Introduction to PL/SQL 438 | ### 11.1 a 439 | ``` 440 | Write a PL/SQL block that will print ‘Happy Anniversary X’ for each employee X whose 441 | hiring date is today. Use cursor FOR loop for the task. 442 | ``` 443 | ```sql 444 | DECLARE 445 | YEARS NUMBER ; 446 | hd_m NUMBER; 447 | hd_d NUMBER; 448 | cd NUMBER; 449 | cm NUMBER; 450 | BEGIN 451 | 452 | FOR R IN (SELECT HIRE_DATE,LAST_NAME FROM EMPLOYEES ) 453 | LOOP 454 | hd_m :=extract(MONTH from R.HIRE_DATE); 455 | hd_d := extract(DAY from R.HIRE_DATE); 456 | cd := EXTRACT(DAY from SYSDATE); 457 | cm := EXTRACT(MONTH from SYSDATE); 458 | 459 | IF cd=hd_d AND hd_m=cm THEN 460 | DBMS_OUTPUT.PUT_LINE('Happy Anniversary' || R.LAST_NAME ) ; 461 | END IF; 462 | END LOOP ; 463 | END ; 464 | / 465 | ``` 466 | ### 11.2 b 467 | ``` 468 | Write an example PL/SQL block that inserts a new arbitrary row to the COUNTRIES table. 469 | The block should handle the exception DUP_VAL_ON_INDEX and OTHERS. Run the 470 | block for different COUNTRY_ID and observe the cases when above exception occurs. 471 | ``` 472 | ```sql 473 | DECLARE 474 | BEGIN 475 | INSERT INTO COUNTRIES 476 | VALUES('BD' , 'Bangladesh' , 4); 477 | 478 | EXCEPTION 479 | WHEN DUP_VAL_ON_INDEX THEN 480 | DBMS_OUTPUT.PUT_LINE('Duplicate value found!!') ; 481 | WHEN OTHERS THEN 482 | DBMS_OUTPUT.PUT_LINE('I dont know what happened!') ; 483 | END; 484 | / 485 | ``` 486 | 487 | You are invited to correct me in case I made a mistake and are welcomed to add those few missing exercises if you want. 488 | 489 | 490 | 491 | 492 | 493 | 494 | 495 | 496 | 497 | 498 | 499 | 500 | 501 | 502 | 503 | 504 | 505 | 506 | 507 | 508 | 509 | 510 | 511 | 512 | 513 | 514 | 515 | 516 | 517 | 518 | --------------------------------------------------------------------------------