Growth ๐ŸŒณ/Practice ๐Ÿ’ป

[ํ”„๋กœ๊ทธ๋ž˜๋จธ์Šค] ์ž๋™์ฐจ ๋Œ€์—ฌ ๊ธฐ๋ก๋ณ„ ๋Œ€์—ฌ ๊ธˆ์•ก ๊ตฌํ•˜๊ธฐ (23.06.14 ์žฌํ’€์ด)

์ธ” 2023. 1. 30. 15:05

๐Ÿ“ข ๋ณธ ํฌ์ŠคํŒ…์— ํ™œ์šฉ๋˜๋Š” ๊ธฐ๋ณธ ๋ฌธ์ œ ๋ฐ ์ž๋ฃŒ ์ถœ์ฒ˜๋Š”

       ํ”„๋กœ๊ทธ๋ž˜๋จธ์Šค ์ฝ”๋”ฉํ…Œ์ŠคํŠธ ์—ฐ์Šต,   
       
https://school.programmers.co.kr/learn/challenges?page=1&languages=mysql%2Coracle
์ž„์„ ๋ฐํž™๋‹ˆ๋‹ค.


โ–  ๋ฌธ์ œ

๋ฌธ์ œ ์„ค๋ช…

๋‹ค์Œ์€ ์–ด๋Š ์ž๋™์ฐจ ๋Œ€์—ฌ ํšŒ์‚ฌ์—์„œ ๋Œ€์—ฌ ์ค‘์ธ ์ž๋™์ฐจ๋“ค์˜ ์ •๋ณด๋ฅผ ๋‹ด์€ CAR_RENTAL_COMPANY_CAR ํ…Œ์ด๋ธ”๊ณผ ์ž๋™์ฐจ ๋Œ€์—ฌ ๊ธฐ๋ก ์ •๋ณด๋ฅผ ๋‹ด์€ CAR_RENTAL_COMPANY_RENTAL_HISTORY ํ…Œ์ด๋ธ”๊ณผ ์ž๋™์ฐจ ์ข…๋ฅ˜ ๋ณ„ ๋Œ€์—ฌ ๊ธฐ๊ฐ„ ์ข…๋ฅ˜ ๋ณ„ ํ• ์ธ ์ •์ฑ… ์ •๋ณด๋ฅผ ๋‹ด์€ CAR_RENTAL_COMPANY_DISCOUNT_PLAN ํ…Œ์ด๋ธ” ์ž…๋‹ˆ๋‹ค.

 

CAR_RENTAL_COMPANY_CAR ํ…Œ์ด๋ธ”์€ ์•„๋ž˜์™€ ๊ฐ™์€ ๊ตฌ์กฐ๋กœ ๋˜์–ด์žˆ์œผ๋ฉฐ, CAR_ID, CAR_TYPE, DAILY_FEE, OPTIONS ๋Š” ๊ฐ๊ฐ ์ž๋™์ฐจ ID, ์ž๋™์ฐจ ์ข…๋ฅ˜, ์ผ์ผ ๋Œ€์—ฌ ์š”๊ธˆ(์›), ์ž๋™์ฐจ ์˜ต์…˜ ๋ฆฌ์ŠคํŠธ๋ฅผ ๋‚˜ํƒ€๋ƒ…๋‹ˆ๋‹ค.

 

Column name Type Nullable
CAR_ID INTEGER FALSE
CAR_TYPE VARCHAR(255) FALSE
DAILY_FEE INTEGER FALSE
OPTIONS VARCHAR(255) FALSE

