Table/index movement using pl/sql procedure
1 2 |
CREATE TABLESPACE AWS_DATA01 DATAFILE '+DATA' size 10G ##################### PRE-VALIDATIONS ################## |
1) Gather all below data into a SQL log file for future validations
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 |
spool TABLE_INDEX_REORG_REBUILD_PREVALIDATIONS.log set echo on set linesize 300 col index_name for a30 col degree for a10 col status for a10 col table_name for a30 col owner for a30 col object_type for a20 col constraint_type for a20 col constraint_name for a30 col validated for a20 col degree for a10 set pagesize 100 select owner,object_type,status,count(*) from dba_objects where status <> 'VALID' and owner='SCOTT' group by owner,object_type,status order by owner; select owner,index_name,status from dba_indexes where TABLE_OWNER='SCOTT' and status<>'VALID'; select index_name,status from dba_ind_partitions where status <> 'USABLE'; select CONSTRAINT_TYPE,STATUS,count(1) from dba_constraints where owner='SCOTT' group by CONSTRAINT_TYPE,STATUS; set linesize 300 col index_name for a30 col degree for a10 col status for a10 select TABLE_NAME,INDEX_NAME,DEGREE,status from dba_indexes where OWNER='SCOTT' and degree not in (0,1); select object_type , count(*),status from dba_objects where owner=upper('SCOTT') group by object_type,status order by object_type; select table_name,index_name,logging from dba_indexes where OWNER='SCOTT' and logging = 'NO'; select distinct STATUS from v$datafile; select constraint_name,constraint_type,table_name,status,validated from dba_constraints where owner='SCOTT' and status <> 'ENABLED'; select distinct owner from dba_segments where tablespace_name='&tablespace_name'; select distinct owner from dba_tables where tablespace_name='&tablespace_name'; select distinct owner from dba_indexes where tablespace_name='&tablespace_name'; select distinct table_owner from dba_tab_partitions where tablespace_name='&tablespace_name'; select distinct table_owner from dba_tab_subpartitions where tablespace_name='&tablespace_name'; select distinct index_owner from dba_ind_partitions where tablespace_name='&tablespace_name'; select distinct index_owner from dba_ind_subpartitions where tablespace_name='&tablespace_name'; select distinct STATUS from v$datafile; select * from v$recover_file; select distinct segment_type from dba_segments where tablespace_name='&tablespace_name'; select distinct status from dba_indexes; select distinct status from dba_ind_partitions; select distinct status from dba_ind_subpartitions; spool off |
2) Export respective schema and whole DB as part of prechecks.
3) Create a Guaranteed Restore point and drop before dropping tablespace if everything is success.
4) Simpler version of index rebuild
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 |
select 'REM ###### Rebuild of Index '||owner||'.'||index_name|| ' of size => '||mb ||'Mb'||chr(13)||chr(10)|| 'alter index '||owner||'.'||index_name||' rebuild online parallel(degree 8) tablespace SEPHORA_DATA;'||chr(13)||chr(10)|| 'alter index '||owner||'.'||index_name||' noparallel;' from ( select a.owner owner,a.index_name index_name,b.tablespace_name tablespace_name,b.bytes/1024/1024 as mb from dba_indexes a, dba_segments b where a.owner=b.owner and b.tablespace_name='WMS_INDEX' and a.index_name=b.segment_name and b.segment_type='INDEX'); select owner,segment_name,partition_name,tablespace_name,bytes/1024/1024 bytes from dba_segments where segment_type='TABLE PARTITION' and tablespace_name='AWS_DATA' and segment_name not like 'BIN$%' order by bytes/1024/1024 desc; select 'alter table '||i.owner||'.'||i.segment_name||' move partition '|| i.partition_name||' tablespace AWS_DATA01;' from dba_lobs where tablespace_name='AWS_DATA'; set lines 250 pages 350 select 'alter table '||table_owner||'.'||table_name||' move partition '||partition_name||' LOB(' || column_name || ') store as (tablespace AWS_DATA01);' from dba_lob_partitions where tablespace_name='AWS_DATA'; set lines 250 pages 350 select 'alter table '||owner||'.'||table_name||' move LOB(' || column_name || ') store as (tablespace AWS_DATA01);' from dba_lobs where tablespace_name='AWS_DATA'; select a.owner,b.table_name,a.tablespace_name, b.COLUMN_NAME from dba_indexes a , dba_lobs b where a.tablespace_name='AWS_DATA'; select partition_name, lob_partition_name, tablespace_name,table_name ,column_name from dba_lob_partitions where tablespace_name='AWS_DATA'; alter table SHOW_LOB_STORAGE move partition P2 lob(DDD) store as (tablespace PARTFORLOB02); ################################### LOBSEGMENT MOVE ########################################## set linesize 250 SET SERVEROUTPUT ON format WORD_WRAPPED exec dbms_output.enable(100000000); break on segment_name; declare tname varchar2(50); towner varchar2(50); cursor c1 is select a.owner,b.table_name,a.tablespace_name,a.bytes/1024/1024 bytes, b.COLUMN_NAME from dba_segments a , dba_lobs b where a.segment_type='LOBSEGMENT' and a.tablespace_name='AWS_DATA' and a.segment_name not like 'BIN$%' and a.segment_name=b.segment_name order by bytes/1024/1024 desc; begin dbms_output.put_line('set time on'); dbms_output.put_line('set timing on'); dbms_output.put_line('set echo on'); dbms_output.put_line('set verify on'); dbms_output.put_line(chr(5)); dbms_output.put_line('alter session set db_file_multiblock_read_count=128;'); dbms_output.put_line('alter session set resumable_timeout=3600;'); dbms_output.put_line('alter session set "_px_max_granules_per_slave"=3000;'); dbms_output.put_line('alter session set "_px_index_sampling"=3000;'); dbms_output.put_line('alter session set "_px_dynamic_sample_size"=3000;'); dbms_output.put_line(chr(5)); dbms_output.put_line('spool AWS_DATA01_LOB2023.log'); dbms_output.put_line(chr(5)); for i in c1 loop towner := i.owner; tname := i.table_name; dbms_output.put_line('REM --- MOVING TABLE '||i.table_name||' OF SIZE ----> '||i.bytes||' MB ') ; dbms_output.put_line('alter table '||i.owner||'.'||i.table_name||' move LOB(' || i.column_name || ') store as (tablespace AWS_DATA01);'); dbms_output.put_line(''); dbms_output.put_line(chr(3)); dbms_output.put_line('REM *************************************************************************'); dbms_output.put_line(chr(3)); end loop; dbms_output.put_line('spool off'); dbms_output.put_line('exit'); end; / ###################################### INDEX REBUILD ######################### set linesize 300 SET SERVEROUTPUT ON format WORD_WRAPPED exec dbms_output.enable(100000000); break on segment_name; declare tname varchar2(50); towner varchar2(50);\ cursor c2 is select owner,segment_name as index_name,tablespace_name,bytes/1024/1024 as mb from dba_segments where tablespace_name='AWS_DATA' and segment_type='INDEX'; begin dbms_output.put_line('set time on'); dbms_output.put_line('set timing on'); dbms_output.put_line('set echo on'); dbms_output.put_line('set verify on'); dbms_output.put_line(chr(5)); dbms_output.put_line('alter session set db_file_multiblock_read_count=128;'); dbms_output.put_line('alter session set resumable_timeout=3600;'); dbms_output.put_line('alter session set "_px_max_granules_per_slave"=3000;'); dbms_output.put_line('alter session set "_px_index_sampling"=3000;'); dbms_output.put_line('alter session set "_px_dynamic_sample_size"=3000;'); dbms_output.put_line(chr(5)); dbms_output.put_line('spool AWS_DATA01_INDEX_MOVE.log'); dbms_output.put_line(chr(5)); for j in c2 loop dbms_output.put_line(null); dbms_output.put_line(''); dbms_output.put_line(chr(5)); dbms_output.put_line('REM --- REBUILD INDEX '||tname||'.'||j.index_name||' OF SIZE ----> '||j.mb||' MB ') ; dbms_output.put_line('alter index '||j.owner||'.'||j.index_name||' rebuild online parallel(degree 8)tablespace AWS_DATA01;'); dbms_output.put_line('alter index '||j.owner||'.'||j.index_name||' noparallel;'); dbms_output.put_line(''); dbms_output.put_line(chr(3)); dbms_output.put_line('REM *************************************************************************'); dbms_output.put_line(chr(3)); end loop; dbms_output.put_line('spool off'); dbms_output.put_line('exit'); end; / ############################# TABLE WITH SEGMENT MOVEMENT ############################ set linesize 300 SET SERVEROUTPUT ON format WORD_WRAPPED exec dbms_output.enable(90000000000); set linesize 300 break on segment_name; declare tname varchar2(50); towner varchar2(50); cursor c1 is select owner,segment_name,tablespace_name,bytes/1024/1024 bytes from dba_segments where segment_type='TABLE' and tablespace_name='AWS_DATA' and segment_name not like 'BIN$%' order by bytes/1024/1024 desc; begin dbms_output.put_line('set time on'); dbms_output.put_line('set timing on'); dbms_output.put_line('set echo on'); dbms_output.put_line('set verify on'); dbms_output.put_line(chr(5)); dbms_output.put_line('alter session set db_file_multiblock_read_count=128;'); dbms_output.put_line('alter session set resumable_timeout=3600;'); dbms_output.put_line('alter session set "_px_max_granules_per_slave"=3000;'); dbms_output.put_line('alter session set "_px_index_sampling"=3000;'); dbms_output.put_line('alter session set "_px_dynamic_sample_size"=3000;'); dbms_output.put_line(chr(5)); dbms_output.put_line('spool AWS_DATA01_2023_Table.log'); dbms_output.put_line(chr(5)); for i in c1 loop towner := i.owner; tname := i.segment_name; dbms_output.put_line('REM --- MOVING TABLE '||i.segment_name||' OF SIZE ----> '||i.bytes||' MB ') ; dbms_output.put_line('alter table '||i.owner||'.'||i.segment_name||' move tablespace AWS_DATA01;'); dbms_output.put_line(''); dbms_output.put_line(chr(3)); dbms_output.put_line('REM *************************************************************************'); dbms_output.put_line(chr(3)); end loop; dbms_output.put_line('spool off'); dbms_output.put_line('exit'); end; / ################################### TABLE PARTITION WITH SEGMENT MOVEMENT ########################## Table partition move set linesize 300 SET SERVEROUTPUT ON format WORD_WRAPPED exec dbms_output.enable(100000000); break on segment_name; declare tname varchar2(50); towner varchar2(50); pname varchar2(50); cursor c1 is select owner,segment_name,partition_name,tablespace_name,bytes/1024/1024 bytes from dba_segments where segment_type='TABLE PARTITION' and tablespace_name='AWS_DATA' and segment_name not like 'BIN$%' order by bytes/1024/1024 desc; begin dbms_output.put_line('set time on'); dbms_output.put_line('set timing on'); dbms_output.put_line('set echo on'); dbms_output.put_line('set verify on'); dbms_output.put_line(chr(5)); dbms_output.put_line('alter session set db_file_multiblock_read_count=128;'); dbms_output.put_line('alter session set resumable_timeout=3600;'); dbms_output.put_line('alter session set "_px_max_granules_per_slave"=3000;'); dbms_output.put_line('alter session set "_px_index_sampling"=3000;'); dbms_output.put_line('alter session set "_px_dynamic_sample_size"=3000;'); dbms_output.put_line(chr(5)); dbms_output.put_line('spool AWS_DATA01_PART.log'); dbms_output.put_line(chr(5)); for i in c1 loop towner := i.owner; tname := i.segment_name; pname := i.partition_name; dbms_output.put_line('REM --- MOVING TABLE '||i.segment_name||' OF SIZE ----> '||i.bytes||' MB ') ; dbms_output.put_line('alter table '||i.owner||'.'||i.segment_name||' move partition '|| i.partition_name||' tablespace AWS_DATA01;'); dbms_output.put_line(''); dbms_output.put_line(chr(3)); dbms_output.put_line('REM *************************************************************************'); dbms_output.put_line(chr(3)); end loop; dbms_output.put_line('spool off'); dbms_output.put_line('exit'); end; / ################################### TABLE WITH NO SEGMENT MOVEMENT ########################### set linesize 300 SET SERVEROUTPUT ON format WORD_WRAPPED exec dbms_output.enable(90000000000); set linesize 300 break on table_name; declare tname varchar2(50); towner varchar2(50); cursor c1 is select owner,table_name,tablespace_name from dba_tables where tablespace_name='AWS_DATA' order by 2 desc; begin dbms_output.put_line('set time on'); dbms_output.put_line('set timing on'); dbms_output.put_line('set echo on'); dbms_output.put_line('set verify on'); dbms_output.put_line(chr(5)); dbms_output.put_line('alter session set db_file_multiblock_read_count=128;'); dbms_output.put_line('alter session set resumable_timeout=3600;'); dbms_output.put_line('alter session set "_px_max_granules_per_slave"=3000;'); dbms_output.put_line('alter session set "_px_index_sampling"=3000;'); dbms_output.put_line('alter session set "_px_dynamic_sample_size"=3000;'); dbms_output.put_line(chr(5)); dbms_output.put_line('spool AWS_DATA01_2023_Table_noData.log'); dbms_output.put_line(chr(5)); for i in c1 loop towner := i.owner; tname := i.table_name; dbms_output.put_line('REM --- MOVING TABLE '||i.table_name||' OF SIZE ----> MB ') ; dbms_output.put_line('alter table '||i.owner||'.'||i.table_name||' move tablespace AWS_DATA01;'); dbms_output.put_line(''); dbms_output.put_line(chr(3)); dbms_output.put_line('REM *************************************************************************'); dbms_output.put_line(chr(3)); end loop; dbms_output.put_line('spool off'); dbms_output.put_line('exit'); end; / ################### TABLE PARTITION MOVEMENT WITH NO SEGMENTS ########################## set linesize 300 SET SERVEROUTPUT ON format WORD_WRAPPED exec dbms_output.enable(100000000); break on table_name; declare tname varchar2(50); towner varchar2(50); pname varchar2(50); cursor c1 is select table_owner,table_name,partition_name,tablespace_name from dba_tab_partitions where tablespace_name='AWS_DATA' order by 2 desc; begin dbms_output.put_line('set time on'); dbms_output.put_line('set timing on'); dbms_output.put_line('set echo on'); dbms_output.put_line('set verify on'); dbms_output.put_line(chr(5)); dbms_output.put_line('alter session set db_file_multiblock_read_count=128;'); dbms_output.put_line('alter session set resumable_timeout=3600;'); dbms_output.put_line('alter session set "_px_max_granules_per_slave"=3000;'); dbms_output.put_line('alter session set "_px_index_sampling"=3000;'); dbms_output.put_line('alter session set "_px_dynamic_sample_size"=3000;'); dbms_output.put_line(chr(5)); dbms_output.put_line('spool AWS_DATA01_PART.log'); dbms_output.put_line(chr(5)); for i in c1 loop towner := i.table_owner; tname := i.table_name; pname := i.partition_name; dbms_output.put_line('REM --- MOVING TABLE '||i.table_name||' OF SIZE ----> MB ') ; dbms_output.put_line('alter table '||i.table_owner||'.'||i.table_name||' move partition '|| i.partition_name||' tablespace AWS_DATA01;'); dbms_output.put_line(''); dbms_output.put_line(chr(3)); dbms_output.put_line('REM *************************************************************************'); dbms_output.put_line(chr(3)); end loop; dbms_output.put_line('spool off'); dbms_output.put_line('exit'); end; / ################################## UNUSABLE INDEX MOVEMENT ################################### select index_name from dba_indexes where status='UNUSABLE' select 'REM ###### Rebuild of Index '||owner||'.'||index_name|| ' of size => '||mb ||'Mb'||chr(13)||chr(10)|| 'alter index '||owner||'.'||index_name||' rebuild online parallel(degree 8);'||chr(13)||chr(10)|| 'alter index '||owner||'.'||index_name||' noparallel;' from ( select a.owner owner,a.index_name index_name,b.tablespace_name tablespace_name,b.bytes/1024/1024 as mb from dba_indexes a, dba_segments b where a.owner=b.owner and b.tablespace_name in ('WMS_UC_INDEX01','AWS_DATA','AWS_DATA01','WMS_INDEX') and a.index_name=b.segment_name and a.status='UNUSABLE' and b.segment_type='INDEX'); set pagesize 20000 set linesize 300 select 'REM ###### Rebuild of Index '||owner||'.'||index_name|| ' of size => '||'Mb'||chr(13)||chr(10)|| 'alter index '||owner||'.'||index_name||' rebuild online parallel(degree 8);'||chr(13)||chr(10)|| 'alter index '||owner||'.'||index_name||' noparallel;' from dba_indexes where status='UNUSABLE'; ############################## INDEX WITH NO SEGMENT REBUILD ################################### set pagesize 20000 set linesize 300 select 'REM ###### Rebuild of Index '||owner||'.'||index_name|| ' of size => '||'Mb'||chr(13)||chr(10)|| 'alter index '||owner||'.'||index_name||' rebuild online tablespace AWS_DATA01;'||chr(13)||chr(10)|| 'alter index '||owner||'.'||index_name||' noparallel;' from dba_indexes where tablespace_name='AWS_DATA'; ############################### INDEX REBUILD WITH SEGMENTS ################################### set linesize 300 SET SERVEROUTPUT ON format WORD_WRAPPED exec dbms_output.enable(100000000); break on segment_name; declare tname varchar2(50); towner varchar2(50); cursor c2 is select owner,segment_name as index_name,tablespace_name,bytes/1024/1024 as mb from dba_segments where tablespace_name in ('WMS_UC_INDEX01','AWS_DATA','AWS_DATA01','WMS_INDEX') and segment_type='INDEX'; begin dbms_output.put_line('set time on'); dbms_output.put_line('set timing on'); dbms_output.put_line('set echo on'); dbms_output.put_line('set verify on'); dbms_output.put_line(chr(5)); dbms_output.put_line('alter session set db_file_multiblock_read_count=128;'); dbms_output.put_line('alter session set resumable_timeout=3600;'); dbms_output.put_line('alter session set "_px_max_granules_per_slave"=3000;'); dbms_output.put_line('alter session set "_px_index_sampling"=3000;'); dbms_output.put_line('alter session set "_px_dynamic_sample_size"=3000;'); dbms_output.put_line(chr(5)); dbms_output.put_line('spool AWS_DATA01_INDEX_MOVE_TABLE.log'); dbms_output.put_line(chr(5)); for j in c2 loop dbms_output.put_line(null); dbms_output.put_line(''); dbms_output.put_line(chr(5)); dbms_output.put_line('REM --- REBUILD INDEX '||tname||'.'||j.index_name||' OF SIZE ----> '||j.mb||' MB ') ; dbms_output.put_line('alter index '||j.owner||'.'||j.index_name||' rebuild online parallel(degree 8);'); dbms_output.put_line('alter index '||j.owner||'.'||j.index_name||' noparallel;'); dbms_output.put_line(''); dbms_output.put_line(chr(3)); dbms_output.put_line('REM *************************************************************************'); dbms_output.put_line(chr(3)); end loop; dbms_output.put_line('spool off'); dbms_output.put_line('exit'); end; / #################### Gather Table statistics after table movement ####################### Normal Table: select 'REM ###### Analyze of Table '||owner||'.'||table_name|| ' of size => '||mb ||'Mb'||chr(13)||chr(10)|| 'exec DBMS_STATS.GATHER_TABLE_STATS('''||owner||''','''||table_name||''',DEGREE=>2,CASCADE=>TRUE,estimate_percent=>100,method_opt=>''FOR ALL COLUMNS SIZE REPEAT'');' from ( select a.owner owner,a.table_name table_name,b.tablespace_name tablespace_name,b.bytes/1024/1024 as mb from dba_tables a, dba_segments b where a.owner=b.owner and a.table_name=b.segment_name and b.segment_type='TABLE' and a.owner ='SCOTT' order by mb desc); Partitioned Table: select 'REM ###### Analyze of Table '||owner||'.'||segment_name||' of size '||MB||' MB'||chr(13)||chr(10)|| 'exec DBMS_STATS.GATHER_TABLE_STATS('||''''||owner||''''||','||''''||segment_name||''''||', DEGREE=>2, method_opt=>''FOR ALL COLUMNS SIZE REPEAT'',estimate_percent=>100,CASCADE=>TRUE,granularity =>'||'''ALL'''||') ;' from ( select a.owner owner,a.segment_name segment_name,a.segment_type segment_type,sum(a.bytes/1024/1024) as mb from dba_segments a, dba_tables b where a.owner = b.owner and a.segment_name = b.table_name and a.owner='SCOTT' and a.segment_type in 'TABLE PARTITION' group by a.owner,a.segment_name,a.segment_type order by mb desc) / ####################### POST VALIDATIONS ###################################### spool TABLE_INDEX_REORG_REBUILD_POSTVALIDATIONS.log set echo on set linesize 300 col index_name for a30 col degree for a10 col status for a10 col table_name for a30 col owner for a30 col object_type for a20 col constraint_type for a20 col constraint_name for a30 col validated for a20 col degree for a10 set pagesize 100 select owner,object_type,status,count(*) from dba_objects where status <> 'VALID' and owner='SCOTT' group by owner,object_type,status order by owner; select owner,index_name,status from dba_indexes where TABLE_OWNER='SCOTT' and status<>'VALID'; select index_name,status from dba_ind_partitions where status <> 'USABLE'; select CONSTRAINT_TYPE,STATUS,count(1) from dba_constraints where owner='SCOTT' group by CONSTRAINT_TYPE,STATUS; set linesize 300 col index_name for a30 col degree for a10 col status for a10 select TABLE_NAME,INDEX_NAME,DEGREE,status from dba_indexes where OWNER='SCOTT' and degree not in (0,1); select object_type , count(*),status from dba_objects where owner=upper('SCOTT') group by object_type,status order by object_type; select table_name,index_name,logging from dba_indexes where OWNER='SCOTT' and logging = 'NO'; select distinct STATUS from v$datafile; select constraint_name,constraint_type,table_name,status,validated from dba_constraints where owner='SCOTT' and status <> 'ENABLED'; select distinct owner from dba_segments where tablespace_name='&tablespace_name'; select distinct owner from dba_tables where tablespace_name='&tablespace_name'; select distinct owner from dba_indexes where tablespace_name='&tablespace_name'; select distinct table_owner from dba_tab_partitions where tablespace_name='&tablespace_name'; select distinct table_owner from dba_tab_subpartitions where tablespace_name='&tablespace_name'; select distinct index_owner from dba_ind_partitions where tablespace_name='&tablespace_name'; select distinct index_owner from dba_ind_subpartitions where tablespace_name='&tablespace_name'; select distinct STATUS from v$datafile; select * from v$recover_file; select distinct segment_type from dba_segments where tablespace_name='&tablespace_name'; select distinct status from dba_indexes; select distinct status from dba_ind_partitions; select distinct status from dba_ind_subpartitions; Drop tablespace AWS1_DATA01 including contents and datafiles; Drop tablespace AWS_DATA including contents and datafiles; Drop tablespace AWS_DATA including contents and datafiles cascade constraints; ( FOR FORCE DROPPING BUT DON'T TRY THIS ) |
Author : Venkat Vinod Kumar Siram
LinkedIn : https://www.linkedin.com/in/vinodsiram/
Thank you for giving your valuable time to read the above information. Please click here to subscribe for further updates
KTExperts is always active on social media platforms.
Facebook : https://www.facebook.com/ktexperts
LinkedIn : https://www.linkedin.com/company/ktexperts/
Twitter : https://twitter.com/ktexpertsadmin
YouTube : https://www.youtube.com/c/ktexperts
Instagram : https://www.instagram.com/knowledgesharingplatform