#4 - ABC Analysis

ABC ๋ถ„์„์€ ์žฌ๊ณ ๊ด€๋ฆฌ์— ์‚ฌ์šฉ๋˜๋Š” ์žฌ๊ณ  ๋ถ„๋ฅ˜ ๊ธฐ๋ฒ•์˜ ํ•˜๋‚˜์ด๋‹ค.[1][2]

์ œํ’ˆ์˜ ์ค‘์š”๋„์— ๋”ฐ๋ผ ๋“ฑ๊ธ‰์„ ๋งค๊ธฐ๊ณ  ๊ทธ์— ๋”ฐ๋ฅธ ํŒ๋งค ์ „๋žต์„ ์„ธ์šธ ๋•Œ ํ™œ์šฉ๋œ๋‹ค. ์ค‘์š”๋„๋Š” ๋งค์ถœ์— ๋”ฐ๋ผ ๊ตฌ๋ถ„๋˜๋ฉฐ 20%์˜ ์ œํ’ˆ์ด 80%์˜ ๋งค์ถœ์„ ์ฐจ์ง€ํ•œ๋‹ค๊ณ  ์•Œ๋ ค์ง„ ํŒŒ๋ ˆํ†  ๋ฒ•์น™๋„ ABC ๋ถ„์„์— ๊ทผ๊ฑฐํ•˜๊ณ  ์žˆ๋‹ค.

ex. ๋ˆ„์ ๋งค์ถœ ๋น„์ค‘ 70% - A ๊ทธ๋ฃน, 7090% B ๊ทธ๋ฃน, 90100% C ๊ทธ๋ฃน

ABC ๋ถ„์„ (Pareto Chart)

์ œํ’ˆ๋ณ„ ๋งค์ถœ ๋ฐ์ดํ„ฐ๋ฅผ ๊ฐ€์ง€๊ณ  ABC ๋ถ„์„์„ ์ง„ํ–‰ํ•ด ๋ณด์ž.

๋‹ค์Œ์€ ํŒ๋งค ์ œํ’ˆ์˜ ์นดํ…Œ๊ณ ๋ฆฌ๊นŒ์ง€ ํฌํ•จ๋œ ๋งค์ถœ ์ƒ์„ธ ์ด๋ ฅ์ด๋‹ค.

๋งค์ถœ ๋ฐ์ดํ„ฐ ์ƒ์„ฑ - ๊ตฌ๋งค ์ƒ์„ธ ์ด๋ ฅ

DECLARE purchase_detail_log_raw ARRAY<STRUCT<
    dt            STRING,
    order_id      INT64,
    user_id       STRING,
    item_id       STRING,
    price         INT64,
    category      STRING,
    sub_category  STRING
>>
DEFAULT [
  ('2017-01-18', 48291, 'usr33395', 'lad533', 37300,  'ladys_fashion', 'bag'),
  ('2017-01-18', 48291, 'usr33395', 'lad329', 97300,  'ladys_fashion', 'jacket'),
  ('2017-01-18', 48291, 'usr33395', 'lad102', 114600, 'ladys_fashion', 'jacket'),
  ('2017-01-18', 48291, 'usr33395', 'lad886', 33300,  'ladys_fashion', 'bag'),
  ('2017-01-18', 48292, 'usr52832', 'dvd871', 32800,  'dvd'          , 'documentary'),
  ('2017-01-18', 48292, 'usr52832', 'gam167', 26000,  'game'         , 'accessories'),
  ('2017-01-18', 48292, 'usr52832', 'lad289', 57300,  'ladys_fashion', 'bag'),
  ('2017-01-18', 48293, 'usr28891', 'out977', 28600,  'outdoor'      , 'camp'),
  ('2017-01-18', 48293, 'usr28891', 'boo256', 22500,  'book'         , 'business'),
  ('2017-01-18', 48293, 'usr28891', 'lad125', 61500,  'ladys_fashion', 'jacket'),
  ('2017-01-18', 48294, 'usr33604', 'mem233', 116300, 'mens_fashion' , 'jacket'),
  ('2017-01-18', 48294, 'usr33604', 'cd477' , 25800,  'cd'           , 'classic'),
  ('2017-01-18', 48294, 'usr33604', 'boo468', 31000,  'book'         , 'business'),
  ('2017-01-18', 48294, 'usr33604', 'foo402', 48700,  'food'         , 'meats'),
  ('2017-01-18', 48295, 'usr38013', 'foo134', 32000,  'food'         , 'fish'),
  ('2017-01-18', 48295, 'usr38013', 'lad147', 96100,  'ladys_fashion', 'jacket')
];
CREATE OR REPLACE TABLE learning_club.purchase_detail_log AS
SELECT l.* FROM UNNEST(purchase_detail_log_raw) l;

