Skip to content

Commit

Permalink
Don't drop partitions
Browse files Browse the repository at this point in the history
Various updates to script forced by change purge to truncate rather than drop tree selector partitions.
  • Loading branch information
davidkurtz committed Oct 7, 2022
1 parent cca5fbf commit 7cd27b9
Show file tree
Hide file tree
Showing 6 changed files with 47 additions and 26 deletions.
2 changes: 1 addition & 1 deletion nvision_current_schema_trigger.sql
Original file line number Diff line number Diff line change
Expand Up @@ -9,7 +9,7 @@ FOR EACH ROW
WHEN (new.runstatus IN('7') AND new.prcsname IN('RPTBOOK','NVSRUN') AND new.prcstype like 'nVision%')
BEGIN
--EXECUTE IMMEDIATE 'ALTER SESSION SET current_schema = NVEXEC'||LTRIM(TO_CHAR(dbms_utility.get_hash_value(:new.prcsinstance,1,16),'00'));
EXECUTE IMMEDIATE 'ALTER SESSION SET current_schema = NVEXEC'||LTRIM(TO_CHAR(MOD(:new.prcsinstance,16),'00'));
EXECUTE IMMEDIATE 'ALTER SESSION SET current_schema = NVEXEC'||LTRIM(TO_CHAR(MOD(:new.prcsinstance,64),'00'));
EXCEPTION WHEN OTHERS THEN NULL; --exception deliberately coded to suppress all exceptions
END;
/
Expand Down
12 changes: 8 additions & 4 deletions nvision_dynamic_selectors.sql
Original file line number Diff line number Diff line change
Expand Up @@ -79,6 +79,7 @@ EXCEPTION WHEN OTHERS THEN NULL; --exception deliberately coded to suppress all
END;
/
show errors
ALTER TRIGGER sysadm.xx_nvision_end DISABLE;
pause
--------------------------------------------------------------------------------
--mark/unmark static selectors
Expand Down Expand Up @@ -131,12 +132,13 @@ BEGIN
SELECT owner, table_name, SUBSTR(table_name,-2) length
FROM all_tables t
WHERE table_name LIKE 'PSTREESELECT__'
AND (owner = 'SYSADM' OR owner like 'NVEXEC%')
) LOOP
l_sql := 'INSERT INTO ps_nvs_treeslctlog (selector_num, process_instance, length, num_rows, timestamp, module, appinfo_action, client_info, status_flag, tree_name, ownerid, partition_name, job_no) SELECT s.selector_num, 0, '||i.length||', COUNT(*), SYSDATE, '' '', '' '', '' '', ''I'', '' '', '''||i.owner||''', '' '', 0
FROM '||i.owner||'.'||i.table_name||' s WHERE NOT EXISTS(SELECT 1 FROM ps_nvs_treeslctlog l WHERE l.selector_num = s.selector_num) GROUP BY s.selector_num';
dbms_output.put_line(l_sql);
--dbms_output.put_line(l_sql);
EXECUTE IMMEDIATE l_sql;
dbms_output.put_line(SQL%ROWCOUNT||' rows inserted');
dbms_output.put_line(i.owner||'.'||i.table_name||':'||SQL%ROWCOUNT||' rows inserted');
END LOOP;
END;
/
Expand All @@ -160,6 +162,7 @@ BEGIN
AND t.partition_name = o.subobject_name
AND o.owner = t.table_owner
AND o.object_Type = 'TABLE PARTITION'
AND (o.owner = 'SYSADM' OR o.owner like 'NVEXEC%')
) LOOP
l_high_Value := i.high_Value;
l_selector_Num := TO_NUMBER(l_high_value)-1;
Expand Down Expand Up @@ -298,11 +301,11 @@ DECLARE
l_sql CLOB;
BEGIN
FOR i IN (
SELECT selector_num, length
SELECT ownerid, selector_num, length
FROM ps_nvs_treeslctlog l
WHERE num_rows = 0
) LOOP
l_sql := 'SELECT COUNT(*) FROM PSTREESELECT'||LTRIM(TO_CHAR(i.length,'00'))||' WHERE selector_num = :1';
l_sql := 'SELECT COUNT(*) FROM '||i.ownerid||'.PSTREESELECT'||LTRIM(TO_CHAR(i.length,'00'))||' WHERE selector_num = :1';
EXECUTE IMMEDIATE l_sql INTO l_num_rows USING i.selector_num;
dbms_output.put_line(l_sql||':'||l_num_rows);
IF l_num_rows > 0 THEN
Expand All @@ -326,6 +329,7 @@ BEGIN
SELECT table_owner, table_name, partition_position, partition_name, high_value, high_value_length
FROM all_tab_partitions p
WHERE table_name LIKE 'PSTREESELECT__'
AND (table_owner = 'SYSADM' OR table_owner like 'NVEXEC%')
ORDER BY table_name, partition_position desc
) LOOP
l_selector_num := SUBSTR(i.high_value,1,i.high_value_length) - 1;
Expand Down
27 changes: 13 additions & 14 deletions pstreeselect_interval_partitioning.txt
Original file line number Diff line number Diff line change
Expand Up @@ -10,7 +10,7 @@ CREATE TABLE PSYPSTREESELECT05 (SELECTOR_NUM INTEGER NOT NULL,
PARTITION BY RANGE (selector_num) INTERVAL (1)
(PARTITION VALUES LESS THAN(2))
TABLESPACE "PTWORK"
STORAGE(INITIAL 128K NEXT 128K)
STORAGE(INITIAL 64K NEXT 64K)
/
INSERT INTO PSYPSTREESELECT05 (
SELECTOR_NUM,
Expand All @@ -36,15 +36,15 @@ CREATE UNIQUE INDEX PS_PSTREESELECT05 ON PSTREESELECT05 (SELECTOR_NUM
RANGE_FROM_05,
RANGE_TO_05)
local PCTFREE 5 COMPRESS 1
TABLESPACE "PSINDEX"
TABLESPACE "PSINDEX" STORAGE(INITIAL 64K NEXT 64K)
/
ALTER INDEX PS_PSTREESELECT05 NOPARALLEL LOGGING
/
CREATE INDEX PSAPSTREESELECT05 ON PSTREESELECT05 (SELECTOR_NUM,
RANGE_FROM_05,
RANGE_TO_05,
TREE_NODE_NUM)
local PCTFREE 5 COMPRESS 1 TABLESPACE "PSINDEX"
local PCTFREE 5 COMPRESS 1 TABLESPACE "PSINDEX" STORAGE(INITIAL 64K NEXT 64K)
/
ALTER INDEX PSAPSTREESELECT05 NOPARALLEL LOGGING
/
Expand All @@ -69,7 +69,7 @@ CREATE TABLE PSYPSTREESELECT06 (SELECTOR_NUM INTEGER NOT NULL,
PARTITION BY RANGE (selector_num) INTERVAL (1)
(PARTITION VALUES LESS THAN(2))
TABLESPACE "PTWORK"
STORAGE(INITIAL 128K NEXT 128K)
STORAGE(INITIAL 64K NEXT 64K)
/
INSERT INTO PSYPSTREESELECT06 (
SELECTOR_NUM,
Expand All @@ -95,15 +95,15 @@ CREATE UNIQUE INDEX PS_PSTREESELECT06 ON PSTREESELECT06 (SELECTOR_NUM
RANGE_FROM_06,
RANGE_TO_06)
local PCTFREE 5 COMPRESS 1
TABLESPACE "PSINDEX"
TABLESPACE "PSINDEX" STORAGE(INITIAL 64K NEXT 64K)
/
ALTER INDEX PS_PSTREESELECT06 NOPARALLEL LOGGING
/
CREATE INDEX PSAPSTREESELECT06 ON PSTREESELECT06 (SELECTOR_NUM,
RANGE_FROM_06,
RANGE_TO_06,
TREE_NODE_NUM)
local PCTFREE 5 COMPRESS 1 TABLESPACE "PSINDEX"
local PCTFREE 5 COMPRESS 1 TABLESPACE "PSINDEX" STORAGE(INITIAL 64K NEXT 64K)
/
ALTER INDEX PSAPSTREESELECT06 NOPARALLEL LOGGING
/
Expand All @@ -128,7 +128,7 @@ CREATE TABLE PSYPSTREESELECT08 (SELECTOR_NUM INTEGER NOT NULL,
PARTITION BY RANGE (selector_num) INTERVAL (1)
(PARTITION VALUES LESS THAN(2))
TABLESPACE "PTWORK"
STORAGE(INITIAL 128K NEXT 128K)
STORAGE(INITIAL 64K NEXT 64K)
/
INSERT INTO PSYPSTREESELECT08 (
SELECTOR_NUM,
Expand All @@ -153,15 +153,15 @@ CREATE UNIQUE INDEX PS_PSTREESELECT08 ON PSTREESELECT08 (SELECTOR_NUM
TREE_NODE_NUM,
RANGE_FROM_08,
RANGE_TO_08)
local PCTFREE 5 COMPRESS 1 TABLESPACE "PSINDEX"
local PCTFREE 5 COMPRESS 1 TABLESPACE "PSINDEX" STORAGE(INITIAL 64K NEXT 64K)
/
ALTER INDEX PS_PSTREESELECT08 NOPARALLEL LOGGING
/
CREATE INDEX PSAPSTREESELECT08 ON PSTREESELECT08 (SELECTOR_NUM,
RANGE_FROM_08,
RANGE_TO_08,
TREE_NODE_NUM)
local PCTFREE 5 COMPRESS 1 TABLESPACE "PSINDEX"
local PCTFREE 5 COMPRESS 1 TABLESPACE "PSINDEX" STORAGE(INITIAL 64K NEXT 64K)
/
ALTER INDEX PSAPSTREESELECT08 NOPARALLEL LOGGING
/
Expand Down Expand Up @@ -193,7 +193,7 @@ CREATE TABLE PSYPSTREESELECT10 (SELECTOR_NUM INTEGER NOT NULL,
PARTITION BY RANGE (selector_num) INTERVAL (1)
(PARTITION VALUES LESS THAN(2))
TABLESPACE "PTWORK"
STORAGE(INITIAL 128K NEXT 128K)
STORAGE(INITIAL 64K NEXT 64K)
/
INSERT INTO PSYPSTREESELECT10 (
SELECTOR_NUM,
Expand All @@ -213,20 +213,19 @@ DROP TABLE PSTREESELECT10
/
ALTER TABLE PSYPSTREESELECT10 RENAME TO PSTREESELECT10
/
CREATE UNIQUE INDEX PS_PSTREESELECT10 ON PSTREESELECT10 (SELECTOR_NUM
,
CREATE UNIQUE INDEX PS_PSTREESELECT10 ON PSTREESELECT10 (SELECTOR_NUM,
TREE_NODE_NUM,
RANGE_FROM_10,
RANGE_TO_10)
local PCTFREE 5 COMPRESS 1 TABLESPACE "PSINDEX"
local PCTFREE 5 COMPRESS 1 TABLESPACE "PSINDEX" STORAGE(INITIAL 64K NEXT 64K)
/
ALTER INDEX PS_PSTREESELECT10 NOPARALLEL LOGGING
/
CREATE INDEX PSAPSTREESELECT10 ON PSTREESELECT10 (SELECTOR_NUM,
RANGE_FROM_10,
RANGE_TO_10,
TREE_NODE_NUM)
local PCTFREE 5 COMPRESS 1 TABLESPACE "PSINDEX"
local PCTFREE 5 COMPRESS 1 TABLESPACE "PSINDEX" STORAGE(INITIAL 64K NEXT 64K)
/
ALTER INDEX PSAPSTREESELECT10 NOPARALLEL LOGGING
/
Expand Down
17 changes: 15 additions & 2 deletions treeselector_statprefs.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,7 +7,7 @@ begin
, SUBSTR(t.table_name,-2) length
FROM all_users u
, all_tables t
WHERE u.username like 'NVEXEC%'
WHERE (u.username = 'SYSADM' OR u.username like 'NVEXEC%')
AND t.owner = u.username
AND t.table_name like 'PSTREESELECT__'
) LOOP
Expand All @@ -19,19 +19,32 @@ begin
,'FOR ALL COLUMNS SIZE AUTO FOR COLUMNS SIZE 254 SELECTOR_NUM TREE_NODE_NUM FOR COLUMNS SIZE 1 RANGE_FROM_'||i.length||
' RANGE_TO_'||i.length||' (SELECTOR_NUM, TREE_NODE_NUM) (SELECTOR_NUM, RANGE_FROM_'||i.length||') (SELECTOR_NUM, RANGE_TO_'||i.length||')'
);
dbms_stats.gather_table_stats(i.owner,i.table_name);
END LOOP;
end;
/


set lines 200
set lines 200 pages 99
break on owner skip 1 on table_name skip 1
column owner format a10
column partition_name format a20
column preference_value format a100 word_wrapped on
column table_name format a18
select *
from all_tab_stat_prefs
where table_name like 'PSTREESELECT__'
and (owner = 'SYSADM' or owner like 'NVEXEC%')
order by 1,2,3
/

select owner, table_name, partition_position, partition_name, num_rows, blocks, last_analyzed
from all_tab_statistics
where table_name like 'PSTREESELECT__'
and (owner = 'SYSADM' or owner like 'NVEXEC%')
--and partitioned = 'YES'
order by owner, table_name, partition_position nulls first
/

spool off
break on report
5 changes: 3 additions & 2 deletions treeselector_triggers.sql
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
REM treeselector_triggers.sql
set serveroutput on echo on
clear screen
spool treeselector_triggers
--------------------------------------------------------------------------------
--log selector population - dynamically create insert/delete triggers
Expand All @@ -25,9 +26,9 @@ BEGIN
WHERE r.recname = r.sqltablename
AND r.recname like 'PSTREESELECT__'
AND t.table_name = r.sqltablename
AND (t.owner = 'SYSADM' or t.owner LIKE 'NVEXEC%')
) LOOP
l_cmd := 'CREATE OR REPLACE TRIGGER '||i.owner||'.'||LOWER(i.recname||'_'||i.action)||'
FOR '||i.action||' ON '||i.owner||'.'||i.recname||' compound trigger
l_cmd := 'CREATE OR REPLACE TRIGGER '||i.owner||'.'||LOWER(i.recname||'_'||i.action)||' FOR '||i.action||' ON '||i.owner||'.'||i.recname||' compound trigger
l_err_msg VARCHAR2(100 CHAR);
AFTER EACH ROW IS
BEGIN
Expand Down
10 changes: 7 additions & 3 deletions xx_nvision_selectors.sql
Original file line number Diff line number Diff line change
Expand Up @@ -103,7 +103,7 @@ EXCEPTION
RETURN(l_partition_name);
END;
--------------------------------------------------------------------------------
--drop partition in a selector table
--truncate partition in a selector table
--------------------------------------------------------------------------------
PROCEDURE purge_selector
(p_length INTEGER
Expand Down Expand Up @@ -148,7 +148,10 @@ BEGIN
-- EXECUTE IMMEDIATE l_cmd INTO l_num_rows;
-- debug_msg(l_cmd||':'||l_num_rows);

l_cmd := 'ALTER TABLE '||p_ownerid||'.'||l_table_name||' DROP PARTITION '||l_partition_name||' UPDATE INDEXES';
l_cmd := 'ALTER TABLE '||p_ownerid||'.'||l_table_name||' TRUNCATE PARTITION '||l_partition_name||' UPDATE INDEXES DROP STORAGE';
--cannot drop partitions because they do not get created again when the selector number recycles
--l_cmd := 'ALTER TABLE '||p_ownerid||'.'||l_table_name||' DROP PARTITION '||l_partition_name||' UPDATE INDEXES';

debug_msg(l_cmd);
EXECUTE IMMEDIATE l_cmd;
l_cmd := '';
Expand Down Expand Up @@ -687,13 +690,14 @@ BEGIN
AND table_name = l_table_name
ORDER BY table_name, partition_position desc
) LOOP
l_selector_num := SUBSTR(i.high_value,1,i.high_value_length) - 1; /*seletor high value-1*/
l_selector_num := SUBSTR(i.high_value,1,i.high_value_length) - 1; /*selector high value-1*/
IF l_selector_num = g_selector_num THEN
l_partition_name := i.partition_name;
debug_msg('Partition:'||l_partition_name);
EXIT;
ELSIF l_selector_num < g_selector_num THEN
debug_msg('No Partition identified');
l_partition_name := ' '; /*added 6.10.2022*/
EXIT;
END IF;
END LOOP;
Expand Down

0 comments on commit 7cd27b9

Please sign in to comment.