Redesigned Packages page

This commit is contained in:
Jan Kvetina 2022-01-11 20:46:31 +01:00
parent 42a907fde3
commit 84bd472af7
3 changed files with 309 additions and 873 deletions

File diff suppressed because it is too large Load Diff

View File

@ -1,5 +1,12 @@
CREATE OR REPLACE VIEW obj_modules AS CREATE OR REPLACE VIEW obj_modules AS
WITH p AS ( WITH x AS (
SELECT
app.get_item('$PACKAGE_NAME') AS package_name,
app.get_item('$MODULE_TYPE') AS module_type
FROM users u
WHERE u.user_id = app.get_user_id()
),
p AS (
SELECT SELECT
i.object_name, i.object_name,
i.object_type, i.object_type,
@ -7,12 +14,22 @@ WITH p AS (
i.type AS module_type, i.type AS module_type,
i.line AS start_line, i.line AS start_line,
LEAD(i.line) OVER (PARTITION BY i.object_name, i.object_type ORDER BY i.line) - 1 AS end_line, 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 ROW_NUMBER() OVER (PARTITION BY i.object_name, i.object_type, i.name ORDER BY i.line) AS overload,
--
p.authid,
p.result_cache
FROM user_identifiers i FROM user_identifiers i
JOIN user_source s JOIN user_source s
ON s.name = i.object_name ON s.name = i.object_name
AND s.type = i.object_type AND s.type = i.object_type
AND s.line = i.line AND s.line = i.line
JOIN user_procedures p -- only public procedures
ON p.object_name = i.object_name
AND p.procedure_name = i.name
AND p.object_type = 'PACKAGE'
AND NVL(p.overload, 1) = 1
JOIN x
ON s.name = NVL(x.package_name, s.name)
WHERE i.type IN ('PROCEDURE', 'FUNCTION') WHERE i.type IN ('PROCEDURE', 'FUNCTION')
AND i.object_type IN ('PACKAGE', 'PACKAGE BODY') AND i.object_type IN ('PACKAGE', 'PACKAGE BODY')
AND i.usage = CASE s.type WHEN 'PACKAGE BODY' THEN 'DEFINITION' ELSE 'DECLARATION' END AND i.usage = CASE s.type WHEN 'PACKAGE BODY' THEN 'DEFINITION' ELSE 'DECLARATION' END
@ -21,6 +38,8 @@ e AS (
-- find ending lines -- find ending lines
SELECT s.* SELECT s.*
FROM user_source s FROM user_source s
JOIN x
ON s.name = NVL(x.package_name, s.name)
WHERE ( WHERE (
(s.type = 'PACKAGE BODY' AND REGEXP_LIKE(UPPER(s.text), '^\s*END(\s+[A-Z0-9_]+)?\s*;')) OR (s.type = 'PACKAGE BODY' AND REGEXP_LIKE(UPPER(s.text), '^\s*END(\s+[A-Z0-9_]+)?\s*;')) OR
(s.type = 'PACKAGE' AND REGEXP_LIKE(UPPER(s.text), ';')) (s.type = 'PACKAGE' AND REGEXP_LIKE(UPPER(s.text), ';'))
@ -33,6 +52,8 @@ t AS (
p.module_name, p.module_name,
p.module_type, p.module_type,
CASE WHEN MAX(p.overload) OVER (PARTITION BY p.object_name, p.module_name) > 1 THEN p.overload END AS overload, CASE WHEN MAX(p.overload) OVER (PARTITION BY p.object_name, p.module_name) > 1 THEN p.overload END AS overload,
p.authid,
p.result_cache,
-- --
MIN(CASE p.object_type WHEN 'PACKAGE' THEN p.start_line END) AS spec_start, MIN(CASE p.object_type WHEN 'PACKAGE' THEN p.start_line END) AS spec_start,
MIN(CASE p.object_type WHEN 'PACKAGE' THEN e.line END) AS spec_end, MIN(CASE p.object_type WHEN 'PACKAGE' THEN e.line END) AS spec_end,
@ -45,25 +66,10 @@ t AS (
ON e.name = p.object_name ON e.name = p.object_name
AND e.type = p.object_type AND e.type = p.object_type
AND e.line BETWEEN p.start_line AND NVL(p.end_line, 999999) AND e.line BETWEEN p.start_line AND NVL(p.end_line, 999999)
GROUP BY p.object_name, p.module_name, p.module_type, p.overload GROUP BY p.object_name, p.module_name, p.module_type, p.overload, p.authid, p.result_cache
),
g AS (
-- add module arguments
SELECT
t.package_name,
t.module_name,
t.module_type,
t.overload,
LISTAGG(a.argument_name || ' ' || a.in_out, ', ') WITHIN GROUP (ORDER BY a.position) AS args
FROM t
JOIN user_arguments a
ON a.package_name = t.package_name
AND a.object_name = t.module_name
AND a.overload = NVL(t.overload, 1)
AND a.position > 0
GROUP BY t.package_name, t.module_name, t.module_type, t.overload
), ),
a AS ( a AS (
-- arguments
SELECT SELECT
a.package_name, a.package_name,
a.object_name AS module_name, a.object_name AS module_name,
@ -72,9 +78,12 @@ a AS (
NULLIF(SUM(CASE WHEN a.in_out LIKE 'IN%' THEN 1 ELSE 0 END), 0) AS args_in, NULLIF(SUM(CASE WHEN a.in_out LIKE 'IN%' THEN 1 ELSE 0 END), 0) AS args_in,
NULLIF(SUM(CASE WHEN a.in_out LIKE '%OUT' AND position > 0 THEN 1 ELSE 0 END), 0) AS args_out NULLIF(SUM(CASE WHEN a.in_out LIKE '%OUT' AND position > 0 THEN 1 ELSE 0 END), 0) AS args_out
FROM user_arguments a FROM user_arguments a
JOIN x
ON a.package_name = NVL(x.package_name, a.package_name)
GROUP BY a.package_name, a.object_name, a.overload GROUP BY a.package_name, a.object_name, a.overload
), ),
d AS ( d AS (
-- documentation lines
SELECT SELECT
d.package_name, d.module_name, d.module_type, d.overload, --x.line, x.text d.package_name, d.module_name, d.module_type, d.overload, --x.line, x.text
LISTAGG(REGEXP_SUBSTR(x.text, '^\s*--\s*(.*)\s*$', 1, 1, NULL, 1), '<br />') WITHIN GROUP (ORDER BY x.line) AS comment_, LISTAGG(REGEXP_SUBSTR(x.text, '^\s*--\s*(.*)\s*$', 1, 1, NULL, 1), '<br />') WITHIN GROUP (ORDER BY x.line) AS comment_,
@ -98,10 +107,30 @@ d AS (
AND x.line BETWEEN d.doc_start AND d.doc_end AND x.line BETWEEN d.doc_start AND d.doc_end
AND NOT REGEXP_LIKE(x.text, '^\s*--\s*$') AND NOT REGEXP_LIKE(x.text, '^\s*--\s*$')
GROUP BY d.package_name, d.module_name, d.module_type, d.overload GROUP BY d.package_name, d.module_name, d.module_type, d.overload
),
g AS (
SELECT
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 user_source s
JOIN x
ON s.name = NVL(x.package_name, s.name)
WHERE s.type = 'PACKAGE'
AND REGEXP_LIKE(s.text, '^\s*--\s*###')
) )
SELECT SELECT
t.package_name, t.package_name,
t.module_name, t.module_name,
--
(
SELECT MIN(g.group_sort || g.group_name) KEEP (DENSE_RANK FIRST ORDER BY g.line DESC) AS group_name
FROM g
WHERE g.name = t.package_name
AND g.line < t.spec_start
) AS group_name,
--
CASE WHEN t.module_type = 'FUNCTION' THEN 'Y' END AS is_function, CASE WHEN t.module_type = 'FUNCTION' THEN 'Y' END AS is_function,
t.overload, t.overload,
-- --
@ -113,11 +142,16 @@ SELECT
t.body_lines, t.body_lines,
-- --
CASE WHEN b.text IS NOT NULL THEN 'Y' END AS is_private, CASE WHEN b.text IS NOT NULL THEN 'Y' END AS is_private,
CASE WHEN t.authid = 'DEFINER' THEN 'Y' END AS is_definer,
CASE WHEN t.result_cache = 'YES' THEN 'Y' END AS is_cached,
-- --
a.args_in, a.args_in,
a.args_out, a.args_out,
d.comment_ d.comment_
FROM t FROM t
JOIN x
ON t.package_name = NVL(x.package_name, t.package_name)
AND SUBSTR(t.module_type, 1, 1) = NVL(x.module_type, SUBSTR(t.module_type, 1, 1))
LEFT JOIN a LEFT JOIN a
ON a.package_name = t.package_name ON a.package_name = t.package_name
AND a.module_name = t.module_name AND a.module_name = t.module_name
@ -138,6 +172,7 @@ COMMENT ON TABLE obj_modules IS 'Find package modules (proced
-- --
COMMENT ON COLUMN obj_modules.package_name IS 'Package name'; COMMENT ON COLUMN obj_modules.package_name IS 'Package name';
COMMENT ON COLUMN obj_modules.module_name IS 'Module name'; COMMENT ON COLUMN obj_modules.module_name IS 'Module name';
COMMENT ON COLUMN obj_modules.group_name IS 'Group name to have similar modules grouped together';
COMMENT ON COLUMN obj_modules.is_function IS 'Module type (function)'; COMMENT ON COLUMN obj_modules.is_function IS 'Module type (function)';
COMMENT ON COLUMN obj_modules.overload IS 'Overload ID'; COMMENT ON COLUMN obj_modules.overload IS 'Overload ID';
COMMENT ON COLUMN obj_modules.spec_start IS 'Module start in specification'; COMMENT ON COLUMN obj_modules.spec_start IS 'Module start in specification';

46
views/obj_packages.sql Normal file
View File

@ -0,0 +1,46 @@
CREATE OR REPLACE VIEW obj_packages AS
WITH x AS (
SELECT
app.get_item('$PACKAGE_NAME') AS package_name
FROM users u
WHERE u.user_id = app.get_user_id()
),
s AS (
SELECT
s.name AS package_name,
COUNT(*) AS count_lines
FROM user_source s
WHERE s.type = 'PACKAGE BODY'
GROUP BY s.name
),
f AS (
SELECT
a.package_name,
SUM(CASE WHEN a.position = 0 THEN 1 ELSE 0 END) AS count_functions
FROM user_arguments a
GROUP BY a.package_name
)
SELECT
p.object_name AS package_name,
--
COUNT(p.procedure_name) - MIN(f.count_functions) AS count_procedures,
--
MIN(f.count_functions) AS count_functions,
MAX(s.count_lines) AS count_lines,
MAX(o.last_ddl_time) AS last_ddl_time,
--
-- dependencies?
--
NULL AS desc_
FROM user_objects o
CROSS JOIN x
JOIN user_procedures p
ON p.object_name = o.object_name
AND o.object_type = 'PACKAGE'
JOIN s
ON s.package_name = p.object_name
LEFT JOIN f
ON f.package_name = p.object_name
WHERE o.object_name = NVL(x.package_name, o.object_name)
GROUP BY p.object_name;