12
返回列表 发新帖
楼主: david31415

怎么从tablsespace 里面删除一个datafile?

[复制链接]
论坛徽章:
3
ITPUB元老
日期:2005-02-28 12:57:00授权会员
日期:2005-10-30 17:05:33会员2006贡献徽章
日期:2006-04-17 13:46:34
11#
发表于 2001-12-6 13:39 | 只看该作者
How to 'DROP' a Datafile from a Tablespace:
===========================================

Before we start with detailed explanations of the process involved, please note
that Oracle does not provide an interface for dropping datafiles in the same
way that you could drop a schema object such as a table, a view, a user, etc.  
Once you make a datafile part of a tablespace, the datafile CANNOT be removed,
although we can use some workarounds.

Before performing certain operations such as taking tablespaces/datafiles
offline, and trying to drop them, ensure you have a full backup.

If the datafile you wish to remove is the only datafile in that tablespace,
simply drop the entire tablespace using:

    DROP TABLESPACE <tablespace name> INCLUDING CONTENTS;

You can confirm how many datafiles make up a tablespace by running the
following query:

    select file_name, tablespace_name
    from dba_data_files
    where tablespace_name ='<name of tablespace>';

The DROP TABLESPACE command removes the tablespace, the datafile, and the
tablespace's contents from the data dictionary.  Oracle will no longer have
access to ANY object that was contained in this tablespace.  The physical
datafile must then be removed using an operating system command (Oracle NEVER
physically removes any datafiles).  Depending on which platform you try this
on, you may not be able to physically delete the datafile until Oracle is
completely shut down. (For example, on Windows NT, you may have to shutdown
Oracle AND stop the associated service before the operating system will allow
you to delete the file - in some cases, file locks are still held by Oracle.)

If you have more than one datafile in the tablespace, and you do NOT need the
information contained in that tablespace, or if you can easily recreate the
information in this tablespace, then use the same command as above:

    DROP TABLESPACE <tablespace name> INCLUDING CONTENTS;

Again, this will remove the tablespace, the datafiles, and the tablespace's
contents from the data dictionary.  Oracle will no longer have access to ANY
object that was contained in this tablespace.  You can then use CREATE
TABLESPACE and re-import the appropriate objects back into the tablespace.

If you have more than one datafile in the tablespace and you wish to keep the
objects that reside in the other datafile(s) which are part of this tablespace,
then you must export all the objects  inside the affected tablespace.  Gather
information on the current datafiles within the tablespace by running this
query:

    select file_name, tablespace_name
    from dba_data_files
    where tablespace_name ='<name of tablespace>';

Make sure you specify the tablespace name in capital letters.

In order to allow you to identify which objects are inside the affected
tablespace for the purposes of running your export, use the following query:

    select owner,segment_name,segment_type
    from dba_segments
    where tablespace_name='<name of tablespace>'

Now, export all the objects that you wish to keep.

Once the export is done, issue the DROP TABLESPACE tablespace INCLUDING
CONTENTS.  

Note that this PERMANENTLY removes all objects in this tablespace. Delete the
datafiles belonging to this tablespace using the operating system. (See the
comment above about possible problems in doing this.) Recreate the tablespace
with the datafile(s) desired, then import the objects into that tablespace.  
(This may have to be done at the table level, depending on how the tablespace
was organized.)  

NOTE:
The ALTER DATABASE DATAFILE <datafile name> OFFLINE DROP command, is not meant
to allow you to remove a datafile. What the command really means is that you
are offlining the datafile with the intention of dropping the tablespace.

If you are running in archivelog mode, you can also use:

    ALTER DATABASE DATAFILE <datafile name> OFFLINE;

instead of OFFLINE DROP.  Once the datafile is offline, Oracle no longer
attempts to access it, but it is still considered part of that tablespace. This
datafile is marked only as offline in the controlfile and there is no SCN
comparison done between the controlfile and the datafile during startup (This
also allows you to startup a database with a non-critical datafile missing).  
The entry for that datafile is not deleted from the controlfile to give us the
opportunity to recover that datafile.


