From oracle-l-bounce@freelists.org Wed Oct 12 11:10:27 2005 Return-Path: Received: from air891.startdedicated.com (root@localhost) by orafaq.com (8.12.10/8.12.10) with ESMTP id j9CGAQS6005011 for ; Wed, 12 Oct 2005 11:10:26 -0500 X-ClientAddr: 206.53.239.180 Received: from turing.freelists.org (freelists-180.iquest.net [206.53.239.180]) by air891.startdedicated.com (8.12.10/8.12.10) with ESMTP id j9CGAHvX004982 for ; Wed, 12 Oct 2005 11:10:18 -0500 Received: from localhost (localhost [127.0.0.1]) by turing.freelists.org (Avenir Technologies Mail Multiplex) with ESMTP id 5CFC71FBA67; Wed, 12 Oct 2005 11:09:51 -0500 (EST) Received: from turing.freelists.org ([127.0.0.1]) by localhost (turing [127.0.0.1]) (amavisd-new, port 10024) with ESMTP id 16677-01; Wed, 12 Oct 2005 11:09:51 -0500 (EST) Received: from turing (localhost [127.0.0.1]) by turing.freelists.org (Avenir Technologies Mail Multiplex) with ESMTP id 45D721FCE22; Wed, 12 Oct 2005 11:09:50 -0500 (EST) DomainKey-Signature: a=rsa-sha1; q=dns; c=nofws; s=beta; d=gmail.com; h=received:message-id:date:from:to:subject:cc:in-reply-to:mime-version:content-type:references; b=WN9C8u0ZA3/8wYsXjV+2TwaFJ3WhiTBREAK15+0PFQbPlxiY5ZN8rkDSont6D1ubIUV07oHqF155l5X0yMzBLqzKNrbtIhBQ24xC2yXdULrIfF3j96K6NHc0TSvVKQf6P4ONe1bhweq8ACN9i19YCzsbiFbNCyAQDdS9mkKehP4= Message-ID: <1a3629600510120907y34c3880drb1f64d8a50017fc4@mail.gmail.com> Date: Wed, 12 Oct 2005 12:07:51 -0400 From: Chirag DBA To: John.Hallas@gb.vodafone.co.uk Subject: Re: tablespaces ddl extract script Cc: norman.dunbar@environment-agency.gov.uk, davidsharples@gmail.com, sjaffarhussain@gmail.com, oracle-l@freelists.org In-Reply-To: <1C6E45ADB2EC324F9553E468ABFE0F63030F0F7C@UKWMXM04> MIME-Version: 1.0 Content-Type: multipart/alternative; boundary="----=_Part_56824_19445714.1129133271006" References: <1C6E45ADB2EC324F9553E468ABFE0F63030F0F7C@UKWMXM04> X-archive-position: 26811 X-ecartis-version: Ecartis v1.0.0 Sender: oracle-l-bounce@freelists.org Errors-To: oracle-l-bounce@freelists.org X-original-sender: chiragdba@gmail.com Precedence: normal Reply-To: chiragdba@gmail.com X-list: oracle-l X-Virus-Scanned: by amavisd-new-20030616-p9 (Debian) at avenirtech.net X-mailscan-MailScanner-Information: Please contact the ISP for more information X-mailscan-MailScanner: Found to be clean X-MailScanner-From: oracle-l-bounce@freelists.org X-Spam-Checker-Version: SpamAssassin 2.63 (2004-01-11) on air891.startdedicated.com X-Spam-Level: X-Spam-Status: No, hits=-4.1 required=5.0 tests=AWL,BAYES_00,HTML_MESSAGE, NORMAL_HTTP_TO_IP autolearn=no version=2.63 ------=_Part_56824_19445714.1129133271006 Content-Type: text/plain; charset=ISO-8859-1 Content-Transfer-Encoding: quoted-printable Content-Disposition: inline try this re script...!! DECLARE CURSOR get_ts IS SELECT * FROM dba_tablespaces WHERE tablespace_name !=3D 'SYSTEM'; CURSOR get_df (p_ts VARCHAR2) IS SELECT * from dba_data_files WHERE tablespace_name =3D p_ts; l_str VARCHAR2(10); BEGIN FOR ts_rec IN get_ts LOOP dbms_output.put_line ('CREATE TABLESPACE '||ts_rec.tablespace_name); -- For each tablespace loop through the datafiles FOR df_rec IN get_df (ts_rec.tablespace_name) LOOP IF get_df%ROWCOUNT =3D 1 THEN l_str :=3D 'DATAFILE'; ELSE l_str :=3D ','; END IF; dbms_output.put_line (l_str||' ' ||chr(39)||df_rec.file_name||chr(39) ||' SIZE '||df_rec.bytes||' REUSE '); if df_rec.autoextensible =3D 'YES' then dbms_output.put_line (' AUTOEXTEND ON' ||' NEXT '||df_rec.increment_by ); if df_rec.maxbytes =3D 68719443968 then dbms_output.put_line (' MAXSIZE UNLIMITED'); else dbms_output.put_line (' MAXSIZE '||df_rec.maxbytes); end if; end if; END LOOP; /* Extent Management Clause */ dbms_output.put_line ('EXTENT MANAGEMENT ' ||ts_rec.extent_management ); if ts_rec.extent_management =3D 'LOCAL' then if ts_rec.allocation_type =3D 'SYSTEM' then dbms_output.put_line (' AUTOALLOCATE '); else dbms_output.put_line (' UNIFORM SIZE '||ts_rec.initial_extent); end if; end if; if ts_rec.extent_management =3D 'DICTIONARY' then dbms_output.put_line ('DEFAULT STORAGE (INITIAL '||ts_rec.initial_extent ||' NEXT '||ts_rec.next_extent ||' MINEXTENTS '||ts_rec.min_extents ||' MAXEXTENTS '||ts_rec.max_extents ||' PCTINCREASE '||ts_rec.pct_increase||' ) '); end if; dbms_output.put_line (' ONLINE;'); dbms_output.new_line; END LOOP; END; / On 10/12/05, Hallas, John, Tech Dev wrote: > > Perform a set long 2000 and then try again > > Set long 2000 > > SELECT DBMS_METADATA.GET_DDL('TABLESPACE', tablespace_name) FROM > DBA_tablespaces; > > CREATE TABLESPACE "SYSTEM" DATAFILE > '/u01/oradata/WLINT1DB/system_01.dbf' SIZE 314572800 REUSE , > '/u02/oradata/WLINT1DB/system_02.dbf' SIZE 314572800 REUSE > LOGGING ONLINE PERMANENT BLOCKSIZE 8192 > EXTENT MANAGEMENT LOCAL AUTOALLOCATE SEGMENT SPACE MANAGEMENT MANUAL > > > > John > > -----Original Message----- > From: oracle-l-bounce@freelists.org > [mailto:oracle-l-bounce@freelists.org] On Behalf Of Norman Dunbar > Sent: 12 October 2005 11:49 > To: davidsharples@gmail.com; sjaffarhussain@gmail.com > Cc: oracle-l@freelists.org > Subject: Re: tablespaces ddl extract script > > > Unfortunately, on my 9.2.0.4 system, it is incomplete : > > SQL>select dbms_metadata.get_ddl('TABLESPACE','NORMAN') as fred from > dual; > > FRED > ---------------------------------------------------------- > > CREATE TABLESPACE "NORMAN" DATAFILE > '/u00/oracle/oradata/lccsdev/norman_01 > > Which is a tad upsetting :o( > > > I would suggest doing a full export with no actual rows etc being > exported, then run an import with SHOW=3DYES LOGFILE=3DSHOW.LOG and > extracting the commands from SHOW.LOG if the metadata thing doesn't work > for your system either. > > > Cheers, > Norman. > > > Norman Dunbar. > Contract Oracle DBA. > Rivers House, Leeds. > > Internal : 7 28 2051 > External : 0113 231 2051 > > > >>> David Sharples 10/12/05 11:29am >>> > SQL> select dbms_metadata.get_ddl('TABLESPACE','TS_NAME') from dual; > google and metalink are your friends > > > > Information in this message may be confidential and may be legally > privileged. If you have received this message by mistake, please notify > the sender immediately, delete it and do not copy it to anyone else. > > We have checked this email and its attachments for viruses. But you > should still check any attachment before opening it. > > We may have to make this message and any reply to it public if asked to > under the Freedom of Information Act, Data Protection Act or for > litigation. Email messages and attachments sent to or from any > Environment Agency address may also be accessed by someone other than > the sender or recipient, for business purposes. > > If we have sent you information and you wish to use it please read our > terms and conditions which you can get by calling us on 08708 506 506. > Find out more about the Environment Agency at > www.environment-agency.gov.uk > -- > http://www.freelists.org/webpage/oracle-l > > > -- > http://www.freelists.org/webpage/oracle-l > ------=_Part_56824_19445714.1129133271006 Content-Type: text/html; charset=ISO-8859-1 Content-Transfer-Encoding: quoted-printable Content-Disposition: inline
try this re script...!! 
 
