:meta-keywords: common table expression, recursive query, recursive cte :meta-description: Common Table Expressions (CTEs) are temporary tables (list of results) associated with a statement. *** CTE *** CTE(Common Table Expressions)는 질ì˜ë¬¸ê³¼ ê´€ë ¨ëœ ìž„ì‹œ í…Œì´ë¸”(ê²°ê³¼ 목ë¡)ì´ë‹¤. 질ì˜ë¬¸ ë‚´ì—서 CTE를 여러 번 ì°¸ì¡°í• ìˆ˜ 있으며 질ì˜ë¬¸ 범위 ë‚´ì—서만 표시ëœë‹¤. CTE를 사용하면 질ì˜ë¬¸ 로ì§ì„ 보다 효과ì 으로 분리하여 수행 ì„±ëŠ¥ì„ ê°œì„ í• ìˆ˜ 있으며 계층 질ì˜ë¬¸ì„ ìƒì„±í• 때 **CONNECT BY** 질ì˜ë¬¸ ë˜ëŠ” 복잡한 ì§ˆì˜ ëŒ€ì‹ ìž¬ê·€ì CTE를 ì‚¬ìš©í• ìˆ˜ 있다. CTE는 **WITH** ì ˆë¡œ 시작한다. ë¶€ì§ˆì˜ ëª©ë¡ê³¼ 부질ì˜ë¥¼ 사용하는 최종 질ì˜ê°€ 있어야 한다. ê° ë¶€ì§ˆì˜(í…Œì´ë¸” 표현ì‹)는 ì´ë¦„ê³¼ ì§ˆì˜ ì •ì˜ë¥¼ í¬í•¨í•œë‹¤. í…Œì´ë¸” 표현ì‹ì€ ì´ì „ì— ë™ì¼í•œ 질ì˜ë¬¸ì— ì •ì˜ëœ 다른 í…Œì´ë¸” 표현ì‹ì„ ì°¸ì¡°í• ìˆ˜ 있다. êµ¬ë¬¸ì€ ë‹¤ìŒê³¼ 같다. :: WITH [RECURSIVE <recursive_cte_name> [ (<recursive_column_names>) ] AS <recursive_sub-query>] <cte_name1> [ (<cte1_column_names>) ] AS <sub-query1> <cte_name2> [ (<cte2_column_names>) ] AS <sub-query2> ... <final_query> * *recursive_cte_name*, *cte_name1*, *cte_name2* : í…Œì´ë¸” 표현ì‹(부질ì˜)ì˜ ì‹ë³„ìž * *recursive_column_names*, *cte1_column_names*, *cte2_column_names* : ê° í…Œì´ë¸” í‘œí˜„ì‹ ê²°ê³¼ ì»¬ëŸ¼ì— ëŒ€í•œ ì‹ë³„ìž * *sub-query1*, *sub-query2* : ê° í…Œì´ë¸” 표현ì‹ì„ ì •ì˜í•˜ëŠ” ë¶€ì§ˆì˜ * *final_query* : ì´ì „ì— ì •ì˜ëœ í…Œì´ë¸” 표현ì‹ì„ 사용하는 질ì˜. ì¼ë°˜ì 으로 **FROM** ì ˆì€ CTE ì‹ë³„ìžë¥¼ í¬í•¨í•œë‹¤. 가장 단순한 ì‚¬ìš©ë²•ì€ í…Œì´ë¸” 표현ì‹ì˜ ê²°ê³¼ 목ë¡ì„ 결합하는 것ì´ë‹¤. .. code-block:: sql CREATE TABLE products (id INTEGER PRIMARY KEY, parent_id INTEGER, item VARCHAR(100), price INTEGER); INSERT INTO products VALUES (1, -1, 'Drone', 2000); INSERT INTO products VALUES (2, 1, 'Blade', 10); INSERT INTO products VALUES (3, 1, 'Brushless motor', 20); INSERT INTO products VALUES (4, 1, 'Frame', 50); INSERT INTO products VALUES (5, -1, 'Car', 20000); INSERT INTO products VALUES (6, 5, 'Wheel', 100); INSERT INTO products VALUES (7, 5, 'Engine', 4000); INSERT INTO products VALUES (8, 5, 'Frame', 4700); WITH of_drones AS (SELECT item, 'drones' FROM products WHERE parent_id = 1), of_cars AS (SELECT item, 'cars' FROM products WHERE parent_id = 5) SELECT * FROM of_drones UNION ALL SELECT * FROM of_cars ORDER BY 1; :: item 'drones' ============================================ 'Blade' 'drones' 'Brushless motor' 'drones' 'Car' 'cars' 'Drone' 'drones' 'Engine' 'cars' 'Frame' 'drones' 'Frame' 'cars' 'Wheel' 'cars' 한 CTEì˜ ë¶€ì§ˆì˜ê°€ 다른 CTEì˜ ë¶€ì§ˆì˜ì— 참조ë 수 있다(참조ë˜ëŠ” CTEê°€ 미리 ì •ì˜ë˜ì–´ 있어야 함) : .. code-block:: sql WITH of_drones AS (SELECT item FROM products WHERE parent_id = 1), filter_common_with_cars AS (SELECT * FROM of_drones INTERSECT SELECT item FROM products WHERE parent_id = 5) SELECT * FROM filter_common_with_cars ORDER BY 1; :: item ====================== 'Frame' 다ìŒê³¼ ê°™ì€ ê²½ìš° 오류가 ë°œìƒí•œë‹¤. : * 둘 ì´ìƒì˜ CTEì—서 ë™ì¼í•œ ì‹ë³„ìžëª… 사용. * ì¤‘ì²©ëœ **WITH** ì ˆ 사용. .. code-block:: sql WITH my_cte AS (SELECT item FROM products WHERE parent_id = 1), my_cte AS (SELECT * FROM my_cte INTERSECT SELECT item FROM products WHERE parent_id = 5) SELECT * FROM my_cte ORDER BY 1; :: before ' SELECT * FROM my_cte ORDER BY 1; ' CTE name ambiguity, there are more than one CTEs with the same name: 'my_cte'. .. code-block:: sql WITH of_drones AS (SELECT item FROM products WHERE parent_id = 1), of_cars1 AS (WITH of_cars2 AS (SELECT item FROM products WHERE parent_id = 5) SELECT * FROM of_cars2 ) SELECT * FROM of_drones, of_cars1 ORDER BY 1; :: before ' SELECT * FROM of_drones, of_cars1 ORDER BY 1; ' Nested WITH clauses are not supported. CTE 컬럼명 ========== ê° CTE ê²°ê³¼ì˜ ì»¬ëŸ¼ëª…ì€ CTE ì´ë¦„ 다ìŒì— ì§€ì •í• ìˆ˜ 있다. CTE 컬럼 목ë¡ì˜ 요소 수는 CTE 부질ì˜ì˜ 컬럼 수와 ì¼ì¹˜í•´ì•¼ 한다. .. code-block:: sql WITH of_drones (product_name, product_type, price) AS (SELECT item, 'drones', price FROM products WHERE parent_id = 1), of_cars (product_name, product_type, price) AS (SELECT item, 'cars', price FROM products WHERE parent_id = 5) SELECT * FROM of_drones UNION ALL SELECT * FROM of_cars ORDER BY product_type, price; WITH of_drones (product_name, product_type, price) AS (SELECT item, 'drones' as type, MAX(price) FROM products WHERE parent_id = 1 GROUP BY type), of_cars (product_name, product_type, price) AS (SELECT item, 'cars' as type, MAX (price) FROM products WHERE parent_id = 5 GROUP BY type) SELECT * FROM of_drones UNION ALL SELECT * FROM of_cars ORDER BY product_type, price; :: product_name product_type price ========================================================= 'Wheel' 'cars' 100 'Engine' 'cars' 4000 'Frame' 'cars' 4700 'Blade' 'drones' 10 'Brushless motor' 'drones' 20 'Frame' 'drones' 50 product_name product_type price ======================================================== 'Wheel' 'cars' 4700 'Blade' 'drones' 50 CTEì— ì»¬ëŸ¼ëª…ì´ ì—†ìœ¼ë©´ CTEì˜ ì²« 번째 ë‚´ë¶€ Select 문ì—서 ì»¬ëŸ¼ëª…ì„ ê°€ì ¸ì˜¨ë‹¤. ì›ë³¸ êµ¬ë¬¸ì— ë”°ë¼ í‘œí˜„ì‹ ê²°ê³¼ ì»¬ëŸ¼ëª…ì´ ê²°ì •ëœë‹¤. .. code-block:: sql WITH of_drones AS (SELECT item, 'drones', MAX(price) FROM products WHERE parent_id = 1 GROUP BY 2), of_cars AS (SELECT item, 'cars', MAX (price) FROM products WHERE parent_id = 5 GROUP BY 2) SELECT * FROM of_drones UNION ALL SELECT * FROM of_cars ORDER BY 1; :: item 'drones' max(products.price) ================================================================ 'Blade' 'drones' 50 'Wheel' 'cars' 4700 ìž¬ê·€ì ˆ ====== **RECURSIVE** 키워드를 사용하여 반복ë˜ëŠ” 질ì˜ë¥¼ êµ¬ì„±í• ìˆ˜ 있다(í…Œì´ë¸” í‘œí˜„ì‹ ë¶€ì§ˆì˜ ì •ì˜ ìžì²´ ì´ë¦„ í¬í•¨). 재귀 í…Œì´ë¸” 표현ì‹ì€ 비재귀ì 부분과 재귀ì 부분(CTE ì´ë¦„으로 ë¶€ì§ˆì˜ ì°¸ì¡°)으로 구성ëœë‹¤. **UNION ALL** ì§ˆì˜ ì—°ì‚°ìžë¥¼ 사용하여 재귀ì 부분과 비재귀ì ë¶€ë¶„ì„ **ê²°í•© 해야 한다** . 무한 반복하지 않ë„ë¡ ìž¬ê·€ì ë¶€ë¶„ì„ ì •ì˜í•´ì•¼ 한다. ë˜í•œ 재귀ì ë¶€ë¶„ì— ì§‘ê³„ 함수를 í¬í•¨í•˜ëŠ” 경우 집계 함수가 í•ìƒ íŠœí”Œì„ ë°˜í™˜í•˜ê³ ìž¬ê·€ ë°˜ë³µì´ ê³„ì†ë˜ë¯€ë¡œ **GROUP BY** ì ˆë„ í¬í•¨í•´ì•¼ 한다. **WHERE** ì ˆì˜ ì¡°ê±´ì„ ë” ì´ìƒ 만족하지 ì•Šê³ í˜„ìž¬ ìˆ˜í–‰ëœ ë°˜ë³µì˜ ê²°ê³¼ê°€ ì—†ì„ ê²½ìš° 재귀 ë°˜ë³µì´ ì¤‘ë‹¨ëœë‹¤. .. code-block:: sql WITH RECURSIVE cars (id, parent_id, item, price) AS ( SELECT id, parent_id, item, price FROM products WHERE item LIKE 'Car%' UNION ALL SELECT p.id, p.parent_id, p.item, p.price FROM products p INNER JOIN cars rec_cars ON p.parent_id = rec_cars.id) SELECT item, price FROM cars ORDER BY 1; :: item price =================================== 'Car' 20000 'Engine' 4000 'Frame' 4700 'Wheel' 100 재귀ì CTE는 무한 ë£¨í”„ì— ë¹ ì§ˆìˆ˜ 있다. ì´ëŸ° 경우를 피하기 위해서 시스템 파ë¼ë¯¸í„° **cte_max_recursions** 를 ì›í•˜ëŠ” 임계치로 ì„¤ì •í•´ì•¼ 한다. ì´ íŒŒë¼ë¯¸í„°ì˜ ê¸°ë³¸ê°’ì€ 2,000번 재귀 반복ì´ë©°, ìµœëŒ€ê°’ì€ 1,000,000 ìµœì†Œê°’ì€ 2ì´ë‹¤. .. code-block:: sql SET SYSTEM PARAMETERS 'cte_max_recursions=2'; WITH RECURSIVE cars (id, parent_id, item, price) AS ( SELECT id, parent_id, item, price FROM products WHERE item LIKE 'Car%' UNION ALL SELECT p.id, p.parent_id, p.item, p.price FROM products p INNER JOIN cars rec_cars ON p.parent_id = rec_cars.id) SELECT item, price FROM cars ORDER BY 1; :: In the command from line 9, Maximum recursions 2 reached executing CTE. .. warning:: * CTE 부질ì˜ì˜ 복잡ë„ì— ë”°ë¼, ë§Žì€ ëŸ‰ì˜ ë°ì´íƒ€ê°€ ìƒì‚°ë˜ë©°, 심지어 **cte_max_recursions** ì˜ ê¸°ë³¸ê°’ë§Œìœ¼ë¡œë„ ë””ìŠ¤í¬ ê³µê°„ ë¶€ì¡±ì„ ë°œìƒí• 수 있다. 재귀ì CTEì˜ ì‹¤í–‰ ì•Œê³ ë¦¬ì¦˜ì€ ë‹¤ìŒê³¼ ê°™ì´ ìš”ì•½ ë 수 있다: * CTEì˜ ë¹„ìž¬ê·€ì ë¶€ë¶„ì„ ìˆ˜í–‰í•˜ê³ ê²°ê³¼ë¥¼ 최종 ê²°ê³¼ ì…‹ì— ì¶”ê°€ * 비재귀ì 부분ì—서 ì–»ì€ ê²°ê³¼ ì…‹ì„ ì‚¬ìš©í•˜ì—¬ 재귀ì ë¶€ë¶„ì„ ìˆ˜í–‰í•˜ê³ , 결과를 최종 ê²°ê³¼ ì…‹ì— ì¶”ê°€í•œ 후, ê²°ê³¼ ì…‹ ë‚´ì—서 현재 ë°˜ë³µì˜ ì‹œìž‘ê³¼ ëì„ ê¸°ì–µí•œë‹¤ * ì´ì „ ë°˜ë³µì˜ ê²°ê³¼ ì…‹ì„ ì‚¬ìš©í•˜ì—¬ 비재귀ì ë¶€ë¶„ì˜ ìˆ˜í–‰ì„ ë°˜ë³µí•˜ê³ í•´ë‹¹ 결과를 최종 ê²°ê³¼ ì…‹ì— ì¶”ê°€ * 재귀 반복ì—서 결과가 ìƒì„±ë˜ì§€ 않으면 중지 * ì„¤ì •ëœ ìµœëŒ€ 반복 íšŸìˆ˜ì— ë„달하는 경우ì—ë„ ì¤‘ì§€ 재귀ì CTE를 **FROM** ì ˆì—서 바로 참조해야 한다. 부질ì˜ì—서 참조하면 오류가 ë°œìƒí•œë‹¤. .. code-block:: sql WITH RECURSIVE cte1(x) AS SELECT c FROM t1 UNION ALL SELECT * FROM (SELECT cte1.x + 1 FROM cte1 WHERE cte1.x < 5) SELECT * FROM cte1; :: before ' SELECT * FROM cte1; ' Recursive CTE 'cte1' must be referenced directly in its recursive query. DMLê³¼ CREATEì—서 CTEì˜ ì‚¬ìš© ============================ **SELECT** ë¬¸ì— ëŒ€í•œ 사용 외ì—ë„ CTE는 다른 문장ì—ë„ ì‚¬ìš©ë 수 있다. CTEê°€ **CREATE TABLE** *table_name* **AS SELECT** ì— ì‚¬ìš©ë 수있다: .. code-block:: sql CREATE TABLE inc AS WITH RECURSIVE cte (n) AS ( SELECT 1 UNION ALL SELECT n + 1 FROM cte WHERE n < 3) SELECT n FROM cte; SELECT * FROM inc; :: n ============= 1 2 3 ë˜í•œ, **INSERT**/**REPLACE INTO** *table_name* **SELECT** ë„ CTE ì‚¬ìš©ì´ ê°€ëŠ¥í•˜ë‹¤: .. code-block:: sql INSERT INTO inc WITH RECURSIVE cte (n) AS ( SELECT 1 UNION ALL SELECT n + 1 FROM cte WHERE n < 3) SELECT * FROM cte; REPLACE INTO inc WITH cte AS (SELECT * FROM inc) SELECT * FROM cte; ë˜í•œ **UPDATE** ì˜ ë¶€ì§ˆì˜ì—ì„œë„ ì‚¬ìš©ê°€ëŠ¥í•˜ë‹¤: .. code-block:: sql CREATE TABLE green_products (producer_id INTEGER, sales_n INTEGER, product VARCHAR, product_type INTEGER, price INTEGER); INSERT INTO green_products VALUES (1, 99, 'bicycle', 1, 99); INSERT INTO green_products VALUES (2, 337, 'bicycle', 1, 129); INSERT INTO green_products VALUES (3, 5012, 'bicycle', 1, 199); INSERT INTO green_products VALUES (1, 989, 'scooter', 2, 899); INSERT INTO green_products VALUES (3, 3211, 'scooter', 2, 599); INSERT INTO green_products VALUES (4, 2312, 'scooter', 2, 1009); WITH price_increase_th AS ( SELECT SUM (sales_n) * 7 / 10 AS threshold, product_type FROM green_products GROUP BY product_type ) UPDATE green_products gp JOIN price_increase_th th ON gp.product_type = th.product_type SET price = price + (price / 10) WHERE sales_n >= threshold; ë˜í•œ, **DELETE** ì˜ ë¶€ì§ˆì˜ì—ì„œë„ ì‚¬ìš©ê°€ëŠ¥í•˜ë‹¤: .. code-block:: sql WITH product_removal_th AS ( SELECT SUM (sales_n) / 20 AS threshold, product_type FROM green_products GROUP BY product_type ) DELETE FROM green_products gp WHERE sales_n < (select threshold from product_removal_th WHERE product_type = gp.product_type);