Skip to Main Content

Breadcrumb

Question and Answer

Connor McDonald

Thanks for the question, Robert.

Asked: February 20, 2018 - 1:31 pm UTC

Last updated: March 08, 2018 - 5:53 am UTC

Version: 11.2.0.4

Viewed 1000+ times

You Asked

I have a database - about 6.2Terabytes in size - has about 525G freespace. There are basically three tablespaces (other than the normal. FO_tables has about 50 tables. One of the tables there has two blob columns - each in it's own tablesapce. One of the blob colums is about 52G. The other is 5.6TB. So, as you might surmise, this one table, in fact, this one column is about 95% plus of the entire database. It has images in it of orders, etc. This database is going to move to an IBM platform. Some of the data has been moved to the new environment, and those rows have been deleted... about 7 million have been removed... about 7.5 million remain.

A dba in on the team in India did a reorg on the table and told the application manager he got back 5G of space. Well, the reorg did not include the two blob columns, so basically there was no real reorg. I was thinking, so what? Oracle knows where the freed up space is and can now use it. Not sure if it can use the freed up lob space on that large column.

The real question is the rman backup. Before the deletions, the rman took about 23 maybe 24 hours - used 6 channels.... but now the rman backup takes about 55 to 60 hours. So I was wondering does rman not worry about unused or free space?... and skip over it, and does that carry over into that lob segment area? Or does rman have a problem with all this freed up space?

If rman can skim over the freed up space on the 265 or so files that make up this massive lob segment and only backup the existing segments, seems like all things remaining the same, the backup should be faster.

Or do we have to reorg (with like an alter table tablename shrink space (and add the lob segment clause, etc)) to make this rman backup run faster?

Or if there shouldn't be any problem with the huge amount of freed up space as concerns the timing of the rman backup, I would assume I need to talk to backup team about why the backup is suddenly taking about 2.5 times as long as before. I know this is a lot of questions... but I need to get an indication of which direction I should go towards.

I just found out that the email I sent to you is not going to be read, that I had to go back into the website. I was wondering why I was getting no response. so... here is the info you asked for:

Well… as to your “does the Enter key work on your keyboard ?” question….
I find as a dba, with more and more responding to users and doing sql commands, especially while On-call and worrying about something I do will possibly cause an outage in a production assembly plant, etc, that sometimes my finger is poised above that Enter Key and I ask myself “Do I really want to high the Return”? …

Here is results of the dbms_metadata you wanted and a freespace report, and a description of table:

SQL> @freespc

                                Pct    Free         Total                 Free
       Tablespace Name          Free   Exts         Bytes                Bytes
------------------------------ ------ ------ -------------------- --------------------
FORDPVLT_TABLE                   99.6      1          262,144,000          261,095,424
DFLT                             99.6      1          262,144,000          261,095,424
TOOLS                            99.6      1          262,144,000          261,029,888
USERS                            98.4      1          262,144,000          257,818,624
SYSAUX                           74.9    377       10,737,418,240        8,038,711,296
F2_TABLES                        70.5    335       52,428,800,000       36,977,573,888
FORD_AUDIT                       63.0      2        1,048,576,000          660,930,560
SYSTEM                           31.1      1          786,432,000          244,318,208
F2_IMG_THUMB_BO                  24.3     69      215,629,168,640       52,371,128,320
F2_IMG_BA                         8.5    346    6,225,018,224,640      525,770,686,464
UNDOTBS1                          0.1      1       10,485,760,000            8,388,608
                                      ------ -------------------- --------------------
sum                                     1135    6,517,182,955,520      625,112,776,704

SQL> Desc FCF2PAD.ZF2T205_PAGE_IMG
Name                                                              Null?    Type
----------------------------------------------------------------- -------- --------------------------------------------
PAGE_SQNC_NB                                                      NOT NULL NUMBER(10)
TRNSMSSN_NB                                                       NOT NULL NUMBER(12)
TRNSMSSN_ATTCH_NB                                                 NOT NULL NUMBER(5)
IMG_BO                                                            NOT NULL BLOB
IMG_THUMB_BO                                                      NOT NULL BLOB
LSTUPDT_TS                                                        NOT NULL TIMESTAMP(6)
LSTUPDT_USER_ID_CD                                                NOT NULL CHAR(9 CHAR)
PAGE_SRC_CD                                                       NOT NULL CHAR(1 CHAR)
PAGE_DCN_TX                                                                VARCHAR2(40 CHAR)

SQL> set heading off;
SQL> set echo off;
SQL> Set pages 999;
SQL> set long 90000;
SQL> select dbms_metadata.get_ddl('TABLE','ZF2T205_PAGE_IMG','FCF2PAD') from dual;


  CREATE TABLE "FCF2PAD"."ZF2T205_PAGE_IMG"
   (    "PAGE_SQNC_NB" NUMBER(10,0) NOT NULL ENABLE,
        "TRNSMSSN_NB" NUMBER(12,0) NOT NULL ENABLE,
        "TRNSMSSN_ATTCH_NB" NUMBER(5,0) NOT NULL ENABLE,
        "IMG_BO" BLOB NOT NULL ENABLE,
        "IMG_THUMB_BO" BLOB NOT NULL ENABLE,
        "LSTUPDT_TS" TIMESTAMP (6) NOT NULL ENABLE,
        "LSTUPDT_USER_ID_CD" CHAR(9 CHAR) NOT NULL ENABLE,
        "PAGE_SRC_CD" CHAR(1 CHAR) DEFAULT 'F' NOT NULL ENABLE,
        "PAGE_DCN_TX" VARCHAR2(40 CHAR),
         CONSTRAINT "ZF2I2051" PRIMARY KEY ("PAGE_SQNC_NB")
  USING INDEX PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
  STORAGE(INITIAL 81920 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
  PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1
  BUFFER_POOL DEFAULT FLASH_CACHE DEFAULT CELL_FLASH_CACHE DEFAULT)
  TABLESPACE "F2_TABLES"  ENABLE
   ) SEGMENT CREATION IMMEDIATE
  PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255
NOCOMPRESS LOGGING
  STORAGE(INITIAL 81920 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
  PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1
  BUFFER_POOL DEFAULT FLASH_CACHE DEFAULT CELL_FLASH_CACHE DEFAULT)
  TABLESPACE "F2_TABLES"
LOB ("IMG_BO") STORE AS BASICFILE (
  TABLESPACE "F2_IMG_BA" DISABLE STORAGE IN ROW CHUNK 8192 PCTVERSION 0
  NOCACHE LOGGING
  STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
  PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1
  BUFFER_POOL DEFAULT FLASH_CACHE DEFAULT CELL_FLASH_CACHE DEFAULT))