If you do not wish to follow any of these procedures, there are other things
that can be done besides dropping the tablespace.

- If the reason you wanted to drop the file is because you mistakenly created
  the file of the wrong size, then consider using the RESIZE command.  

- If you really added the datafile by mistake, and Oracle has not yet allocated
  any space within this datafile, then you can use ALTER DATABASE DATAFILE
  <filename> RESIZE; command to make the file smaller than 5 Oracle blocks. If
  the datafile is resized to smaller than 5 oracle blocks, then it will never
  be considered for extent allocation. At some later date, the tablespace can
  be rebuilt to exclude the incorrect datafile.

使用道具 举报

回复
论坛徽章:
1
授权会员
日期:2005-10-30 17:05:33
12#
发表于 2001-12-6 14:54 | 只看该作者
sqlcode:

I adore you!!!!!!!!! and i have brought your anwner to FAQ.

使用道具 举报

回复
论坛徽章:
3
ITPUB元老
日期:2005-02-28 12:57:00授权会员
日期:2005-10-30 17:05:33会员2006贡献徽章
日期:2006-04-17 13:46:34
13#
发表于 2001-12-6 16:03 | 只看该作者
it is said by oracle.
you cant drop a  datafile from oracle
you can resize a datafile size down to 5M, oracle will igon this datafile.

使用道具 举报

回复
论坛徽章:
1
ITPUB元老
日期:2005-02-28 12:57:00
14#
发表于 2001-12-6 16:40 | 只看该作者
可以:ALTER DATABASE DATAFILE ‘dele_file_path’OFFLINE DROP 即可

使用道具 举报

回复
论坛徽章:
0
15#
发表于 2001-12-7 09:07 | 只看该作者
Think of this way:

you have two data files, dbf1 and dbf2, for a tablespace called data01,
you have a table in data01 and the table is cross these two files, part of it in dbf1 and part of it in dbf2. What happens if you can drop one of the datafiles? Therefore, don't think you can drop a datafile. You can only drop a tablespace.

使用道具 举报

回复
论坛徽章:
1
授权会员
日期:2005-10-30 17:05:33
16#
发表于 2001-12-7 13:50 | 只看该作者

文章“How to 'DROP' a Datafile from a Tablespace: ”中最后一句话怎么理解?

"At some later date, the tablespace can
be rebuilt to exclude the incorrect datafile."
oracle 会把5个datablock的datafile自动删除吗?

使用道具 举报

回复
论坛徽章:
1
授权会员
日期:2005-10-30 17:05:33
17#
 楼主| 发表于 2001-12-7 18:30 | 只看该作者

小于5M的datafile怎么被处理?

不会被自动删除吧?
我为了学习方便,
一直在tools tablespace里面加了几个size = 1M的datafile-

一直在呀?而且可以正确的操作-

能否在详细解释一下吗?

使用道具 举报

回复

您需要登录后才可以回帖 登录 | 注册

本版积分规则 发表回复

TOP技术积分榜 社区积分榜 徽章 团队 统计 知识索引树 积分竞拍 文本模式 帮助
  ITPUB首页 | ITPUB论坛 | 数据库技术 | 企业信息化 | 开发技术 | 微软技术 | 软件工程与项目管理 | IBM技术园地 | 行业纵向讨论 | IT招聘 | IT文档
  ChinaUnix | ChinaUnix博客 | ChinaUnix论坛
CopyRight 1999-2011 itpub.net All Right Reserved. 北京盛拓优讯信息技术有限公司版权所有 联系我们 未成年人举报专区 
京ICP备16024965号-8  北京市公安局海淀分局网监中心备案编号:11010802021510 广播电视节目制作经营许可证:编号(京)字第1149号
  
快速回复 返回顶部 返回列表