ABC ๋ถ„์„ ๋งˆํŠธ

ABC ๋ถ„์„์— ํ•„์š”ํ•œ ์ง€ํ‘œ๋“ค๋กœ ๋งˆํŠธ๋ฅผ ๊ตฌ์„ฑํ•œ ์˜ˆ๋Š” ๋‹ค์Œ๊ณผ ๊ฐ™๋‹ค. ๋งˆ์ง€๋ง‰ ๋“ฑ๊ธ‰ ์ปฌ๋Ÿผ์€ ํŽธ์˜์ƒ ์ถ”๊ฐ€ํ•˜์˜€๋‹ค.

โ–  ๋ฐ์ดํ„ฐ ๋งˆํŠธ ํ˜•์‹

row
category
๋งค์ถœ
๊ตฌ์„ฑ๋น„
๊ตฌ์„ฑ๋น„๋ˆ„๊ณ„
๋“ฑ๊ธ‰

1

ladys_fashion

497400

57.76

57.76

A

2

mens_fashion

116300

13.51

71.27

B

3

food

80700

9.37

80.64

B

4

book

53500

6.21

86.85

B

5

dvd

32800

3.81

90.66

C

6

outdoor

28600

3.32

93.98

C

7

game

26000

3.02

97.0

C

8

cd

25800

3.0

100.0

C

๊ฐ ์ปฌ๋Ÿผ์˜ ์˜๋ฏธ์™€ ์‚ฐ์ถœ ๋ฐฉ๋ฒ•์„ ๊ฐ„๋žตํžˆ ์‚ดํŽด๋ณด์ž.

  1. category - ๋ถ„์„์˜ ๊ธฐ์ค€

  2. ๋งค์ถœ - purchase_detail_log ์—์„œ ์ œํ’ˆ category๋ณ„ ์ง‘๊ณ„ ํ•จ์ˆ˜ ์ ์šฉ

  3. ๊ตฌ์„ฑ๋น„ - ๋งค์ถœ / ์ด๋งค์ถœ * 100 (%)

    1. ๋ถ„์„(์œˆ๋„์šฐ) ํ•จ์ˆ˜๋กœ ์ด๋งค์ถœ ๊ณ„์‚ฐ - SUM(..) OVER ()

    2. ์Šค์นผ๋ผ ์„œ๋ธŒ์ฟผ๋ฆฌ๋ฅผ ํ†ตํ•ด์„œ ์ด๋งค์ถœ ๊ณ„์‚ฐ - (SELECT SUM(...) FROM ...)

  4. ๊ตฌ์„ฑ๋น„๋ˆ„๊ณ„ - cumulative sum ๋ถ„์„ํ•จ์ˆ˜ ์ ์šฉ

    1. PARTITION BY ?

    2. ORDER BY ?

    3. Window Frame ?

โ–  category๋ณ„ ๋งค์ถœ

์–ด๋ ต์ง€ ์•Š๊ฒŒ ๊ณ„์‚ฐํ•  ์ˆ˜ ์žˆ๋‹ค. ์—ฌ๊ธฐ์„œ๋Š” ํ•œ๋‹ฌ ๋งค์ถœ์„ ๊ธฐ์ค€์œผ๋กœ ์ œํ’ˆ ์นดํ…Œ๊ณ ๋ฆฌ๋ณ„ ๋งค์ถœ์•ก์ด ์‚ฐ์ถœ๋œ๋‹ค.

SELECT category,
       SUM(price),
       -- ...
  FROM learning_club.purchase_detail_log
 WHERE dt BETWEEN '2017-01-01' AND '2017-01-31'
 GROUP BY 1
;

โ–  category๋ณ„ ๊ตฌ์„ฑ๋น„