์ž๋™์ฐจ ์ข…๋ฅ˜๋Š” '์„ธ๋‹จ', 'SUV', '์Šนํ•ฉ์ฐจ', 'ํŠธ๋Ÿญ', '๋ฆฌ๋ฌด์ง„' ์ด ์žˆ์Šต๋‹ˆ๋‹ค. ์ž๋™์ฐจ ์˜ต์…˜ ๋ฆฌ์ŠคํŠธ๋Š” ์ฝค๋งˆ(',')๋กœ ๊ตฌ๋ถ„๋œ ํ‚ค์›Œ๋“œ ๋ฆฌ์ŠคํŠธ(์˜ˆ: ''์—ด์„ ์‹œํŠธ,์Šค๋งˆํŠธํ‚ค,์ฃผ์ฐจ๊ฐ์ง€์„ผ์„œ'')๋กœ ๋˜์–ด์žˆ์œผ๋ฉฐ, ํ‚ค์›Œ๋“œ ์ข…๋ฅ˜๋Š” '์ฃผ์ฐจ๊ฐ์ง€์„ผ์„œ', '์Šค๋งˆํŠธํ‚ค', '๋„ค๋น„๊ฒŒ์ด์…˜', 'ํ†ตํ’์‹œํŠธ', '์—ด์„ ์‹œํŠธ', 'ํ›„๋ฐฉ์นด๋ฉ”๋ผ', '๊ฐ€์ฃฝ์‹œํŠธ' ๊ฐ€ ์žˆ์Šต๋‹ˆ๋‹ค.

 

CAR_RENTAL_COMPANY_RENTAL_HISTORY ํ…Œ์ด๋ธ”์€ ์•„๋ž˜์™€ ๊ฐ™์€ ๊ตฌ์กฐ๋กœ ๋˜์–ด์žˆ์œผ๋ฉฐ, HISTORY_ID, CAR_ID, START_DATE, END_DATE  ๋Š” ๊ฐ๊ฐ ์ž๋™์ฐจ ๋Œ€์—ฌ ๊ธฐ๋ก ID, ์ž๋™์ฐจ ID, ๋Œ€์—ฌ ์‹œ์ž‘์ผ, ๋Œ€์—ฌ ์ข…๋ฃŒ์ผ์„ ๋‚˜ํƒ€๋ƒ…๋‹ˆ๋‹ค.

Column name Type Nullable
HISTORY_ID INTEGER FALSE
CAR_ID INTEGER FALSE
START_DATE DATE FALSE
END_DATE DATE FALSE

CAR_RENTAL_COMPANY_DISCOUNT_PLAN ํ…Œ์ด๋ธ”์€ ์•„๋ž˜์™€ ๊ฐ™์€ ๊ตฌ์กฐ๋กœ ๋˜์–ด์žˆ์œผ๋ฉฐ, PLAN_ID, CAR_TYPE, DURATION_TYPE, DISCOUNT_RATE  ๋Š” ๊ฐ๊ฐ ์š”๊ธˆ ํ• ์ธ ์ •์ฑ… ID, ์ž๋™์ฐจ ์ข…๋ฅ˜, ๋Œ€์—ฌ ๊ธฐ๊ฐ„ ์ข…๋ฅ˜, ํ• ์ธ์œจ(%)์„ ๋‚˜ํƒ€๋ƒ…๋‹ˆ๋‹ค.

Column name Type Nullable
PLAN_ID INTEGER FALSE
CAR_TYPE VARCHAR(255) FALSE
DURATION_TYPE VARCHAR(255) FALSE
DISCOUNT_RATE INTEGER FALSE

ํ• ์ธ์œจ์ด ์ ์šฉ๋˜๋Š” ๋Œ€์—ฌ ๊ธฐ๊ฐ„ ์ข…๋ฅ˜๋กœ๋Š” '7์ผ ์ด์ƒ' (๋Œ€์—ฌ ๊ธฐ๊ฐ„์ด 7์ผ ์ด์ƒ 30์ผ ๋ฏธ๋งŒ์ธ ๊ฒฝ์šฐ), '30์ผ ์ด์ƒ' (๋Œ€์—ฌ ๊ธฐ๊ฐ„์ด 30์ผ ์ด์ƒ 90์ผ ๋ฏธ๋งŒ์ธ ๊ฒฝ์šฐ), '90์ผ ์ด์ƒ' (๋Œ€์—ฌ ๊ธฐ๊ฐ„์ด 90์ผ ์ด์ƒ์ธ ๊ฒฝ์šฐ) ์ด ์žˆ์Šต๋‹ˆ๋‹ค. ๋Œ€์—ฌ ๊ธฐ๊ฐ„์ด 7์ผ ๋ฏธ๋งŒ์ธ ๊ฒฝ์šฐ ํ• ์ธ์ •์ฑ…์ด ์—†์Šต๋‹ˆ๋‹ค.


