From 9568898b9ba07a8f95bf57a1a2b1517f49a152bd Mon Sep 17 00:00:00 2001 From: Jan Kvetina Date: Wed, 9 Mar 2022 21:25:48 +0100 Subject: [PATCH] Deduplicate, fix overloaded modules, groups + improve performance --- views/obj_modules.sql | 114 +++++++++++++++++++++----------------- views/obj_modules_mvw.sql | 94 ++++++++++++++++++++++--------- views/obj_packages.sql | 1 + 3 files changed, 132 insertions(+), 77 deletions(-) diff --git a/views/obj_modules.sql b/views/obj_modules.sql index 1420525..38fdec2 100644 --- a/views/obj_modules.sql +++ b/views/obj_modules.sql @@ -12,6 +12,49 @@ WITH x AS ( UPPER(app.get_item('$SEARCH_ARGUMENTS')) AS search_arguments, LOWER(app.get_item('$SEARCH_SOURCE')) AS search_source FROM DUAL +), +t AS ( + SELECT /*+ MATERIALIZE */ + t.*, + x.argument_name, + x.search_arguments, + x.search_source + FROM obj_modules_mvw t + JOIN x + ON x.owner = t.owner + AND t.package_name = NVL(x.package_name, t.package_name) + AND t.module_name = NVL(x.module_name, t.module_name) + --AND SUBSTR(t.module_type, 1, 1) = NVL(x.module_type, SUBSTR(t.module_type, 1, 1)) + -- + AND (t.package_name LIKE x.search_packages || '%' ESCAPE '\' OR x.search_packages IS NULL) + AND (t.module_name LIKE x.search_modules || '%' ESCAPE '\' OR x.search_modules IS NULL) +), +a AS ( + SELECT /*+ MATERIALIZE */ + t.package_name, + t.module_name, + t.subprogram_id + FROM t + JOIN all_arguments a + ON a.owner = t.owner + AND a.package_name = t.package_name + AND a.object_name = t.module_name + AND a.subprogram_id = t.subprogram_id + AND a.argument_name LIKE t.search_arguments || '%' ESCAPE '\' + AND (a.argument_name = t.argument_name OR t.argument_name IS NULL) + GROUP BY t.package_name, t.module_name, t.subprogram_id +), +s AS ( + SELECT /*+ MATERIALIZE */ + t.package_name, + t.module_name, + t.subprogram_id + FROM t + JOIN all_source s + ON s.owner = t.owner + AND s.name = t.package_name + AND s.line BETWEEN t.body_start AND t.body_end + AND s.text LIKE '%' || t.search_source || '%' ESCAPE '\' ) SELECT t.owner, @@ -19,8 +62,7 @@ SELECT t.module_name, t.subprogram_id, t.overload, - NULL AS group_name, - -- + t.group_name, t.is_function, t.is_private, t.is_autonomous, @@ -36,54 +78,26 @@ SELECT t.count_lines, t.count_statements, t.comment_ -FROM obj_modules_mvw t -JOIN x - ON x.owner = t.owner - AND t.package_name = NVL(x.package_name, t.package_name) - AND t.module_name = NVL(x.module_name, t.module_name) - --AND SUBSTR(t.module_type, 1, 1) = NVL(x.module_type, SUBSTR(t.module_type, 1, 1)) - -- - AND (t.package_name LIKE x.search_packages || '%' ESCAPE '\' OR x.search_packages IS NULL) - AND (t.module_name LIKE x.search_modules || '%' ESCAPE '\' OR x.search_modules IS NULL) - -- - -- group name - -- -JOIN all_arguments a - ON a.owner = x.owner - AND a.package_name = t.package_name - AND a.object_name = t.module_name - AND a.subprogram_id = t.subprogram_id - -- - AND (a.argument_name LIKE x.search_arguments || '%' ESCAPE '\') - AND (a.argument_name = x.argument_name OR x.argument_name IS NULL) - -- -JOIN all_source s - ON s.owner = t.owner - AND s.name = t.package_name - AND s.line BETWEEN t.body_start AND t.body_end - AND (s.text LIKE '%' || x.search_source || '%' ESCAPE '\' OR x.search_source IS NULL) - -- -GROUP BY - t.owner, - t.package_name, - t.module_name, - t.subprogram_id, - t.overload, - t.is_function, - t.is_private, - t.is_autonomous, - t.is_cached, - t.is_definer, - t.args_in, - t.args_out, - t.spec_start, - t.spec_end, - t.spec_lines, - t.body_start, - t.body_end, - t.count_lines, - t.count_statements, - t.comment_; +FROM t +WHERE ( + (t.package_name, t.module_name, t.subprogram_id) IN ( + SELECT a.package_name, a.module_name, a.subprogram_id + FROM a + ) + OR ( + t.argument_name IS NULL + AND t.search_arguments IS NULL + ) + ) + AND ( + (t.package_name, t.module_name, t.subprogram_id) IN ( + SELECT s.package_name, s.module_name, s.subprogram_id + FROM s + ) + OR ( + t.search_source IS NULL + ) + ); -- COMMENT ON TABLE obj_modules IS 'Find package modules (procedures and functions) and their boundaries (start-end lines)'; -- diff --git a/views/obj_modules_mvw.sql b/views/obj_modules_mvw.sql index e47f694..cf98fb0 100644 --- a/views/obj_modules_mvw.sql +++ b/views/obj_modules_mvw.sql @@ -8,7 +8,7 @@ WITH w AS ( FROM apex_applications a WHERE a.owner NOT LIKE 'APEX%' ), -p AS ( +i AS ( -- find modules and start lines in spec and body SELECT /*+ MATERIALIZE */ i.owner, @@ -18,24 +18,35 @@ p AS ( i.type AS module_type, i.line AS start_line, -- - LEAD(i.line) OVER (PARTITION BY i.object_name, i.object_type ORDER BY p.subprogram_id, i.line) - 1 AS end_line, - ROW_NUMBER() OVER (PARTITION BY i.object_name, i.object_type, p.subprogram_id ORDER BY p.subprogram_id) AS overload_check, - -- - NVL(p.overload, 1) AS overload, - p.subprogram_id, - p.authid, - p.result_cache + LEAD(i.line) OVER (PARTITION BY i.object_name, i.object_type ORDER BY i.line) - 1 AS end_line, + ROW_NUMBER() OVER (PARTITION BY i.object_name, i.object_type, i.name ORDER BY i.line) AS overload FROM all_identifiers i JOIN w ON w.owner = i.owner - JOIN all_procedures p -- only public procedures - ON p.owner = i.owner - AND p.object_name = i.object_name - AND p.procedure_name = i.name WHERE i.type IN ('PROCEDURE', 'FUNCTION') AND i.object_type IN ('PACKAGE', 'PACKAGE BODY') AND i.usage IN ('DEFINITION', 'DECLARATION') ), +p AS ( + SELECT /*+ MATERIALIZE */ + i.owner, + i.object_name, + i.object_type, + i.module_name, + i.module_type, + i.start_line, + i.end_line, + p.overload, + p.subprogram_id, + p.authid, + p.result_cache + FROM i + JOIN all_procedures p -- only public procedures + ON p.owner = i.owner + AND p.object_name = i.object_name + AND p.procedure_name = i.module_name + AND NVL(p.overload, 1) = i.overload +), e AS ( -- find ending lines SELECT /*+ MATERIALIZE */ @@ -96,20 +107,6 @@ a AS ( AND a.subprogram_id = t.subprogram_id GROUP BY t.owner, t.package_name, t.module_name, t.module_type, t.subprogram_id ), -g AS ( - -- group for related modules - SELECT /*+ MATERIALIZE */ - s.owner, - s.name, - s.line, - RTRIM(REGEXP_REPLACE(s.text, '^\s*--\s*###\s*', '')) AS group_name, - RPAD(' ', ROW_NUMBER() OVER(ORDER BY s.line DESC)) AS group_sort - FROM all_source s - JOIN w - ON w.owner = s.owner - WHERE s.type = 'PACKAGE' - AND REGEXP_LIKE(s.text, '^\s*--\s*###') -), q AS ( -- search statements SELECT /*+ MATERIALIZE */ @@ -167,6 +164,7 @@ SELECT t.module_name, t.subprogram_id, t.overload, + g.group_name, -- CASE WHEN t.module_type = 'FUNCTION' THEN 'Y' END AS is_function, CASE WHEN b.line IS NOT NULL THEN 'Y' END AS is_private, @@ -214,4 +212,46 @@ LEFT JOIN all_source n AND n.type = 'PACKAGE BODY' AND n.line BETWEEN t.body_start AND t.body_end AND REGEXP_LIKE(n.text, 'PRAGMA\s+AUTONOMOUS_TRANSACTION') -; +LEFT JOIN ( + SELECT + t.owner, + t.package_name, + t.module_name, + t.subprogram_id, + t.overload, + MIN(g.group_sort || g.group_name) KEEP (DENSE_RANK FIRST ORDER BY g.line DESC) AS group_name + FROM ( + -- group for related modules + SELECT /*+ MATERIALIZE */ + s.owner, + s.name, + s.line, + RTRIM(REGEXP_REPLACE(s.text, '^\s*--\s*###\s*', '')) AS group_name, + RPAD(' ', ROW_NUMBER() OVER(ORDER BY s.line DESC)) AS group_sort + FROM all_source s + JOIN w + ON w.owner = s.owner + WHERE s.type = 'PACKAGE' + AND REGEXP_LIKE(s.text, '^\s*--\s*###') + ) g + JOIN t + ON t.owner = t.owner + WHERE g.name = t.package_name + AND g.line < t.spec_start + GROUP BY + t.owner, + t.package_name, + t.module_name, + t.subprogram_id, + t.overload +) g + ON g.owner = t.owner + AND g.package_name = t.package_name + AND g.module_name = t.module_name + AND g.subprogram_id = t.subprogram_id; +-- +BEGIN + DBMS_MVIEW.REFRESH('OBJ_MODULES_MVW', 'C', parallelism => 4); -- 52s on free cloud +END; +/ + diff --git a/views/obj_packages.sql b/views/obj_packages.sql index 3fc0f90..76aefe7 100644 --- a/views/obj_packages.sql +++ b/views/obj_packages.sql @@ -21,6 +21,7 @@ FROM obj_modules t JOIN all_objects o ON o.owner = t.owner AND o.object_name = t.package_name + AND o.object_type = 'PACKAGE' GROUP BY t.package_name; -- COMMENT ON TABLE obj_packages IS 'List of packages';