CREATE OR REPLACE TABLE learning_club.abc_mart AS 
SELECT category,
       SUM(price) AS amount,
       ROUND(SUM(price) / (SUM(SUM(price)) OVER ()) * 100, 2) AS amount_rate,
       ROUND(SUM(SUM(price)) OVER (ORDER BY SUM(price) DESC ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) /
       SUM(SUM(price)) OVER () * 100, 2) AS cumulative_rate
  FROM learning_club.purchase_detail_log
 WHERE dt BETWEEN '2017-01-01' AND '2017-01-31'
 GROUP BY 1
 ORDER BY 2 DESC;

๊ตฌ์„ฑ๋น„๋ฅผ ๊ตฌํ•˜๊ธฐ ์œ„ํ•ด์„œ๋Š” ์šฐ์„  ์ „์ฒด ๋งค์ถœ์•ก์ด ํ•„์š”ํ•˜๋‹ค. ์ „์ฒด ๋งค์ถœ์•ก์€ ๋ถ„์„ ํ•จ์ˆ˜๋ฅผ ์‚ฌ์šฉํ•˜์—ฌ ๋‹ค์Œ๊ณผ ๊ฐ™์ด ๊ณ„์‚ฐํ•œ๋‹ค.

SUM(SUM(price)) OVER ()

OVER ๊ตฌ๋ฌธ ์•ˆ์— ํŒŒํ‹ฐ์…˜์ด๋‚˜ ์œˆ๋„์šฐํ”„๋ ˆ์ž„์„ ์ง€์ •ํ•˜์ง€ ์•Š์•˜๋‹ค. ์ด๋Š” ์ „์ฒด ํ…Œ์ด๋ธ”์„ ํ•˜๋‚˜์˜ ํŒŒํ‹ฐ์…˜์œผ๋กœ ๋ณด๊ฒ ๋‹ค๋Š” ์–˜๊ธฐ์ด๋ฉฐ ์œˆ๋„์šฐํ”„๋ ˆ์ž„๋„ ํŒŒํ‹ฐ์…˜์˜ ์ฒ˜์Œ๋ถ€ํ„ฐ ๋๊นŒ์ง€๋ฅผ ํ•˜๋‚˜๋กœ ๊ฐ„์ฃผํ•˜๊ฒ ๋‹ค๋Š” ์˜๋ฏธ์ด๋‹ค. ์ด๋ ‡๊ฒŒ ๋งŒ๋“ค์–ด์ง„ ์œˆ๋„์šฐํ”„๋ ˆ์ž„์„ SUM(SUM())ํ•˜๋ฉด ์ „์ฒด ๋งค์ถœ์•ก์ด ๊ตฌํ•ด์ง„๋‹ค.

์•ˆ์ชฝ์˜ SUM()์€ GROUP BY์— ์˜ํ•ด์„œ ์ˆ˜ํ–‰๋˜๋Š” ์ง‘๊ณ„ํ•จ์ˆ˜๋กœ ์ง์ „์˜ category๋ณ„ ๋งค์ถœ์—์„œ์˜ SUM(price)์™€ ๋™์ผํ•˜๋‹ค. ๋ฐ˜๋ฉด, ๋ฐ”๊นฅ์ชฝ์˜ SUM()์€ ์ง‘๊ณ„ํ•จ์ˆ˜๊ฐ€ ์•„๋‹Œ ๋ถ„์„ํ•จ์ˆ˜๋กœ์„œ ์นดํ…Œ๊ณ ๋ฆฌ๋ณ„ ๋งค์ถœ์„ ๋ชจ๋‘ ํ•ฉ์‚ฐํ•˜๊ฒŒ ๋œ๋‹ค.