๋ฌธ์ œ ์„ค๋ช…

CAR_RENTAL_COMPANY_CAR ํ…Œ์ด๋ธ”๊ณผ CAR_RENTAL_COMPANY_RENTAL_HISTORY ํ…Œ์ด๋ธ”๊ณผ CAR_REN TAL_COMPANY_DISCOUNT_PLAN ํ…Œ์ด๋ธ”์—์„œ ์ž๋™์ฐจ ์ข…๋ฅ˜๊ฐ€ 'ํŠธ๋Ÿญ'์ธ ์ž๋™์ฐจ์˜ ๋Œ€์—ฌ ๊ธฐ๋ก์— ๋Œ€ํ•ด์„œ ๋Œ€์—ฌ ๊ธฐ๋ก ๋ณ„๋กœ ๋Œ€์—ฌ ๊ธˆ์•ก(์ปฌ๋Ÿผ๋ช…: FEE)์„ ๊ตฌํ•˜์—ฌ ๋Œ€์—ฌ ๊ธฐ๋ก ID์™€ ๋Œ€์—ฌ ๊ธˆ์•ก ๋ฆฌ์ŠคํŠธ๋ฅผ ์ถœ๋ ฅํ•˜๋Š” SQL๋ฌธ์„ ์ž‘์„ฑํ•ด์ฃผ์„ธ์š”. ๊ฒฐ๊ณผ๋Š” ๋Œ€์—ฌ ๊ธˆ์•ก์„ ๊ธฐ์ค€์œผ๋กœ ๋‚ด๋ฆผ์ฐจ์ˆœ ์ •๋ ฌํ•˜๊ณ , ๋Œ€์—ฌ ๊ธˆ์•ก์ด ๊ฐ™์€ ๊ฒฝ์šฐ ๋Œ€์—ฌ ๊ธฐ๋ก ID๋ฅผ ๊ธฐ์ค€์œผ๋กœ ๋‚ด๋ฆผ์ฐจ์ˆœ ์ •๋ ฌํ•ด์ฃผ์„ธ์š”.

 

์ฃผ์˜์‚ฌํ•ญ

FEE์˜ ๊ฒฝ์šฐ ์˜ˆ์‹œ์ฒ˜๋Ÿผ ์ •์ˆ˜๋ถ€๋ถ„๋งŒ ์ถœ๋ ฅ๋˜์–ด์•ผ ํ•ฉ๋‹ˆ๋‹ค.


โ–  ํ’€์ด

  ๋ฌธ์ œ ์š”๊ตฌ์‚ฌํ•ญ  

์ž๋™์ฐจ ์ข…๋ฅ˜๊ฐ€ 'ํŠธ๋Ÿญ'์ธ ์ž๋™์ฐจ์˜ ๋Œ€์—ฌ ๊ธฐ๋ก์— ๋Œ€ํ•ด์„œ                < WHERE์ ˆ์— ์กฐ๊ฑด1 : CAR_TYPE 

๋Œ€์—ฌ ๊ธฐ๋ก ๋ณ„๋กœ ๋Œ€์—ฌ ๊ธˆ์•ก(์ปฌ๋Ÿผ๋ช…: FEE)์„ ๊ตฌํ•˜์—ฌ                       < ๋Œ€์—ฌ ๊ธฐ๋ก๋ณ„๋กœ FEE *

๋Œ€์—ฌ ๊ธฐ๋ก ID์™€ ๋Œ€์—ฌ ๊ธˆ์•ก ๋ฆฌ์ŠคํŠธ๋ฅผ ์ถœ๋ ฅ                   

๊ฒฐ๊ณผ๋Š” ๋Œ€์—ฌ ๊ธˆ์•ก์„ ๊ธฐ์ค€์œผ๋กœ ๋‚ด๋ฆผ์ฐจ์ˆœ ์ •๋ ฌ                                      < ์ •๋ ฌ์กฐ๊ฑด1 

๋Œ€์—ฌ ๊ธˆ์•ก์ด ๊ฐ™์€ ๊ฒฝ์šฐ ๋Œ€์—ฌ ๊ธฐ๋ก ID๋ฅผ ๊ธฐ์ค€์œผ๋กœ ๋‚ด๋ฆผ์ฐจ์ˆœ ์ •๋ ฌ     < ์ •๋ ฌ์กฐ๊ฑด2

 

