DataBase/MySQL
[MySQL] Oracle의 계층 쿼리 WITH RECURSIVE를 MySQL에서 사용하기
S0PH1A
2019. 2. 27. 15:00
반응형
[MySQL] Oracle의 계층 쿼리 WITH RECURSIVE를 MySQL에서 사용하기
Mysql에서 계층 쿼리를 사용하려고 했지만,
Oracle, Mssql 의 WITH RECURSIVE ~ AS 문을 이용한 계층 쿼리 를 Mysql은 제공하지 않았다.
구글링해보니, MySQL 에서는 VIEW(뷰) 즉, 가상 테이블을 만들어서 사용해야 한다고 했다.
더 검색해 보니, 누군가 View 가 아닌 Temporary 테이블을 이용하여 WITH RECURSIVE 기능을 하는 프로시져를 올려둔 사람이 있었다.
"Temporary 테이블" 이란?
-임시 테이블
-View와는 다르게 특정 결과를 임시적으로 저장할 수 있다.
-현재 접속한 single session에 한하여 재사용이 가능하다.
-Stored Procedure에서 유용하게 사용된다고 한다.
아래는 WITH_EMULATOR 프로시져 생성 쿼리 문이다.
# Usage: the standard syntax: # WITH RECURSIVE recursive_table AS # (initial_SELECT # UNION ALL # recursive_SELECT) # final_SELECT; # should be translated by you to # CALL WITH_EMULATOR(recursive_table, initial_SELECT, recursive_SELECT, # final_SELECT, 0, ""). # ALGORITHM: # 1) we have an initial table T0 (actual name is an argument # "recursive_table"), we fill it with result of initial_SELECT. # 2) We have a union table U, initially empty. # 3) Loop: # add rows of T0 to U, # run recursive_SELECT based on T0 and put result into table T1, # if T1 is empty # then leave loop, # else swap T0 and T1 (renaming) and empty T1 # 4) Drop T0, T1 # 5) Rename U to T0 # 6) run final select, send relult to client # This is for *one* recursive table. # It would be possible to write a SP creating multiple recursive tables. delimiter | CREATE PROCEDURE WITH_EMULATOR( recursive_table varchar(100), # name of recursive table initial_SELECT varchar(65530), # seed a.k.a. anchor recursive_SELECT varchar(65530), # recursive member final_SELECT varchar(65530), # final SELECT on UNION result max_recursion int unsigned, # safety against infinite loop, use 0 for default create_table_options varchar(65530) # you can add CREATE-TABLE-time options # to your recursive_table, to speed up initial/recursive/final SELECTs; example: # "(KEY(some_column)) ENGINE=MEMORY" ) BEGIN declare new_rows int unsigned; declare show_progress int default 0; # set to 1 to trace/debug execution declare recursive_table_next varchar(120); declare recursive_table_union varchar(120); declare recursive_table_tmp varchar(120); set recursive_table_next = concat(recursive_table, "_next"); set recursive_table_union = concat(recursive_table, "_union"); set recursive_table_tmp = concat(recursive_table, "_tmp"); # Cleanup any previous failed runs SET @str = CONCAT("DROP TEMPORARY TABLE IF EXISTS ", recursive_table, ",", recursive_table_next, ",", recursive_table_union, ",", recursive_table_tmp); PREPARE stmt FROM @str; EXECUTE stmt; # If you need to reference recursive_table more than # once in recursive_SELECT, remove the TEMPORARY word. SET @str = # create and fill T0 CONCAT("CREATE TEMPORARY TABLE ", recursive_table, " ", create_table_options, " AS ", initial_SELECT); PREPARE stmt FROM @str; EXECUTE stmt; SET @str = # create U CONCAT("CREATE TEMPORARY TABLE ", recursive_table_union, " LIKE ", recursive_table); PREPARE stmt FROM @str; EXECUTE stmt; SET @str = # create T1 CONCAT("CREATE TEMPORARY TABLE ", recursive_table_next, " LIKE ", recursive_table); PREPARE stmt FROM @str; EXECUTE stmt; if max_recursion = 0 then set max_recursion = 100; # a default to protect the innocent end if; recursion: repeat # add T0 to U (this is always UNION ALL) SET @str = CONCAT("INSERT INTO ", recursive_table_union, " SELECT * FROM ", recursive_table); PREPARE stmt FROM @str; EXECUTE stmt; # we are done if max depth reached set max_recursion = max_recursion - 1; if not max_recursion then if show_progress then select concat("max recursion exceeded"); end if; leave recursion; end if; # fill T1 by applying the recursive SELECT on T0 SET @str = CONCAT("INSERT INTO ", recursive_table_next, " ", recursive_SELECT); PREPARE stmt FROM @str; EXECUTE stmt; # we are done if no rows in T1 select row_count() into new_rows; if show_progress then select concat(new_rows, " new rows found"); end if; if not new_rows then leave recursion; end if; # Prepare next iteration: # T1 becomes T0, to be the source of next run of recursive_SELECT, # T0 is recycled to be T1. SET @str = CONCAT("ALTER TABLE ", recursive_table, " RENAME ", recursive_table_tmp); PREPARE stmt FROM @str; EXECUTE stmt; # we use ALTER TABLE RENAME because RENAME TABLE does not support temp tables SET @str = CONCAT("ALTER TABLE ", recursive_table_next, " RENAME ", recursive_table); PREPARE stmt FROM @str; EXECUTE stmt; SET @str = CONCAT("ALTER TABLE ", recursive_table_tmp, " RENAME ", recursive_table_next); PREPARE stmt FROM @str; EXECUTE stmt; # empty T1 SET @str = CONCAT("TRUNCATE TABLE ", recursive_table_next); PREPARE stmt FROM @str; EXECUTE stmt; until 0 end repeat; # eliminate T0 and T1 SET @str = CONCAT("DROP TEMPORARY TABLE ", recursive_table_next, ", ", recursive_table); PREPARE stmt FROM @str; EXECUTE stmt; # Final (output) SELECT uses recursive_table name SET @str = CONCAT("ALTER TABLE ", recursive_table_union, " RENAME ", recursive_table); PREPARE stmt FROM @str; EXECUTE stmt; # Run final SELECT on UNION SET @str = final_SELECT; PREPARE stmt FROM @str; EXECUTE stmt; # No temporary tables may survive: SET @str = CONCAT("DROP TEMPORARY TABLE ", recursive_table); PREPARE stmt FROM @str; EXECUTE stmt; # We are done :-) END| delimiter ;
사용 방법
CALL WITH_EMULATOR(recursive_table, initial_SELECT, recursive_SELECT, final_SELECT, 0, "").
예)
Oracle에서 아래와 같이 사용하던 방식을
WITH RECURSIVE # The temporary buffer, also used as UNION result: EMPLOYEES_EXTENDED AS ( # The seed: SELECT ID, NAME, MANAGER_ID, 0 AS REPORTS FROM EMPLOYEES WHERE ID NOT IN (SELECT MANAGER_ID FROM EMPLOYEES WHERE MANAGER_ID IS NOT NULL) UNION ALL # The recursive member: SELECT M.ID, M.NAME, M.MANAGER_ID, SUM(1+E.REPORTS) AS REPORTS FROM EMPLOYEES M JOIN EMPLOYEES_EXTENDED E ON M.ID=E.MANAGER_ID GROUP BY M.ID, M.NAME, M.MANAGER_ID ) # what we want to do with the complete result (the UNION): SELECT * FROM EMPLOYEES_EXTENDED;
위 프로시져를 이용하면,
Mysql에서 아래처럼 사용이 가능하다.
CALL WITH_EMULATOR( "EMPLOYEES_EXTENDED", " SELECT ID, NAME, MANAGER_ID, 0 AS REPORTS FROM EMPLOYEES WHERE ID NOT IN (SELECT MANAGER_ID FROM EMPLOYEES WHERE MANAGER_ID IS NOT NULL) ", " SELECT M.ID, M.NAME, M.MANAGER_ID, SUM(1+E.REPORTS) AS REPORTS FROM EMPLOYEES M JOIN EMPLOYEES_EXTENDED E ON M.ID=E.MANAGER_ID GROUP BY M.ID, M.NAME, M.MANAGER_ID ", "SELECT * FROM EMPLOYEES_EXTENDED", 0, "" );
해당 관련하여 자세한 설명은 글 하단 출처 페이지를 확인하면 된다.
아주 상세히 예시와 함께 잘 설명되어 있다 : )
[출처] http://guilhembichot.blogspot.com/2013/11/with-recursive-and-mysql.html
반응형