Here is a quick demo on running the Segment Space Advisor manually
I need to start with the ADVISOR privilege
I can then connect with my account to run the Advisor
I can then review the advise :
Thus, it actually reports for each Partition in the table.
Note : Script based on script by Tim Hall (@oraclebase) at https://oracle-base.com/dba/script?category=10g&file=segment_advisor.sql
I need to start with the ADVISOR privilege
$sqlplus SQL*Plus: Release 12.2.0.1.0 Production on Sat Jan 18 22:02:10 2020 Copyright (c) 1982, 2016, Oracle. All rights reserved. Enter user-name: system Enter password: Last Successful login time: Sat Jan 18 2020 22:00:32 +08:00 Connected to: Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production SQL> grant advisor to hemant; Grant succeeded. SQL> exit Disconnected from Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production
I can then connect with my account to run the Advisor
$sqlplus SQL*Plus: Release 12.2.0.1.0 Production on Sat Jan 18 22:02:35 2020 Copyright (c) 1982, 2016, Oracle. All rights reserved. Enter user-name: hemant Enter password: Last Successful login time: Sat Jan 18 2020 21:50:05 +08:00 Connected to: Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production SQL> SQL> DECLARE l_object_id NUMBER; l_task_name VARCHAR2(32767) := 'Advice on My SALES_DATA Table'; BEGIN DBMS_ADVISOR.create_task ( advisor_name => 'Segment Advisor', task_name => l_task_name ); DBMS_ADVISOR.create_object ( task_name => l_task_name, object_type => 'TABLE', attr1 => 'HEMANT', attr2 => 'SALES_DATA', attr3 => NULL, attr4 => NULL, attr5 => NULL, object_id => l_object_id ); DBMS_ADVISOR.set_task_parameter ( task_name => l_task_name, parameter => 'RECOMMEND_ALL', value => 'TRUE'); DBMS_ADVISOR.execute_task(task_name => l_task_name); end; / 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 PL/SQL procedure successfully completed. SQL>
I can then review the advise :
SQL> set serveroutput on begin FOR cur_rec IN (SELECT f.impact, o.type, o.attr1, o.attr2, o.attr3, o.attr4, f.message, f.more_info FROM dba_advisor_findings f, dba_advisor_objects o WHERE f.object_id = o.object_id AND f.task_name = o.task_name AND f.task_name = 'Advice on My SALES_DATA Table' ORDER BY f.impact DESC) LOOP DBMS_OUTPUT.put_line('..'); DBMS_OUTPUT.put_line('Type : ' || cur_rec.type); DBMS_OUTPUT.put_line('Schema : ' || cur_rec.attr1); DBMS_OUTPUT.put_line('Table Name : ' || cur_rec.attr2); DBMS_OUTPUT.put_line('Partition Name : ' || cur_rec.attr3); DBMS_OUTPUT.put_line('Tablespace Name : ' || cur_rec.attr4); DBMS_OUTPUT.put_line('Message : ' || cur_rec.message); DBMS_OUTPUT.put_line('More info : ' || cur_rec.more_info); END LOOP; end; / SQL> 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 .. Type : TABLE PARTITION Schema : HEMANT Table Name : SALES_DATA Partition Name : P_2015 Tablespace Name : USERS Message : The free space in the object is less than 10MB. More info : Allocated Space:65536: Used Space:8192: Reclaimable Space :57344: .. Type : TABLE PARTITION Schema : HEMANT Table Name : SALES_DATA Partition Name : P_2016 Tablespace Name : USERS Message : The free space in the object is less than 10MB. More info : Allocated Space:65536: Used Space:1016: Reclaimable Space :64520: .. Type : TABLE PARTITION Schema : HEMANT Table Name : SALES_DATA Partition Name : P_2017 Tablespace Name : USERS Message : The free space in the object is less than 10MB. More info : Allocated Space:65536: Used Space:1016: Reclaimable Space :64520: .. Type : TABLE PARTITION Schema : HEMANT Table Name : SALES_DATA Partition Name : P_2018 Tablespace Name : USERS Message : The free space in the object is less than 10MB. More info : Allocated Space:65536: Used Space:8192: Reclaimable Space :57344: .. Type : TABLE PARTITION Schema : HEMANT Table Name : SALES_DATA Partition Name : P_2019 Tablespace Name : USERS Message : The free space in the object is less than 10MB. More info : Allocated Space:65536: Used Space:8192: Reclaimable Space :57344: .. Type : TABLE PARTITION Schema : HEMANT Table Name : SALES_DATA Partition Name : P_MAXVALUE Tablespace Name : USERS Message : The free space in the object is less than 10MB. More info : Allocated Space:65536: Used Space:8192: Reclaimable Space :57344: PL/SQL procedure successfully completed. SQL>
Thus, it actually reports for each Partition in the table.
Note : Script based on script by Tim Hall (@oraclebase) at https://oracle-base.com/dba/script?category=10g&file=segment_advisor.sql