* ๋ฌธ์ œ์˜ ์ฃผ์š” ํ’€์ด๋Š” FEE๋ฅผ ๊ตฌํ•˜๋Š” ๊ฒƒ. 

 

๋ฌธ์ œ ์„ค๋ช…์— ๋”ฐ๋ฅด๋ฉด FEE๋ฅผ ๊ตฌํ•˜๋Š” ๊ณต์‹์€ ์•„๋ž˜์™€ ๊ฐ™์ด ๋งŒ๋“ค ์ˆ˜ ์žˆ๋‹ค.

 

FEE = DAILY_FEE × ๋Œ€์—ฌ๊ธฐ๊ฐ„(END_DATE - START_DATE + 1) × ๋Œ€์—ฌ๊ธฐ๊ฐ„๋ณ„ DISCOUNT_RATE

 

 ์ด๋ฒˆ ํ’€์ด์—์„œ๋Š” ์•„๋ž˜ ์ฟผ๋ฆฌ๋กœ CAR_RENTAL_COMPANY_DISCOUNT_PLAN ์—์„œ ํŠธ๋Ÿญ์˜ ๋Œ€์—ฌ๊ธฐ๊ฐ„๋ณ„ ํ• ์ธ์œจ์„ ์ถœ๋ ฅํ•ด์„œ ํ™•์ธํ•ด๋ณด๊ณ  DISCOUNT_PLAN ํ…Œ์ด๋ธ”์€ ๋”ฐ๋กœ ์กฐ์ธํ•˜์ง€ ์•Š์•˜๋‹ค.

SELECT DURATION_TYPE, DISCOUNT_RATE
 FROM CAR_RENTAL_COMPANY_DISCOUNT_PLAN
 WHERE CAR_TYPE = 'ํŠธ๋Ÿญ';

 

> ์ž๋™์ฐจ ๋Œ€์—ฌ ํšŒ์‚ฌ์—์„œ ๋Œ€์—ฌ ์ค‘์ธ ์ž๋™์ฐจ๋“ค์˜ ์ •๋ณด๋ฅผ ๋‹ด์€ CAR_RENTAL_COMPANY_CAR ํ…Œ์ด๋ธ”๊ณผ ์ž๋™์ฐจ ๋Œ€์—ฌ ๊ธฐ๋ก ์ •๋ณด๋ฅผ ๋‹ด์€ CAR_RENTAL_COMPANY_RENTAL_HISTORY ํ…Œ์ด๋ธ”์„ ์กฐ์ธํ•ด์ค€ ํ›„,

DATEDIFF ํ•จ์ˆ˜๋กœ ๋Œ€์—ฌ๊ธฐ๊ฐ„์„ ๊ตฌํ•˜๊ณ 

CASE๋ฌธ์œผ๋กœ ๋Œ€์—ฌ๊ธฐ๊ฐ„๋ณ„ ํ• ์ธ์œจ์„ ๊ตฌํ•ด์„œ

์ผ์ผ ๋Œ€์—ฌ๋ฃŒ(DAILY_FEE) ์™€ ๊ณฑํ•ด์„œ HISTORY_ID๋ณ„ FEE๋ฅผ ์ถœ๋ ฅํ–ˆ๋‹ค.

FEE์˜ ์ •์ˆ˜๋ถ€๋ถ„๋งŒ ์ถœ๋ ฅํ•˜๋Š” ๊ฒƒ์€ FLOOR๋ฅผ ์‚ฌ์šฉํ•ด์ฃผ์—ˆ๋‹ค.

SELECT RH.HISTORY_ID
      ,FLOOR((DATEDIFF(RH.END_DATE, RH.START_DATE)+1) * CC.DAILY_FEE *
            (CASE WHEN DATEDIFF(RH.END_DATE, RH.START_DATE)+1 >= 90 THEN 0.85
                  WHEN DATEDIFF(RH.END_DATE, RH.START_DATE)+1 >= 30 THEN 0.92
                  WHEN DATEDIFF(RH.END_DATE, RH.START_DATE)+1 >= 7 THEN 0.95
             ELSE 1 END)) AS FEE

