Move some non-essential logic from app to app_actions

This commit is contained in:
Jan Kvetina 2021-12-23 22:55:08 +01:00
parent 6b17cbfe66
commit f441421511
6 changed files with 247 additions and 194 deletions

View File

@ -22,7 +22,7 @@ wwv_flow_api.create_page(
,p_page_template_options=>'#DEFAULT#'
,p_required_role=>wwv_flow_api.id(9556407311505078)
,p_last_updated_by=>'DEV'
,p_last_upd_yyyymmddhh24miss=>'20211223202835'
,p_last_upd_yyyymmddhh24miss=>'20211223214227'
);
wwv_flow_api.create_page_plug(
p_id=>wwv_flow_api.id(9192009232668637)
@ -838,7 +838,7 @@ wwv_flow_api.create_page_process(
,p_process_type=>'NATIVE_PLSQL'
,p_process_name=>'ADD_PAGE'
,p_process_sql_clob=>wwv_flow_string.join(wwv_flow_t_varchar2(
'app.nav_add_pages(:P910_PAGE_ID);',
'app_actions.nav_add_pages(:P910_PAGE_ID);',
':P910_ACTION := NULL;',
''))
,p_process_clob_language=>'PLSQL'
@ -854,7 +854,7 @@ wwv_flow_api.create_page_process(
,p_process_type=>'NATIVE_PLSQL'
,p_process_name=>'REMOVE_PAGE'
,p_process_sql_clob=>wwv_flow_string.join(wwv_flow_t_varchar2(
'app.nav_remove_pages(:P910_PAGE_ID);',
'app_actions.nav_remove_pages(:P910_PAGE_ID);',
':P910_ACTION := NULL;',
''))
,p_process_clob_language=>'PLSQL'
@ -884,8 +884,7 @@ wwv_flow_api.create_page_process(
,p_process_type=>'NATIVE_PLSQL'
,p_process_name=>'AUTO_UPDATE'
,p_process_sql_clob=>wwv_flow_string.join(wwv_flow_t_varchar2(
'app.nav_remove_pages();',
'app.nav_add_pages();',
'app_actions.nav_autoupdate();',
''))
,p_process_clob_language=>'PLSQL'
,p_error_display_location=>'INLINE_IN_NOTIFICATION'

View File

@ -22,7 +22,7 @@ wwv_flow_api.create_page(
,p_page_template_options=>'#DEFAULT#'
,p_required_role=>wwv_flow_api.id(9823062898204869)
,p_last_updated_by=>'DEV'
,p_last_upd_yyyymmddhh24miss=>'20211223203814'
,p_last_upd_yyyymmddhh24miss=>'20211223214132'
);
wwv_flow_api.create_page_plug(
p_id=>wwv_flow_api.id(9563395243581646)
@ -524,7 +524,7 @@ wwv_flow_api.create_ig_report_column(
,p_view_id=>wwv_flow_api.id(9619064172238094)
,p_display_seq=>12
,p_column_id=>wwv_flow_api.id(9614276104237528)
,p_is_visible=>true
,p_is_visible=>false
,p_is_frozen=>false
,p_width=>114
);
@ -5120,82 +5120,7 @@ wwv_flow_api.create_page_process(
,p_process_type=>'NATIVE_PLSQL'
,p_process_name=>'PREP_USER_ROLES'
,p_process_sql_clob=>wwv_flow_string.join(wwv_flow_t_varchar2(
'DECLARE',
' FUNCTION get_role_name (',
' in_role_id roles.role_id%TYPE',
' )',
' RETURN roles.role_name%TYPE',
' AS',
' out_name roles.role_name%TYPE;',
' BEGIN',
' SELECT NVL(r.role_name, r.role_id) INTO out_name',
' FROM roles r',
' WHERE r.app_id = app.get_app_id()',
' AND r.role_id = in_role_id;',
' --',
' RETURN out_name;',
' EXCEPTION',
' WHEN NO_DATA_FOUND THEN',
' RETURN in_role_id;',
' END;',
' --',
' PROCEDURE user_roles_pivot_collection (',
' in_page_id apex_application_pages.page_id%TYPE',
' ) AS',
' in_collection CONSTANT apex_collections.collection_name%TYPE := ''P'' || TO_CHAR(in_page_id);',
' --',
' v_query VARCHAR2(32767);',
' v_cols PLS_INTEGER;',
' v_cursor PLS_INTEGER := DBMS_SQL.OPEN_CURSOR;',
' v_desc DBMS_SQL.DESC_TAB;',
' BEGIN',
' -- build query',
' v_query := v_query || ''SELECT'' || CHR(10) || '' u.user_id,'';',
' --',
' FOR r IN (',
' SELECT r.role_id',
' FROM roles r',
' WHERE r.app_id = app.get_app_id()',
' ORDER BY r.role_group NULLS LAST, r.order# NULLS LAST, r.role_id',
' ) LOOP',
' v_query := v_query || CHR(10) || '' MAX(CASE WHEN r.role_id = '''''' || r.role_id || '''''' THEN ''''Y'''' END) AS '' || LOWER(r.role_id) || ''_, '';',
' END LOOP;',
' --',
' v_query := RTRIM(v_query, '', '') || CHR(10) || ''FROM users u LEFT JOIN user_roles r ON r.app_id = app.get_app_id() AND r.user_id = u.user_id'' || CHR(10) || ''GROUP BY u.user_id'';',
' --',
' DBMS_OUTPUT.PUT_LINE(v_query);',
'',
' -- initialize and populate collection',
' IF APEX_COLLECTION.COLLECTION_EXISTS(in_collection) THEN',
' APEX_COLLECTION.DELETE_COLLECTION(in_collection);',
' END IF;',
' --',
' APEX_COLLECTION.CREATE_COLLECTION_FROM_QUERY (',
' p_collection_name => in_collection,',
' p_query => v_query',
' );',
'',
' -- pass proper column names via page items',
' DBMS_SQL.PARSE(v_cursor, v_query, DBMS_SQL.NATIVE);',
' DBMS_SQL.DESCRIBE_COLUMNS(v_cursor, v_cols, v_desc);',
' DBMS_SQL.CLOSE_CURSOR(v_cursor);',
' --',
' FOR i IN 1 .. v_desc.COUNT LOOP',
' BEGIN',
' APEX_UTIL.SET_SESSION_STATE (',
' p_name => ''P'' || in_page_id || ''_C'' || LPAD(i, 3, 0),',
' p_value => get_role_name(RTRIM(v_desc(i).col_name, ''_'')),',
' p_commit => FALSE',
' );',
' EXCEPTION',
' WHEN OTHERS THEN',
' NULL; -- item might not exists',
' END;',
' END LOOP;',
' END;',
'BEGIN',
' user_roles_pivot_collection(:APP_PAGE_ID);',
'END;',
'app_actions.prep_user_roles_pivot(:APP_PAGE_ID);',
''))
,p_process_clob_language=>'PLSQL'
,p_error_display_location=>'INLINE_IN_NOTIFICATION'

View File

@ -387,31 +387,6 @@ CREATE OR REPLACE PACKAGE app AS
--
-- 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;
--
-- Redirect to page and set items if needed
--

View File

@ -839,92 +839,6 @@ CREATE OR REPLACE PACKAGE BODY app AS
PROCEDURE nav_remove_pages (
in_page_id navigation.page_id%TYPE := NULL
)
AS
BEGIN
app.log_module(in_page_id);
-- remove references
FOR c IN (
SELECT n.app_id, n.page_id
FROM navigation n
JOIN nav_pages_to_remove p
ON p.page_id = n.parent_id
AND n.page_id = NVL(in_page_id, n.page_id)
WHERE n.app_id = app.get_app_id()
) LOOP
app.log_debug('REMOVING_PARENT', c.page_id);
--
UPDATE navigation n
SET n.parent_id = NULL
WHERE n.app_id = c.app_id
AND n.page_id = c.page_id;
END LOOP;
-- remove rows for pages which dont exists
FOR c IN (
SELECT p.page_id
FROM nav_pages_to_remove p
WHERE p.page_id = NVL(in_page_id, p.page_id)
) LOOP
app.log_debug('DELETING', c.page_id);
--
DELETE FROM navigation n
WHERE n.app_id = app.get_app_id()
AND n.page_id = c.page_id;
END LOOP;
--
app.log_success();
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();
END;
PROCEDURE nav_autoupdate
AS
BEGIN
app.log_module();
--
app.nav_remove_pages();
app.nav_add_pages();
--
app.log_success();
END;
PROCEDURE redirect (
in_page_id NUMBER := NULL,
in_names VARCHAR2 := NULL,

View File

@ -0,0 +1,75 @@
CREATE OR REPLACE PACKAGE app_actions 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
* -------
*
*/
--
-- 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;
--
--
--
FUNCTION get_role_name (
in_role_id roles.role_id%TYPE
)
RETURN roles.role_name%TYPE;
--
--
--
PROCEDURE prep_user_roles_pivot (
in_page_id apex_application_pages.page_id%TYPE
);
END;
/

165
packages/app_actions.sql Normal file
View File

@ -0,0 +1,165 @@
CREATE OR REPLACE PACKAGE BODY app_actions AS
PROCEDURE nav_remove_pages (
in_page_id navigation.page_id%TYPE := NULL
)
AS
BEGIN
app.log_module(in_page_id);
-- remove references
FOR c IN (
SELECT n.app_id, n.page_id
FROM navigation n
JOIN nav_pages_to_remove p
ON p.page_id = n.parent_id
AND n.page_id = NVL(in_page_id, n.page_id)
WHERE n.app_id = app.get_app_id()
) LOOP
app.log_debug('REMOVING_PARENT', c.page_id);
--
UPDATE navigation n
SET n.parent_id = NULL
WHERE n.app_id = c.app_id
AND n.page_id = c.page_id;
END LOOP;
-- remove rows for pages which dont exists
FOR c IN (
SELECT p.page_id
FROM nav_pages_to_remove p
WHERE p.page_id = NVL(in_page_id, p.page_id)
) LOOP
app.log_debug('DELETING', c.page_id);
--
DELETE FROM navigation n
WHERE n.app_id = app.get_app_id()
AND n.page_id = c.page_id;
END LOOP;
--
app.log_success();
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();
END;
PROCEDURE nav_autoupdate
AS
BEGIN
app.log_module();
--
nav_remove_pages();
nav_add_pages();
--
app.log_success();
END;
FUNCTION get_role_name (
in_role_id roles.role_id%TYPE
)
RETURN roles.role_name%TYPE
AS
out_name roles.role_name%TYPE;
BEGIN
SELECT NVL(r.role_name, r.role_id) INTO out_name
FROM roles r
WHERE r.app_id = app.get_app_id()
AND r.role_id = in_role_id;
--
RETURN out_name;
EXCEPTION
WHEN NO_DATA_FOUND THEN
RETURN in_role_id;
END;
PROCEDURE prep_user_roles_pivot (
in_page_id apex_application_pages.page_id%TYPE
) AS
in_collection CONSTANT apex_collections.collection_name%TYPE := 'P' || TO_CHAR(in_page_id);
--
v_query VARCHAR2(32767);
v_cols PLS_INTEGER;
v_cursor PLS_INTEGER := DBMS_SQL.OPEN_CURSOR;
v_desc DBMS_SQL.DESC_TAB;
BEGIN
-- build query
v_query := v_query || 'SELECT' || CHR(10) || ' u.user_id,';
--
FOR r IN (
SELECT r.role_id
FROM roles r
WHERE r.app_id = app.get_app_id()
ORDER BY r.role_group NULLS LAST, r.order# NULLS LAST, r.role_id
) LOOP
v_query := v_query || CHR(10) || ' MAX(CASE WHEN r.role_id = ''' || r.role_id || ''' THEN ''Y'' END) AS ' || LOWER(r.role_id) || '_, ';
END LOOP;
--
v_query := RTRIM(v_query, ', ') || CHR(10) || 'FROM users u LEFT JOIN user_roles r ON r.app_id = app.get_app_id() AND r.user_id = u.user_id' || CHR(10) || 'GROUP BY u.user_id';
--
DBMS_OUTPUT.PUT_LINE(v_query);
-- initialize and populate collection
IF APEX_COLLECTION.COLLECTION_EXISTS(in_collection) THEN
APEX_COLLECTION.DELETE_COLLECTION(in_collection);
END IF;
--
APEX_COLLECTION.CREATE_COLLECTION_FROM_QUERY (
p_collection_name => in_collection,
p_query => v_query
);
-- pass proper column names via page items
DBMS_SQL.PARSE(v_cursor, v_query, DBMS_SQL.NATIVE);
DBMS_SQL.DESCRIBE_COLUMNS(v_cursor, v_cols, v_desc);
DBMS_SQL.CLOSE_CURSOR(v_cursor);
--
FOR i IN 1 .. v_desc.COUNT LOOP
BEGIN
APEX_UTIL.SET_SESSION_STATE (
p_name => 'P' || in_page_id || '_C' || LPAD(i, 3, 0),
p_value => get_role_name(RTRIM(v_desc(i).col_name, '_')),
p_commit => FALSE
);
EXCEPTION
WHEN OTHERS THEN
NULL; -- item might not exists
END;
END LOOP;
END;
END;
/