cumulative_rate๋Š” ์กฐ๊ธˆ ๋ณต์žกํ•˜๋‹ค. ๋ถ„ํ•ดํ•ด์„œ ์‚ดํŽด๋ณด์ž.

  • ROUND(..., 2)๋Š” ์‹ค์ˆ˜๊ฐ’์˜ ์†Œ์ˆ˜์  2์ž๋ฆฌ๊นŒ์ง€๋งŒ ๋ณด์—ฌ์ง€๋„๋ก ์ง€์ •ํ•œ๋‹ค. ์ƒ๋žตํ•˜๋ฉด ๋‹ค์Œ์ด ๋‚จ๋Š”๋‹ค.

    SUM(SUM(price)) OVER (ORDER BY SUM(price) DESC ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) / SUM(SUM(price)) OVER () * 100

  • ์—ฌ๊ธฐ์„œ ๋ถ„๋ชจ๋Š” ์ „์ฒด ๋งค์ถœ์•ก์„ ๊ณ„์‚ฐํ•˜๊ณ  ์žˆ๋‹ค.

    SUM(SUM(price)) OVER ()

  • ๋ถ„์ž์— ์œ„์น˜ํ•˜๊ณ  ์žˆ๋Š” ๋ถ„์„ํ•จ์ˆ˜ ๊ตฌ๋ฌธ์—์„œ๋Š” ๋‘ ๊ฐ€์ง€๋ฅผ ์‚ดํŽด์•ผ ํ•œ๋‹ค.

    • ์นดํ…Œ๊ณ ๋ฆฌ๋ณ„ ๋งค์ถœ์— ํ•ด๋‹นํ•˜๋Š” SUM(price)์˜ ๋‚ด๋ฆผ์ฐจ์ˆœ์œผ๋กœ ํŒŒํ‹ฐ์…˜์„ ์ •๋ ฌ(ORDER BY)์‹œํ‚ค๊ณ  ์žˆ๋‹ค.

      ORDER BY SUM(price) DESC

    • ์œˆ๋„์šฐํ”„๋ ˆ์ž„์˜ ์‹œ์ž‘์„ ๊ฐ€์žฅ ๋งค์ถœ์ด ๋†’์€ ์ฒซ๋ฒˆ์งธ ํ–‰์—์„œ๋ถ€ํ„ฐ ํ˜„์žฌ ํ–‰๊นŒ์ง€๋กœ ์„ค์ •ํ•˜๊ณ  ์žˆ๋‹ค. ๊ฒฐ๊ตญ ๊ฐ€์žฅ ๋†’์€ ๋งค์ถœ๋ถ€ํ„ฐ ํ˜„์žฌ๊นŒ์ง€์˜ ๋งค์ถœ์„ ๋ˆ„์ ํ•ฉ์‚ฐํ•œ๋‹ค.

      ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW

์š”์•ฝํ•˜๋ฉด ๋งค์ถœ์•ก์„ ๊ธฐ์ค€์œผ๋กœ ๋‚ด๋ฆผ์ฐจ์ˆœ์œผ๋กœ ์นดํ…Œ๊ณ ๋ฆฌ๋ฅผ ์ •๋ ฌ์‹œํ‚จ ํ›„์— ํ•ด๋‹น ์นดํ…Œ๊ณ ๋ฆฌ๊นŒ์ง€์˜ ๋ˆ„์ ๋งค์ถœ์„ ์ „์ฒด๋งค์ถœ๋กœ ๋‚˜๋ˆ”์œผ๋กœ์จ ๊ตฌ์„ฑ๋น„๋ฅผ ๊ตฌํ•  ์ˆ˜ ์žˆ๊ฒŒ ๋œ๋‹ค.

์œ„์˜ ์ฟผ๋ฆฌ๋ฅผ ์ˆ˜ํ–‰์‹œ์ผœ ๋งˆํŠธ๋ฅผ ๋งŒ๋“  ํ›„์— Data Stuio๋กœ ์‹œ๊ฐํ™”๋ฅผ ํ•˜๊ฒŒ ๋˜๋ฉด ์•„๋ž˜์™€ ๊ฐ™์€ ๋ ˆํฌํŠธ๋ฅผ ๋งŒ๋“ค ์ˆ˜ ์žˆ๋‹ค.

์ฐธ๊ณ  ์ž๋ฃŒ

[์ฐธ๊ณ ] ๋‹ค์ฐจ์›๋ถ„์„์„ ์œ„ํ•œ ๋งˆํŠธ - Cube

SELECT category, sub_category, SUM(price) AS amount,
  FROM learning_club.purchase_detail_log
 GROUP BY ROLLUP (1, 2)
 ORDER BY 1, 2 NULLS LAST; 

Last updated