FROM CAR_RENTAL_COMPANY_CAR CC

INNER JOIN CAR_RENTAL_COMPANY_RENTAL_HISTORY RH
ON CC.CAR_ID = RH.CAR_ID

WHERE CC.CAR_TYPE = 'ํŠธ๋Ÿญ'
ORDER BY 2 DESC, 1 DESC;

โœ” ์ถ”๊ฐ€ : discount rate๋ฅผ ํ…Œ์ด๋ธ”์—์„œ ๊ฐ–๊ณ ์™€์„œ ์‚ฌ์šฉํ•  ์ˆ˜ ์žˆ๋„๋ก ์„ธ๊ฐ€์ง€ ํ…Œ์ด๋ธ” ๋ชจ๋‘ ์กฐ์ธํ•ด์„œ ํ•˜๋Š” ๋ฐฉ๋ฒ•

 

โ‘  ์ฒซ๋ฒˆ์งธ ํ’€์ด CASE๋ฌธ์—์„œ ๊ฐ ๋Œ€์—ฌ ๊ธฐ๊ฐ„์— ๋”ฐ๋ผ ํ• ์ธ์œจ์„ ์ง์ ‘์ ์œผ๋กœ ๋„ฃ์–ด์ฃผ๋Š” ๊ฒƒ์ด ์•„๋‹ˆ๋ผ CAR_RENTAL_COMPANY_DISCOUNT_PLAN ํ…Œ์ด๋ธ”์˜ DISCOUNT_RATE๋ฅผ ์‚ฌ์šฉํ•  ์ˆ˜ ์žˆ๋„๋ก ์กฐ๊ฑด์— ๋”ฐ๋ฅธ ์ƒˆ ๊ฐ’์„ DURATION_TYPE ์ปฌ๋Ÿผ๊ฐ’์œผ๋กœ ์ง€์ •ํ•œ๋‹ค.

โ‘ก  CASE๋ฌธ์œผ๋กœ ์ƒˆ๋กœ ์„ค์ •ํ•ด์ค€ DURATION_TYPE ์ปฌ๋Ÿผ์„  ๊ธฐ์ค€์œผ๋กœ DISCOUNT_PLAN ํ…Œ์ด๋ธ”๊ณผ ์กฐ์ธํ•ด์„œ ํ• ์ธ์œจ์„ ๊ณ„์‚ฐํ•œ๋‹ค.

WITH T1 AS (
            SELECT RH.HISTORY_ID AS HISTORY_ID
                  , DATEDIFF(END_DATE, START_DATE) + 1 AS RENT_PERIOD
                  , CC.CAR_TYPE AS CAR_TYPE
                  , CC.DAILY_FEE AS DAILY_FEE
                  , CASE WHEN DATEDIFF(RH.END_DATE, RH.START_DATE)+1 >= 90 THEN '90์ผ ์ด์ƒ'
                         WHEN DATEDIFF(RH.END_DATE, RH.START_DATE)+1 >= 30 THEN '30์ผ ์ด์ƒ'
                         WHEN DATEDIFF(RH.END_DATE, RH.START_DATE)+1 >= 7 THEN '7์ผ ์ด์ƒ'
                     ELSE 'NONE' END AS DURATION_TYPE

            FROM CAR_RENTAL_COMPANY_CAR CC
            INNER JOIN CAR_RENTAL_COMPANY_RENTAL_HISTORY RH
            ON CC.CAR_ID = RH.CAR_ID
            WHERE CC.CAR_TYPE = 'ํŠธ๋Ÿญ')


SELECT T1.HISTORY_ID AS HISTORY_ID
      ,FLOOR(T1.DAILY_FEE * T1.RENT_PERIOD * (100-IFNULL(T2.DISCOUNT_RATE,0))/100) AS FEE
 FROM T1 
 LEFT JOIN CAR_RENTAL_COMPANY_DISCOUNT_PLAN T2
 ON T1.DURATION_TYPE = T2.DURATION_TYPE
 AND T1.CAR_TYPE = T2.CAR_TYPE
 ORDER BY 2 DESC, 1 DESC;