LOB ("IMG_THUMB_BO") STORE AS BASICFILE (
  TABLESPACE "F2_IMG_THUMB_BO" DISABLE STORAGE IN ROW CHUNK 8192 PCTVERSION 0
  NOCACHE LOGGING
  STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
  PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1
  BUFFER_POOL DEFAULT FLASH_CACHE DEFAULT CELL_FLASH_CACHE DEFAULT))


and Connor said...

My first question is - does the Enter key work on your keyboard ? :-)

Second question - can you please post the full DDL (dbms_metadata.get_ddl) for the big table into the question as well, so we can see the settings on the table/blobs.

====================================

I don't think the backup duration change is related to the your LOB maintenance. A (full) RMAN backup will skip *never* used blocks, but that is different to "has been used but is no longer used" blocks. But I did a smaller scale test to see if I could see any change in RMAN behaviour with deleted lobs

SQL> create table t (
  2    x int,
  3    y int,
  4    z timestamp,
  5    b blob )
  6   lob (b) STORE AS BASICFILE (
  7    TABLESPACE LOBS DISABLE STORAGE IN ROW CHUNK 8192 PCTVERSI
  8    NOCACHE LOGGING
  9  );

Table created.

SQL>
SQL>
SQL> declare
  2    bf bfile := bfilename('TEMP','DP01.DMP');  -- 500meg file
  3    bb blob;
  4    len int;
  5  begin
  6    dbms_lob.fileopen(bf, dbms_lob.file_readonly);
  7    len := dbms_lob.getlength(bf);
  8    for i in 1 .. 60 loop
  9      insert into t values (i,i,systimestamp,empty_blob())
 10      returning b into bb;
 11
 12      dbms_lob.loadfromfile(bb,bf,len);
 13      commit;
 14    end loop;
 15    dbms_lob.fileclose(bf);
 16  end;
 17  /

PL/SQL procedure successfully completed.

SQL> select sum(bytes)/1024/1024/1024 gb from dba_segments;

        GB
----------
29.9854736

SQL> select sum(bytes)/1024/1024/1024 gb
  2  from dba_segments
  3  where tablespace_name = 'LOBS';

        GB
----------
25.9443359

SQL> select count(*) from t;

  COUNT(*)
----------
        60

--
-- So at this point, I've got 60 lobs totalling to around 25G, being ~80% of my entire database size. 
-- I'll now backup the database
--
RMAN> backup database format 'c:\oracle\bkp\%U';

