From d8f60cb3433efd18babac25c759f4146d9deb985 Mon Sep 17 00:00:00 2001 From: Jan Kvetina Date: Mon, 31 Jan 2022 21:20:24 +0100 Subject: [PATCH] Views cleanup, show # of referenced objects --- apex/f770/application/pages/page_00955.sql | 58 ++++++++-- packages/app.spec.sql | 14 +++ packages/app.sql | 122 +++++++++++++++++++++ packages/app_actions.spec.sql | 27 ----- packages/app_actions.sql | 116 -------------------- views/obj_views.sql | 12 +- 6 files changed, 190 insertions(+), 159 deletions(-) diff --git a/apex/f770/application/pages/page_00955.sql b/apex/f770/application/pages/page_00955.sql index 7ea8700..669ce05 100644 --- a/apex/f770/application/pages/page_00955.sql +++ b/apex/f770/application/pages/page_00955.sql @@ -200,7 +200,7 @@ wwv_flow_api.create_region_column( ,p_item_type=>'NATIVE_SINGLE_CHECKBOX' ,p_heading=>'Readonly' ,p_heading_alignment=>'CENTER' -,p_display_sequence=>100 +,p_display_sequence=>110 ,p_value_alignment=>'CENTER' ,p_group_id=>wwv_flow_api.id(16023054809727215) ,p_use_group_for=>'BOTH' @@ -231,7 +231,7 @@ wwv_flow_api.create_region_column( ,p_item_type=>'NATIVE_DISPLAY_ONLY' ,p_heading=>'Last Ddl Time' ,p_heading_alignment=>'CENTER' -,p_display_sequence=>130 +,p_display_sequence=>140 ,p_value_alignment=>'CENTER' ,p_attribute_02=>'VALUE' ,p_attribute_05=>'PLAIN' @@ -285,7 +285,7 @@ wwv_flow_api.create_region_column( ,p_item_type=>'NATIVE_SINGLE_CHECKBOX' ,p_heading=>'Definer' ,p_heading_alignment=>'CENTER' -,p_display_sequence=>110 +,p_display_sequence=>120 ,p_value_alignment=>'CENTER' ,p_group_id=>wwv_flow_api.id(16023054809727215) ,p_use_group_for=>'BOTH' @@ -398,7 +398,7 @@ wwv_flow_api.create_region_column( ,p_item_type=>'NATIVE_DISPLAY_ONLY' ,p_heading=>'Comments' ,p_heading_alignment=>'LEFT' -,p_display_sequence=>120 +,p_display_sequence=>130 ,p_value_alignment=>'LEFT' ,p_attribute_02=>'VALUE' ,p_attribute_05=>'PLAIN' @@ -450,7 +450,7 @@ wwv_flow_api.create_region_column( ,p_item_type=>'NATIVE_DISPLAY_ONLY' ,p_heading=>'List Columns' ,p_heading_alignment=>'LEFT' -,p_display_sequence=>90 +,p_display_sequence=>100 ,p_value_alignment=>'LEFT' ,p_attribute_02=>'VALUE' ,p_attribute_05=>'PLAIN' @@ -465,6 +465,33 @@ wwv_flow_api.create_region_column( ,p_is_primary_key=>false ,p_include_in_export=>true ); +wwv_flow_api.create_region_column( + p_id=>wwv_flow_api.id(22085867103580626) +,p_name=>'COUNT_REFERENCES' +,p_source_type=>'DB_COLUMN' +,p_source_expression=>'COUNT_REFERENCES' +,p_data_type=>'NUMBER' +,p_is_query_only=>false +,p_item_type=>'NATIVE_DISPLAY_ONLY' +,p_heading=>'Count' +,p_heading_alignment=>'RIGHT' +,p_display_sequence=>90 +,p_value_alignment=>'RIGHT' +,p_group_id=>wwv_flow_api.id(15339776986749829) +,p_use_group_for=>'BOTH' +,p_attribute_02=>'VALUE' +,p_attribute_05=>'PLAIN' +,p_enable_filter=>true +,p_filter_is_required=>false +,p_filter_lov_type=>'NONE' +,p_use_as_row_header=>false +,p_enable_sort_group=>true +,p_enable_control_break=>true +,p_enable_hide=>true +,p_is_primary_key=>false +,p_duplicate_value=>true +,p_include_in_export=>true +); wwv_flow_api.create_interactive_grid( p_id=>wwv_flow_api.id(14929214006872301) ,p_internal_uid=>14929214006872301 @@ -543,7 +570,7 @@ wwv_flow_api.create_ig_report_column( wwv_flow_api.create_ig_report_column( p_id=>wwv_flow_api.id(14938205769877740) ,p_view_id=>wwv_flow_api.id(14935014538877722) -,p_display_seq=>9 +,p_display_seq=>10 ,p_column_id=>wwv_flow_api.id(14929621363872305) ,p_is_visible=>false ,p_is_frozen=>false @@ -552,7 +579,7 @@ wwv_flow_api.create_ig_report_column( wwv_flow_api.create_ig_report_column( p_id=>wwv_flow_api.id(14940055040877744) ,p_view_id=>wwv_flow_api.id(14935014538877722) -,p_display_seq=>12 +,p_display_seq=>13 ,p_column_id=>wwv_flow_api.id(14929897471872307) ,p_is_visible=>true ,p_is_frozen=>false @@ -569,7 +596,7 @@ wwv_flow_api.create_ig_report_column( wwv_flow_api.create_ig_report_column( p_id=>wwv_flow_api.id(14965446688031898) ,p_view_id=>wwv_flow_api.id(14935014538877722) -,p_display_seq=>10 +,p_display_seq=>11 ,p_column_id=>wwv_flow_api.id(14930051725872309) ,p_is_visible=>false ,p_is_frozen=>false @@ -608,7 +635,7 @@ wwv_flow_api.create_ig_report_column( wwv_flow_api.create_ig_report_column( p_id=>wwv_flow_api.id(16643570436750208) ,p_view_id=>wwv_flow_api.id(14935014538877722) -,p_display_seq=>11 +,p_display_seq=>12 ,p_column_id=>wwv_flow_api.id(16466877978696716) ,p_is_visible=>false ,p_is_frozen=>false @@ -625,11 +652,20 @@ wwv_flow_api.create_ig_report_column( wwv_flow_api.create_ig_report_column( p_id=>wwv_flow_api.id(21563306768800463) ,p_view_id=>wwv_flow_api.id(14935014538877722) -,p_display_seq=>8 +,p_display_seq=>9 ,p_column_id=>wwv_flow_api.id(21541103407954405) ,p_is_visible=>false ,p_is_frozen=>false ); +wwv_flow_api.create_ig_report_column( + p_id=>wwv_flow_api.id(22266916860170945) +,p_view_id=>wwv_flow_api.id(14935014538877722) +,p_display_seq=>8 +,p_column_id=>wwv_flow_api.id(22085867103580626) +,p_is_visible=>true +,p_is_frozen=>false +,p_width=>80 +); wwv_flow_api.create_ig_report( p_id=>wwv_flow_api.id(36527039231747011) ,p_interactive_grid_id=>wwv_flow_api.id(14929214006872301) @@ -1004,7 +1040,7 @@ wwv_flow_api.create_page_process( ,p_process_type=>'NATIVE_PLSQL' ,p_process_name=>'ACTION_REFRESH_VIEWS_SOURCE' ,p_process_sql_clob=>wwv_flow_string.join(wwv_flow_t_varchar2( -'app_actions.refresh_user_source_views();', +'app.refresh_user_source_views();', '')) ,p_process_clob_language=>'PLSQL' ,p_error_display_location=>'INLINE_IN_NOTIFICATION' diff --git a/packages/app.spec.sql b/packages/app.spec.sql index 781d3f7..4f2d26f 100644 --- a/packages/app.spec.sql +++ b/packages/app.spec.sql @@ -1279,6 +1279,20 @@ CREATE OR REPLACE PACKAGE app AS + -- + -- Refresh views source (convert views source from LONG to searchable lines) + -- + PROCEDURE refresh_user_source_views ( + in_view_name VARCHAR2 := NULL, + in_force BOOLEAN := FALSE + ); + + + + + + + -- ### Custom wrappers -- diff --git a/packages/app.sql b/packages/app.sql index 8e4bcc4..a9fac77 100644 --- a/packages/app.sql +++ b/packages/app.sql @@ -2954,6 +2954,128 @@ CREATE OR REPLACE PACKAGE BODY app AS + PROCEDURE refresh_user_source_views ( + in_view_name VARCHAR2 := NULL, + in_force BOOLEAN := FALSE + ) + AS + PRAGMA AUTONOMOUS_TRANSACTION; + -- + in_table_name CONSTANT user_objects.object_name%TYPE := 'USER_SOURCE_VIEWS'; + -- + v_table_time user_objects.last_ddl_time%TYPE; + v_views_time user_objects.last_ddl_time%TYPE; + -- + PROCEDURE clob_to_lines ( + in_name VARCHAR2, + in_clob CLOB, + in_offset NUMBER := NULL + ) + AS + clob_len PLS_INTEGER := DBMS_LOB.GETLENGTH(in_clob); + clob_line PLS_INTEGER := 1; + offset PLS_INTEGER := 1; + amount PLS_INTEGER := 32767; + buffer VARCHAR2(32767); + BEGIN + WHILE offset < clob_len LOOP + IF INSTR(in_clob, CHR(10), offset) = 0 THEN + amount := clob_len - offset + 1; + ELSE + amount := INSTR(in_clob, CHR(10), offset) - offset; + END IF; + -- + IF amount = 0 THEN + buffer := ''; + ELSE + DBMS_LOB.READ(in_clob, amount, offset, buffer); + END IF; + -- + -- @TODO: CREATE & RETURN COLLECTION INSTEAD + -- + IF clob_line > 1 THEN + INSERT INTO user_source_views (name, line, text) + VALUES ( + in_name, + clob_line - 1 - NVL(in_offset, 0), + REPLACE(REPLACE(CASE WHEN clob_line = 2 THEN LTRIM(buffer) ELSE buffer END, CHR(13), ''), CHR(10), '') + ); + END IF; + -- + clob_line := clob_line + 1; + IF INSTR(in_clob, CHR(10), offset) = clob_len THEN + buffer := ''; + END IF; + -- + offset := offset + amount + 1; + END LOOP; + END; + BEGIN + app.log_module(in_view_name, CASE WHEN in_force THEN 'Y' END); + + -- compare timestamps + IF NOT in_force THEN + SELECT o.last_ddl_time INTO v_table_time + FROM user_objects o + WHERE o.object_name = in_table_name + AND o.object_type = 'TABLE'; + -- + SELECT MAX(o.last_ddl_time) INTO v_views_time + FROM user_objects o + WHERE o.object_type = 'VIEW'; + + -- refresh not needed + IF v_table_time > v_views_time THEN + app.log_result('SKIPPING'); + RETURN; + END IF; + ELSE + -- in force mode cleanup whole table + DELETE FROM user_source_views; -- truncate? + END IF; + + -- refresh table content + FOR c IN ( + SELECT + v.view_name, + DBMS_METADATA.GET_DDL('VIEW', v.view_name) AS content + FROM user_views v + JOIN user_objects o + ON o.object_name = v.view_name + AND o.object_type = 'VIEW' + AND (o.last_ddl_time >= v_table_time OR v_table_time IS NULL) + ) LOOP + DELETE FROM user_source_views t + WHERE t.name = c.view_name; + -- + clob_to_lines(c.view_name, REGEXP_REPLACE(c.content, '^(\s*)', '')); + END LOOP; + -- + COMMIT; + + -- alter table to update last refresh date + EXECUTE IMMEDIATE 'ALTER TABLE ' || in_table_name || ' ADD tmp_col NUMBER'; + EXECUTE IMMEDIATE 'ALTER TABLE ' || in_table_name || ' DROP COLUMN tmp_col'; + -- + app.log_success(); + EXCEPTION + WHEN app.app_exception THEN + ROLLBACK; + RAISE; + WHEN OTHERS THEN + ROLLBACK; + app.raise_error(); + END; + + + + + + + + -- ### Dynamic procedure call + -- + -- -- @TODO: -- diff --git a/packages/app_actions.spec.sql b/packages/app_actions.spec.sql index a2eeedb..bf6c9c8 100644 --- a/packages/app_actions.spec.sql +++ b/packages/app_actions.spec.sql @@ -301,33 +301,6 @@ CREATE OR REPLACE PACKAGE app_actions AS - -- ### Views source table - -- - - -- - -- Refresh views source (convert views source to lines) - -- - PROCEDURE refresh_user_source_views ( - in_force BOOLEAN := FALSE - ); - - - - -- - -- Convert VIEW content (LONG) to lines in user_source_view table - -- - PROCEDURE clob_to_lines ( - in_name VARCHAR2, - in_clob CLOB, - in_offset NUMBER := NULL - ); - - - - - - - -- ### E-mails -- diff --git a/packages/app_actions.sql b/packages/app_actions.sql index 24ae304..6da3eaa 100644 --- a/packages/app_actions.sql +++ b/packages/app_actions.sql @@ -844,122 +844,6 @@ CREATE OR REPLACE PACKAGE BODY app_actions AS - PROCEDURE refresh_user_source_views ( - in_force BOOLEAN := FALSE - ) - AS - PRAGMA AUTONOMOUS_TRANSACTION; - -- - in_table_name CONSTANT user_objects.object_name%TYPE := 'USER_SOURCE_VIEWS'; - -- - v_table_time user_objects.last_ddl_time%TYPE; - v_views_time user_objects.last_ddl_time%TYPE; - BEGIN - app.log_module(CASE WHEN in_force THEN 'Y' END); - - -- compare timestamps - IF NOT in_force THEN - SELECT o.last_ddl_time INTO v_table_time - FROM user_objects o - WHERE o.object_name = in_table_name - AND o.object_type = 'TABLE'; - -- - SELECT MAX(o.last_ddl_time) INTO v_views_time - FROM user_objects o - WHERE o.object_type = 'VIEW'; - - -- refresh not needed - IF v_table_time > v_views_time THEN - app.log_result('SKIPPING'); - RETURN; - END IF; - ELSE - -- in force mode cleanup whole table - DELETE FROM user_source_views; -- truncate? - END IF; - - -- refresh table content - FOR c IN ( - SELECT - v.view_name, - DBMS_METADATA.GET_DDL('VIEW', v.view_name) AS content - FROM user_views v - JOIN user_objects o - ON o.object_name = v.view_name - AND o.object_type = 'VIEW' - AND (o.last_ddl_time >= v_table_time OR v_table_time IS NULL) - ) LOOP - DELETE FROM user_source_views t - WHERE t.name = c.view_name; - -- - app_actions.clob_to_lines(c.view_name, REGEXP_REPLACE(c.content, '^(\s*)', '')); - END LOOP; - -- - COMMIT; - - -- alter table to update last refresh date - EXECUTE IMMEDIATE 'ALTER TABLE ' || in_table_name || ' ADD tmp_col NUMBER'; - EXECUTE IMMEDIATE 'ALTER TABLE ' || in_table_name || ' DROP COLUMN tmp_col'; - -- - app.log_success(); - EXCEPTION - WHEN app.app_exception THEN - ROLLBACK; - RAISE; - WHEN OTHERS THEN - ROLLBACK; - app.raise_error(); - END; - - - - PROCEDURE clob_to_lines ( - in_name VARCHAR2, - in_clob CLOB, - in_offset NUMBER := NULL - ) - AS - clob_len PLS_INTEGER := DBMS_LOB.GETLENGTH(in_clob); - clob_line PLS_INTEGER := 1; - offset PLS_INTEGER := 1; - amount PLS_INTEGER := 32767; - buffer VARCHAR2(32767); - BEGIN - WHILE offset < clob_len LOOP - IF INSTR(in_clob, CHR(10), offset) = 0 THEN - amount := clob_len - offset + 1; - ELSE - amount := INSTR(in_clob, CHR(10), offset) - offset; - END IF; - -- - IF amount = 0 THEN - buffer := ''; - ELSE - DBMS_LOB.READ(in_clob, amount, offset, buffer); - END IF; - -- - -- @TODO: CREATE & RETURN COLLECTION INSTEAD - -- - IF clob_line > 1 THEN - INSERT INTO user_source_views (name, line, text) - VALUES ( - in_name, - clob_line - 1 - NVL(in_offset, 0), - REPLACE(REPLACE(CASE WHEN clob_line = 2 THEN LTRIM(buffer) ELSE buffer END, CHR(13), ''), CHR(10), '') - ); - END IF; - -- - clob_line := clob_line + 1; - IF INSTR(in_clob, CHR(10), offset) = clob_len THEN - buffer := ''; - END IF; - -- - offset := offset + amount + 1; - END LOOP; - END; - - - FUNCTION clob_to_blob ( in_clob CLOB ) diff --git a/views/obj_views.sql b/views/obj_views.sql index 2cb20e2..2f11887 100644 --- a/views/obj_views.sql +++ b/views/obj_views.sql @@ -12,7 +12,9 @@ WITH x AS ( ), r AS ( SELECT - d.name AS view_name, + d.name AS view_name, + -- + 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, ', ') @@ -32,7 +34,7 @@ r AS ( ), u AS ( SELECT - d.referenced_name AS view_name, + d.referenced_name AS view_name, -- LISTAGG(app_actions.get_html_a(app_actions.get_object_link(d.type, d.name), d.name), ', ') WITHIN GROUP (ORDER BY d.name) AS used_in_objects @@ -81,9 +83,8 @@ v AS ( ), c AS ( SELECT - c.table_name AS view_name, - -- - COUNT(c.column_name) AS count_columns, + c.table_name AS view_name, + COUNT(c.column_name) AS count_columns, -- LOWER(LISTAGG(c.column_name, ', ') WITHIN GROUP (ORDER BY c.column_id)) AS list_columns, -- @@ -115,6 +116,7 @@ SELECT p.used_on_pages, r.referenced_tables, r.referenced_views, + r.count_references, -- NULLIF(v.read_only, 'N') AS is_readonly, CASE WHEN v.bequeath = 'DEFINER' THEN 'Y' END AS is_definer,