From 916f3dd3e27c989899c3f08cab8b9f977a8e2aa3 Mon Sep 17 00:00:00 2001 From: Jan Kvetina Date: Fri, 22 Jul 2022 17:44:45 +0200 Subject: [PATCH] Move NAV functions to dedicated package --- database/mviews/nav_overview_mvw.sql | 2 +- database/packages/app_actions.spec.sql | 72 ------ database/packages/app_actions.sql | 253 -------------------- database/packages/nav.spec.sql | 107 +++++++++ database/packages/nav.sql | 256 +++++++++++++++++++++ database/triggers/settings__.sql | 2 +- database/views/obj_constraints_fix_dt2.sql | 2 +- database/views/obj_views.sql | 8 +- database/views/roles_auth_schemes.sql | 2 +- 9 files changed, 371 insertions(+), 333 deletions(-) create mode 100644 database/packages/nav.spec.sql create mode 100644 database/packages/nav.sql diff --git a/database/mviews/nav_overview_mvw.sql b/database/mviews/nav_overview_mvw.sql index 5fcb75d..f4b614a 100644 --- a/database/mviews/nav_overview_mvw.sql +++ b/database/mviews/nav_overview_mvw.sql @@ -87,7 +87,7 @@ SELECT WHEN t.authorization_scheme IS NULL AND n.page_id NOT IN (0, 9999) THEN app.get_icon('fa-warning', 'Auth scheme is missing') -- - ELSE app_actions.get_html_a(app.get_page_url ( + ELSE nav.get_html_a(app.get_page_url ( in_page_id => 920, in_app_id => n.app_id, in_names => 'P920_AUTH_SCHEME', diff --git a/database/packages/app_actions.spec.sql b/database/packages/app_actions.spec.sql index cc2a58e..7dfa488 100644 --- a/database/packages/app_actions.spec.sql +++ b/database/packages/app_actions.spec.sql @@ -43,18 +43,6 @@ CREATE OR REPLACE PACKAGE app_actions AS - -- - -- Get HTML alement A - -- - FUNCTION get_html_a ( - in_href VARCHAR2, - in_name VARCHAR2, - in_title VARCHAR2 := NULL - ) - RETURN VARCHAR2; - - - -- -- Create AUTH scheme in APEX -- @@ -67,66 +55,6 @@ CREATE OR REPLACE PACKAGE app_actions AS - - - -- ### Navigation page - -- - - -- - -- Remove missing pages from NAVIGATION table - -- - PROCEDURE nav_remove_pages ( - in_page_id navigation.page_id%TYPE := NULL - ); - - - - -- - -- Add new pages to NAVIGATION table - -- - PROCEDURE nav_add_pages ( - in_page_id navigation.page_id%TYPE := NULL - ); - - - - -- - -- Auto update navigation (add missing pages, remove old records) - -- - PROCEDURE nav_autoupdate; - - - - -- - -- Refresh navigation MVW in a background job and inform user - -- - PROCEDURE refresh_nav_views ( - in_log_id logs.log_id%TYPE, - in_user_id logs.user_id%TYPE, - in_app_id logs.app_id%TYPE, - in_lang_id users.lang_id%TYPE - ); - -- - PROCEDURE refresh_nav_views; - - - - -- - -- Save changes on Navigation page - -- - PROCEDURE save_nav_overview ( - in_action CHAR, - in_app_id navigation.app_id%TYPE, - in_page_id navigation.page_id%TYPE, - in_parent_id navigation.parent_id%TYPE, - in_order# navigation.order#%TYPE, - in_is_hidden navigation.is_hidden%TYPE, - in_is_reset navigation.is_reset%TYPE, - in_is_shared navigation.is_shared%TYPE - ); - - - -- -- Compute filters used on page region -- diff --git a/database/packages/app_actions.sql b/database/packages/app_actions.sql index a1563fb..2b46015 100644 --- a/database/packages/app_actions.sql +++ b/database/packages/app_actions.sql @@ -18,19 +18,6 @@ CREATE OR REPLACE PACKAGE BODY app_actions AS - FUNCTION get_html_a ( - in_href VARCHAR2, - in_name VARCHAR2, - in_title VARCHAR2 := NULL - ) - RETURN VARCHAR2 - AS - BEGIN - RETURN '' || in_name || ''; - END; - - - PROCEDURE create_auth_scheme ( in_app_id apex_application_authorization.application_id%TYPE, in_name apex_application_authorization.authorization_scheme_name%TYPE @@ -96,246 +83,6 @@ CREATE OR REPLACE PACKAGE BODY app_actions AS - PROCEDURE nav_remove_pages ( - in_page_id navigation.page_id%TYPE := NULL - ) - AS - in_app_id CONSTANT navigation.app_id%TYPE := app.get_app_id(); - BEGIN - app.log_module(in_page_id); - - -- remove pages and references, related rows - FOR c IN ( - SELECT in_app_id AS app_id, p.page_id - FROM nav_pages_to_remove p - WHERE p.page_id = NVL(in_page_id, p.page_id) - UNION - SELECT n.app_id, n.page_id - FROM navigation n - WHERE n.app_id = in_app_id - AND n.page_id = in_page_id - ) LOOP - app.log_debug('DELETING', c.app_id, c.page_id); - -- - UPDATE navigation n - SET n.parent_id = NULL - WHERE n.app_id = c.app_id - AND n.parent_id = c.page_id; - -- - DELETE FROM translated_items t - WHERE t.app_id = c.app_id - AND t.page_id = c.page_id; - -- - DELETE FROM navigation n - WHERE n.app_id = c.app_id - AND n.page_id = c.page_id; - END LOOP; - -- - app.log_success(); - EXCEPTION - WHEN app.app_exception THEN - RAISE; - WHEN OTHERS THEN - app.raise_error(); - END; - - - - PROCEDURE nav_add_pages ( - in_page_id navigation.page_id%TYPE := NULL - ) - AS - rec navigation%ROWTYPE; - BEGIN - app.log_module(in_page_id); - - -- add pages which are present in APEX but missing in Navigation table - FOR c IN ( - SELECT n.* - FROM nav_pages_to_add n - WHERE n.page_id = NVL(in_page_id, n.page_id) - ) LOOP - app.log_debug('ADDING', c.page_id); - -- - rec.app_id := c.app_id; - rec.page_id := c.page_id; - rec.parent_id := c.parent_id; - rec.order# := c.order#; - rec.is_hidden := c.is_hidden; - rec.is_reset := c.is_reset; - -- - INSERT INTO navigation VALUES rec; - END LOOP; - -- - app.log_success(); - EXCEPTION - WHEN app.app_exception THEN - RAISE; - WHEN OTHERS THEN - app.raise_error(); - END; - - - - PROCEDURE nav_autoupdate - AS - BEGIN - app.log_module(); - -- - nav_remove_pages(); - nav_add_pages(); - - -- renumber sublings - MERGE INTO navigation g - USING ( - SELECT n.app_id, n.page_id, n.new_order# - FROM ( - SELECT - n.app_id, - n.page_id, - n.order#, - ROW_NUMBER() OVER (PARTITION BY n.parent_id ORDER BY n.order#, n.page_id) * 5 + 5 AS new_order# - FROM navigation n - WHERE n.app_id = app.get_app_id() - AND n.parent_id IS NOT NULL - ) n - WHERE n.new_order# != n.order# - ) n - ON ( - g.app_id = n.app_id - AND g.page_id = n.page_id - ) - WHEN MATCHED THEN - UPDATE SET g.order# = n.new_order#; - -- - app.log_success(); - EXCEPTION - WHEN app.app_exception THEN - RAISE; - WHEN OTHERS THEN - app.raise_error(); - END; - - - - PROCEDURE refresh_nav_views ( - in_log_id logs.log_id%TYPE, - in_user_id logs.user_id%TYPE, - in_app_id logs.app_id%TYPE, - in_lang_id users.lang_id%TYPE - ) - AS - BEGIN - DBMS_MVIEW.REFRESH('NAV_AVAILABILITY_MVW', 'C', parallelism => 2); - DBMS_MVIEW.REFRESH('NAV_OVERVIEW_MVW', 'C', parallelism => 2); - -- - app_actions.send_message ( - in_app_id => in_app_id, - in_user_id => in_user_id, - in_message => app.get_translated_message('MVW_REFRESHED', in_app_id, in_lang_id) - ); - -- - app.log_success(TO_CHAR(in_log_id)); - EXCEPTION - WHEN OTHERS THEN - app_actions.send_message ( - in_app_id => in_app_id, - in_user_id => in_user_id, - in_message => app.get_translated_message('MVW_FAILED', in_app_id, in_lang_id), - in_type => 'WARNING' - ); - COMMIT; - -- - app.raise_error(); - END; - - - - PROCEDURE refresh_nav_views - AS - v_log_id logs.log_id%TYPE; - v_query VARCHAR2(32767); - BEGIN - v_log_id := app.log_module(); - -- - app.create_job ( - in_job_name => 'RECALC_MVW_NAV', - in_statement => 'app_actions.refresh_nav_views(' - || v_log_id || ', ''' - || app.get_user_id() || ''', ' - || app.get_app_id() || ', ''' - || app.get_user_lang() || '''' - || ');' - ); - EXCEPTION - WHEN app.app_exception THEN - RAISE; - WHEN OTHERS THEN - app.raise_error(); - END; - - - - PROCEDURE save_nav_overview ( - in_action CHAR, - in_app_id navigation.app_id%TYPE, - in_page_id navigation.page_id%TYPE, - in_parent_id navigation.parent_id%TYPE, - in_order# navigation.order#%TYPE, - in_is_hidden navigation.is_hidden%TYPE, - in_is_reset navigation.is_reset%TYPE, - in_is_shared navigation.is_shared%TYPE - ) AS - rec navigation%ROWTYPE; - v_log_id logs.log_id%TYPE; - BEGIN - v_log_id := app.log_module_json ( - 'action', in_action, - 'app_id', in_app_id, - 'page_id', in_page_id, - 'parent_id', in_parent_id, - 'order#', in_order#, - 'is_hidden', in_is_hidden, - 'is_reset', in_is_reset, - 'is_shared', in_is_shared - ); - -- - rec.app_id := COALESCE(in_app_id, app.get_app_id()); - rec.page_id := in_page_id; - rec.parent_id := NULLIF(in_parent_id, 0); - rec.order# := in_order#; - rec.is_hidden := in_is_hidden; - rec.is_reset := in_is_reset; - rec.is_shared := in_is_shared; - rec.updated_by := app.get_user_id(); - rec.updated_at := SYSDATE; - -- - IF in_action = 'D' THEN - DELETE FROM navigation t - WHERE t.app_id = in_app_id - AND t.page_id = in_page_id; - ELSE - UPDATE navigation t - SET ROW = rec - WHERE t.app_id = in_app_id - AND t.page_id = in_page_id; - -- - IF SQL%ROWCOUNT = 0 THEN - INSERT INTO navigation - VALUES rec; - END IF; - END IF; - -- - app.log_success(v_log_id); - EXCEPTION - WHEN app.app_exception THEN - RAISE; - WHEN OTHERS THEN - app.raise_error(); - END; - - - PROCEDURE init_filters AS BEGIN diff --git a/database/packages/nav.spec.sql b/database/packages/nav.spec.sql new file mode 100644 index 0000000..063e848 --- /dev/null +++ b/database/packages/nav.spec.sql @@ -0,0 +1,107 @@ +CREATE OR REPLACE PACKAGE nav AS + + /** + * This package is part of the APP CORE project under MIT licence. + * https://github.com/jkvetina/#core + * + * Copyright (c) Jan Kvetina, 2021 + * + * (R) + * --- --- + * #@@@@@@ &@@@@@@ + * @@@@@@@@ .@ @@@@@@@@ + * ----- @@@@@@ @@@@@@, @@@@@@@ ----- + * &@@@@@@@@@@@ @@@ &@@@@@@@@@. @@@@ .@@@@@@@@@@@# + * @@@@@@@@@@@ @ @@@@@@@@@@@@@ @ @@@@@@@@@@@ + * \@@@@@@@@@@ @@@@@@@@@@@@@@@ @@@@@@@@@@ + * @@@@@@@@@ @@@@@@@@@@@@@@@ &@@@@@@@@ + * @@@@@@@( @@@@@@@@@@@@@@@ @@@@@@@@ + * @@@@@@( @@@@@@@@@@@@@@, @@@@@@@ + * .@@@@@, @@@@@@@@@@@@@ @@@@@@ + * @@@@@@ *@@@@@@@@@@@@@ @@@@@@ + * @@@@@@@@@@@@@@@@@@@@@@@@@@@@@@. + * @@@@@@@@@@@@@@@@@@@@@@@@@@@@@ + * @@@@@@@@@@@@@@@@@@@@@@@@@@@@ + * .@@@@@@@@@@@@@@@@@@@@@@@@@ + * .@@@@@@@@@@@@@@@@@@@@@ + * jankvetina.cz + * ------- + * + */ + + -- ### Help functions + -- + + -- + -- Get HTML alement A + -- + FUNCTION get_html_a ( + in_href VARCHAR2, + in_name VARCHAR2, + in_title VARCHAR2 := NULL + ) + RETURN VARCHAR2; + + + + + + -- ### Navigation page + -- + + -- + -- Remove missing pages from NAVIGATION table + -- + PROCEDURE nav_remove_pages ( + in_page_id navigation.page_id%TYPE := NULL + ); + + + + -- + -- Add new pages to NAVIGATION table + -- + PROCEDURE nav_add_pages ( + in_page_id navigation.page_id%TYPE := NULL + ); + + + + -- + -- Auto update navigation (add missing pages, remove old records) + -- + PROCEDURE nav_autoupdate; + + + + -- + -- Refresh navigation MVW in a background job and inform user + -- + PROCEDURE refresh_nav_views ( + in_log_id logs.log_id%TYPE, + in_user_id logs.user_id%TYPE, + in_app_id logs.app_id%TYPE, + in_lang_id users.lang_id%TYPE + ); + -- + PROCEDURE refresh_nav_views; + + + + -- + -- Save changes on Navigation page + -- + PROCEDURE save_nav_overview ( + in_action CHAR, + in_app_id navigation.app_id%TYPE, + in_page_id navigation.page_id%TYPE, + in_parent_id navigation.parent_id%TYPE, + in_order# navigation.order#%TYPE, + in_is_hidden navigation.is_hidden%TYPE, + in_is_reset navigation.is_reset%TYPE, + in_is_shared navigation.is_shared%TYPE + ); + +END; +/ + diff --git a/database/packages/nav.sql b/database/packages/nav.sql new file mode 100644 index 0000000..9bdc8d6 --- /dev/null +++ b/database/packages/nav.sql @@ -0,0 +1,256 @@ +CREATE OR REPLACE PACKAGE BODY nav AS + + FUNCTION get_html_a ( + in_href VARCHAR2, + in_name VARCHAR2, + in_title VARCHAR2 := NULL + ) + RETURN VARCHAR2 + AS + BEGIN + RETURN '' || in_name || ''; + END; + + + + PROCEDURE nav_remove_pages ( + in_page_id navigation.page_id%TYPE := NULL + ) + AS + in_app_id CONSTANT navigation.app_id%TYPE := app.get_app_id(); + BEGIN + app.log_module(in_page_id); + + -- remove pages and references, related rows + FOR c IN ( + SELECT in_app_id AS app_id, p.page_id + FROM nav_pages_to_remove p + WHERE p.page_id = NVL(in_page_id, p.page_id) + UNION + SELECT n.app_id, n.page_id + FROM navigation n + WHERE n.app_id = in_app_id + AND n.page_id = in_page_id + ) LOOP + app.log_debug('DELETING', c.app_id, c.page_id); + -- + UPDATE navigation n + SET n.parent_id = NULL + WHERE n.app_id = c.app_id + AND n.parent_id = c.page_id; + -- + DELETE FROM translated_items t + WHERE t.app_id = c.app_id + AND t.page_id = c.page_id; + -- + DELETE FROM navigation n + WHERE n.app_id = c.app_id + AND n.page_id = c.page_id; + END LOOP; + -- + app.log_success(); + EXCEPTION + WHEN app.app_exception THEN + RAISE; + WHEN OTHERS THEN + app.raise_error(); + END; + + + + PROCEDURE nav_add_pages ( + in_page_id navigation.page_id%TYPE := NULL + ) + AS + rec navigation%ROWTYPE; + BEGIN + app.log_module(in_page_id); + + -- add pages which are present in APEX but missing in Navigation table + FOR c IN ( + SELECT n.* + FROM nav_pages_to_add n + WHERE n.page_id = NVL(in_page_id, n.page_id) + ) LOOP + app.log_debug('ADDING', c.page_id); + -- + rec.app_id := c.app_id; + rec.page_id := c.page_id; + rec.parent_id := c.parent_id; + rec.order# := c.order#; + rec.is_hidden := c.is_hidden; + rec.is_reset := c.is_reset; + -- + INSERT INTO navigation VALUES rec; + END LOOP; + -- + app.log_success(); + EXCEPTION + WHEN app.app_exception THEN + RAISE; + WHEN OTHERS THEN + app.raise_error(); + END; + + + + PROCEDURE nav_autoupdate + AS + BEGIN + app.log_module(); + -- + nav_remove_pages(); + nav_add_pages(); + + -- renumber sublings + MERGE INTO navigation g + USING ( + SELECT n.app_id, n.page_id, n.new_order# + FROM ( + SELECT + n.app_id, + n.page_id, + n.order#, + ROW_NUMBER() OVER (PARTITION BY n.parent_id ORDER BY n.order#, n.page_id) * 5 + 5 AS new_order# + FROM navigation n + WHERE n.app_id = app.get_app_id() + AND n.parent_id IS NOT NULL + ) n + WHERE n.new_order# != n.order# + ) n + ON ( + g.app_id = n.app_id + AND g.page_id = n.page_id + ) + WHEN MATCHED THEN + UPDATE SET g.order# = n.new_order#; + -- + app.log_success(); + EXCEPTION + WHEN app.app_exception THEN + RAISE; + WHEN OTHERS THEN + app.raise_error(); + END; + + + + PROCEDURE refresh_nav_views ( + in_log_id logs.log_id%TYPE, + in_user_id logs.user_id%TYPE, + in_app_id logs.app_id%TYPE, + in_lang_id users.lang_id%TYPE + ) + AS + BEGIN + DBMS_MVIEW.REFRESH('NAV_AVAILABILITY_MVW', 'C', parallelism => 2); + DBMS_MVIEW.REFRESH('NAV_OVERVIEW_MVW', 'C', parallelism => 2); + -- + app_actions.send_message ( + in_app_id => in_app_id, + in_user_id => in_user_id, + in_message => app.get_translated_message('MVW_REFRESHED', in_app_id, in_lang_id) + ); + -- + app.log_success(TO_CHAR(in_log_id)); + EXCEPTION + WHEN OTHERS THEN + app_actions.send_message ( + in_app_id => in_app_id, + in_user_id => in_user_id, + in_message => app.get_translated_message('MVW_FAILED', in_app_id, in_lang_id), + in_type => 'WARNING' + ); + COMMIT; + -- + app.raise_error(); + END; + + + + PROCEDURE refresh_nav_views + AS + v_log_id logs.log_id%TYPE; + v_query VARCHAR2(32767); + BEGIN + v_log_id := app.log_module(); + -- + app.create_job ( + in_job_name => 'RECALC_MVW_NAV', + in_statement => 'app_actions.refresh_nav_views(' + || v_log_id || ', ''' + || app.get_user_id() || ''', ' + || app.get_app_id() || ', ''' + || app.get_user_lang() || '''' + || ');' + ); + EXCEPTION + WHEN app.app_exception THEN + RAISE; + WHEN OTHERS THEN + app.raise_error(); + END; + + + + PROCEDURE save_nav_overview ( + in_action CHAR, + in_app_id navigation.app_id%TYPE, + in_page_id navigation.page_id%TYPE, + in_parent_id navigation.parent_id%TYPE, + in_order# navigation.order#%TYPE, + in_is_hidden navigation.is_hidden%TYPE, + in_is_reset navigation.is_reset%TYPE, + in_is_shared navigation.is_shared%TYPE + ) AS + rec navigation%ROWTYPE; + v_log_id logs.log_id%TYPE; + BEGIN + v_log_id := app.log_module_json ( + 'action', in_action, + 'app_id', in_app_id, + 'page_id', in_page_id, + 'parent_id', in_parent_id, + 'order#', in_order#, + 'is_hidden', in_is_hidden, + 'is_reset', in_is_reset, + 'is_shared', in_is_shared + ); + -- + rec.app_id := COALESCE(in_app_id, app.get_app_id()); + rec.page_id := in_page_id; + rec.parent_id := NULLIF(in_parent_id, 0); + rec.order# := in_order#; + rec.is_hidden := in_is_hidden; + rec.is_reset := in_is_reset; + rec.is_shared := in_is_shared; + rec.updated_by := app.get_user_id(); + rec.updated_at := SYSDATE; + -- + IF in_action = 'D' THEN + DELETE FROM navigation t + WHERE t.app_id = in_app_id + AND t.page_id = in_page_id; + ELSE + UPDATE navigation t + SET ROW = rec + WHERE t.app_id = in_app_id + AND t.page_id = in_page_id; + -- + IF SQL%ROWCOUNT = 0 THEN + INSERT INTO navigation + VALUES rec; + END IF; + END IF; + -- + app.log_success(v_log_id); + EXCEPTION + WHEN app.app_exception THEN + RAISE; + WHEN OTHERS THEN + app.raise_error(); + END; + +END; +/ + diff --git a/database/triggers/settings__.sql b/database/triggers/settings__.sql index aa70e72..2a46820 100644 --- a/database/triggers/settings__.sql +++ b/database/triggers/settings__.sql @@ -37,7 +37,7 @@ COMPOUND TRIGGER :NEW.updated_at := curr_updated_at; -- check name - IF NOT REGEXP_LIKE(:NEW.setting_name, '^[A-Z0-9_]{1,' || TO_CHAR(30 - NVL(LENGTH(app.settings_prefix), 0)) || '}$') THEN + IF NOT REGEXP_LIKE(:NEW.setting_name, '^[A-Z0-9_]{1,' || TO_CHAR(30 - NVL(LENGTH(constants.get_settings_prefix()), 0)) || '}$') THEN app.raise_error('WRONG_NAME', :NEW.setting_name); END IF; diff --git a/database/views/obj_constraints_fix_dt2.sql b/database/views/obj_constraints_fix_dt2.sql index 92cdca2..b216d3b 100644 --- a/database/views/obj_constraints_fix_dt2.sql +++ b/database/views/obj_constraints_fix_dt2.sql @@ -68,7 +68,7 @@ SELECT r.column_name, s.data_type, -- - LISTAGG(app_actions.get_html_a(app_actions.get_object_link('TABLE', s.table_name), s.table_name), ', ') + LISTAGG(nav.get_html_a(app_actions.get_object_link('TABLE', s.table_name), s.table_name), ', ') WITHIN GROUP (ORDER BY s.table_name) AS list_tables, -- COUNT(s.table_name) AS count_tables, diff --git a/database/views/obj_views.sql b/database/views/obj_views.sql index d063299..5649cee 100644 --- a/database/views/obj_views.sql +++ b/database/views/obj_views.sql @@ -18,12 +18,12 @@ r AS ( NULLIF(SUM(CASE WHEN d.referenced_type IN ('TABLE', 'VIEW') THEN 1 ELSE 0 END), 0) AS count_references, -- LISTAGG(CASE WHEN d.referenced_type = 'TABLE' - THEN app_actions.get_html_a(app_actions.get_object_link(d.referenced_type, d.referenced_name), d.referenced_name) END, ', ') + THEN nav.get_html_a(app_actions.get_object_link(d.referenced_type, d.referenced_name), d.referenced_name) END, ', ') WITHIN GROUP (ORDER BY d.referenced_name) AS referenced_tables, -- LISTAGG(CASE WHEN d.referenced_type = 'VIEW' - THEN app_actions.get_html_a(app_actions.get_object_link(d.referenced_type, d.referenced_name), d.referenced_name) END, ', ') + THEN nav.get_html_a(app_actions.get_object_link(d.referenced_type, d.referenced_name), d.referenced_name) END, ', ') WITHIN GROUP (ORDER BY d.referenced_name) AS referenced_views FROM all_dependencies d @@ -38,7 +38,7 @@ u AS ( SELECT /*+ MATERIALIZE */ d.referenced_name AS view_name, -- - LISTAGG(app_actions.get_html_a(app_actions.get_object_link(d.type, d.name), d.name), ', ') + LISTAGG(nav.get_html_a(app_actions.get_object_link(d.type, d.name), d.name), ', ') WITHIN GROUP (ORDER BY d.name) AS used_in_objects FROM all_dependencies d JOIN x @@ -49,7 +49,7 @@ u AS ( p AS ( SELECT /*+ MATERIALIZE */ r.table_name, - LISTAGG(DISTINCT app_actions.get_html_a(app.get_page_url(910, 'P910_PAGE_ID', r.page_id), r.page_id), ', ') + LISTAGG(DISTINCT nav.get_html_a(app.get_page_url(910, 'P910_PAGE_ID', r.page_id), r.page_id), ', ') WITHIN GROUP (ORDER BY r.page_id) AS used_on_pages FROM apex_application_page_regions r JOIN x diff --git a/database/views/roles_auth_schemes.sql b/database/views/roles_auth_schemes.sql index f0a1ee8..3af2451 100644 --- a/database/views/roles_auth_schemes.sql +++ b/database/views/roles_auth_schemes.sql @@ -50,7 +50,7 @@ SELECT r.role_id, r.role_group, -- - app_actions.get_html_a( + nav.get_html_a( app.get_page_url(920, in_names => 'P920_CREATE_SCHEME,P920_AUTH_SCHEME', in_values => 'Y,' || r.role_id