Starting backup at 20180308-131300
using target database control file instead of recovery catalog
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=198 device type=DISK
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00007 name=C:\ORACLE\ORADATA\DB11\LOBS_02.DBF
input datafile file number=00008 name=C:\ORACLE\ORADATA\DB11\LOBS_03.DBF
input datafile file number=00006 name=C:\ORACLE\ORADATA\DB11\LOBS.DBF
input datafile file number=00002 name=C:\ORACLE\ORADATA\DB11\SYSAUX01.DBF
input datafile file number=00003 name=C:\ORACLE\ORADATA\DB11\UNDOTBS01.DBF
input datafile file number=00004 name=C:\ORACLE\ORADATA\DB11\USERS01.DBF
input datafile file number=00001 name=C:\ORACLE\ORADATA\DB11\SYSTEM01.DBF
input datafile file number=00005 name=C:\ORACLE\ORADATA\DB11\EXAMPLE01.DBF
channel ORA_DISK_1: starting piece 1 at 20180308-131301
channel ORA_DISK_1: finished piece 1 at 20180308-131626
piece handle=C:\ORACLE\BKP\01ST95AT_1_1 tag=TAG20180308T131301 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:03:25
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
including current control file in backup set
including current SPFILE in backup set
channel ORA_DISK_1: starting piece 1 at 20180308-131627
channel ORA_DISK_1: finished piece 1 at 20180308-131628
piece handle=C:\ORACLE\BKP\02ST95HA_1_1 tag=TAG20180308T131301 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 20180308-131628

--
-- So the backup time for the entire database (of which our LOBS are the biggest contributor) 
-- comes to 3:25
--
-- Now we'll delete 2/3rds of the lobs, and do an 'alter table move' to simulate the 
-- non-lob reorg of the table you mentioned
--


SQL> delete from t where x <= 40;

40 rows deleted.

SQL> commit;

Commit complete.

SQL> alter table t move;

Table altered.

--
-- and now we'll re-run the backup
--

RMAN> backup database format 'c:\oracle\bkp\%U';

Starting backup at 20180308-133010
using channel ORA_DISK_1
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00007 name=C:\ORACLE\ORADATA\DB11\LOBS_02.DBF
input datafile file number=00008 name=C:\ORACLE\ORADATA\DB11\LOBS_03.DBF
input datafile file number=00006 name=C:\ORACLE\ORADATA\DB11\LOBS.DBF
input datafile file number=00002 name=C:\ORACLE\ORADATA\DB11\SYSAUX01.DBF
input datafile file number=00003 name=C:\ORACLE\ORADATA\DB11\UNDOTBS01.DBF
input datafile file number=00004 name=C:\ORACLE\ORADATA\DB11\USERS01.DBF
input datafile file number=00001 name=C:\ORACLE\ORADATA\DB11\SYSTEM01.DBF
input datafile file number=00005 name=C:\ORACLE\ORADATA\DB11\EXAMPLE01.DBF
channel ORA_DISK_1: starting piece 1 at 20180308-133011
channel ORA_DISK_1: finished piece 1 at 20180308-133336
piece handle=C:\ORACLE\BKP\03ST96B3_1_1 tag=TAG20180308T133010 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:03:25
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
including current control file in backup set
including current SPFILE in backup set
channel ORA_DISK_1: starting piece 1 at 20180308-133337
channel ORA_DISK_1: finished piece 1 at 20180308-133338
piece handle=C:\ORACLE\BKP\04ST96HG_1_1 tag=TAG20180308T133010 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
Finished backup at 20180308-133338

RMAN>


So the timings were the same - as were the backup sizes

SQL> host dir c:\oracle\bkp
 Volume in drive C is System
 Volume Serial Number is EEC5-B9EF

 Directory of c:\oracle\bkp

08/03/2018  01:33 PM    <DIR>          .
08/03/2018  01:33 PM    <DIR>          ..
08/03/2018  01:16 PM    31,838,953,472 01ST95AT_1_1
08/03/2018  01:16 PM        10,059,776 02ST95HA_1_1
08/03/2018  01:33 PM    31,638,020,096 03ST96B3_1_1
08/03/2018  01:33 PM        10,059,776 04ST96HG_1_1


So I don't think its the lobs here. Is it possible that you have a large chunk of archivelogs (from the deletion) that are indirectly causing the impact?

Anyway, a couple of things to consider:

1) if you want to get that lob space back, you could do:

alter table t modify lob (b) (shrink space);

2) For TB sized databases, you really want to be using block change tracking. Besides your first backup, other backups should be minutes not hours or days.

Is this answer out of date? If it is, please let us know via a Comment

More to Explore

Administration

Need more information on Administration? Check out the Administrators guide for the Oracle Database