DECLARE
CURSOR get_ts IS SELECT * FROM dba_tablespaces
 WHE= RE tablespace_name !=3D 'SYSTEM';
CURSOR get_df (p_ts VARCHAR2) IS
&n= bsp; SELECT * from dba_data_files
 WHERE tablespace_name =3D p_ts;<= br>  l_str VARCHAR2(10);
BEGIN
FOR ts_rec IN get_ts LOOP
  dbms_output.put_line ('CRE= ATE TABLESPACE '||ts_rec.tablespace_name);
  -- For each tablespace= loop through the datafiles
  FOR df_rec IN get_df (ts_rec.tablespa= ce_name) LOOP
 IF get_df%ROWCOUNT =3D 1 THEN
 l_str :=3D 'DATAFILE';
=  ELSE
 l_str :=3D ',';
 END IF;
 dbms_output.p= ut_line (l_str||' '
 ||chr(39)||df_rec.file_name||chr(39)
 = ||' SIZE '||df_rec.bytes||' REUSE ');
 if df_rec.autoextensible =3D= 'YES' then
 dbms_output.put_line (' AUTOEXTEND ON'
  ||' NEXT '||df_r= ec.increment_by );
 if df_rec.maxbytes =3D 68719443968 then
&nbs= p;dbms_output.put_line (' MAXSIZE UNLIMITED');
 else
 dbms_= output.put_line (' MAXSIZE '||df_rec.maxbytes);
 end if;
 end if;
  END LOOP;
/* Extent Managem= ent Clause */

dbms_output.put_line  ('EXTENT MANAGEMENT ' ||ts_rec.extent_managem= ent );
if ts_rec.extent_management =3D 'LOCAL' then
if ts_rec.allocat= ion_type =3D 'SYSTEM' then
dbms_output.put_line (' AUTOALLOCATE ');
e= lse
dbms_output.put_line (' UNIFORM SIZE '||ts_rec.initial_extent);
end if;<= br>end if;
if ts_rec.extent_management =3D 'DICTIONARY' then
  d= bms_output.put_line ('DEFAULT STORAGE (INITIAL '||ts_rec.initial_extent
=   ||' NEXT '||ts_rec.next_extent
  ||' MINEXTENTS '||ts_rec.min_extents
  ||' MAXEXTENTS '|= |ts_rec.max_extents
  ||' PCTINCREASE '||ts_rec.pct_increase||' ) '= );
end if;
dbms_output.put_line  (' ONLINE;');
dbms_output.ne= w_line;

END LOOP;

END;
/



On 10/12/05, Hallas, John, Tech Dev <John.Hallas@gb.vodafone.co.uk> wrote:
Perform a set long 2000 and then= try again

Set long 2000

SELECT DBMS_METADATA.GET_DDL('TABLES= PACE', tablespace_name) FROM
DBA_tablespaces;

CREATE TABLESPACE "SYSTEM" DATAFILE'/u01/oradata/WLINT1DB/system_01.dbf' SIZE 314572800 REUSE ,
'/u02/ora= data/WLINT1DB/system_02.dbf' SIZE 314572800 REUSE
LOGGING ONLINE PERMANE= NT BLOCKSIZE 8192
EXTENT MANAGEMENT LOCAL AUTOALLOCATE SEGMENT SPACE MANAGEMENT MANUAL


John

-----Original Message-----
From: oracle-l-bounce@freelists.org
[ma= ilto: oracle-l-bounce@freelists.= org] On Behalf Of Norman Dunbar
Sent: 12 October 2005 11:49
To: <= a href=3D"mailto:davidsharples@gmail.com">davidsharples@gmail.com; sjaffarhussain@gmail.com
Cc: oracle-l@freelists.org
Subject: Re: tablespaces ddl extract scrip= t


Unfortunately, on my 9.2.0.4 sy= stem, it is incomplete :

SQL>select dbms_metadata.get_ddl('TABLESPACE','NORMAN') as fred = from
dual;

FRED
----------------------------------------------= ------------

CREATE TABLESPACE "NORMAN" DATAFILE
'/u00/= oracle/oradata/lccsdev/norman_01

Which is a tad upsetting :o(


I would suggest doing a ful= l export with no actual rows etc being
exported, then run an import with= SHOW=3DYES LOGFILE=3DSHOW.LOG and
extracting the commands from SHOW.LOG if the metadata thing doesn't work
for your system either.


C= heers,
Norman.


Norman Dunbar.
Contract Oracle DBA.
Rive= rs House, Leeds.

Internal : 7 28 2051
External : 0113 231 2051


>>> David Sharples <davidsharples@gmail.com> 10/12/05 11:29am >>>SQL> select dbms_metadata.get_ddl('TABLESPACE','TS_NAME') from dual;
google and metalink are your friends



Information in this= message may be confidential and may be legally
privileged. If you have = received this message by mistake, please notify
the sender immediately, = delete it and do not copy it to anyone else.

We have checked this email and its attachments for viruses. But you=
should still check any attachment before opening it.

We may have= to make this message and any reply to it public if asked to
under the F= reedom of Information Act, Data Protection Act or for
litigation.  Email messages and attachments sent to or from a= ny
Environment Agency address may also be accessed by someone other than=
the sender or recipient, for business purposes.

If we have sent = you information and you wish to use it please read our
terms and conditions which you can get by calling us on 08708 506 506.<= br>Find out more about the Environment Agency at
www.environment-agency.gov.uk
--
http://www.freelists.org/webpage/oracle-l


--
http://www.freelists.org/webpage/= oracle-l

------=_Part_56824_19445714.1129133271006-- -- http://www.freelists.org/webpage/oracle-l