Home » RDBMS Server » Server Utilities » how to move all data from one tablespace to another tablespace (oracle 10g)
how to move all data from one tablespace to another tablespace [message #564375] Thu, 23 August 2012 04:10 Go to next message
x-oracle
Messages: 380
Registered: April 2011
Location: gujarat
Senior Member
hello all,

I want to move all data from my users tablespace to anohter new tablespace i have created name test1

so how can i do this using expdp

i want to move all objects from this my users tablespace to this new tablespace

can you please guide me

thanks in advance
Re: how to move all data from one tablespace to another tablespace [message #564379 is a reply to message #564375] Thu, 23 August 2012 04:23 Go to previous messageGo to next message
Michel Cadot
Messages: 68624
Registered: March 2007
Location: Nanterre, France, http://...
Senior Member
Account Moderator
expdp user/psw tablespaces=MY_TBS ...
impdp user/psw tablespaces=MY_TBS remap_tablespace=MY_TBS:NEW_TBS ...

Regards
Michel

Re: how to move all data from one tablespace to another tablespace [message #564381 is a reply to message #564379] Thu, 23 August 2012 04:51 Go to previous messageGo to next message
x-oracle
Messages: 380
Registered: April 2011
Location: gujarat
Senior Member
thanks for your help michel
michel i am sorry i not told you this i want to move this all objects into one tablespace to another tablespace into this same database

i did this expdp and impdp steps but its gives me error like tables are already exist i just did this following test steps

actuly i want to move all this object from this users tablespace to newly created another tablespace name new_users


C:\Users\Administrator>expdp system/oracle@star tablespaces=t1 dumpfile=tst1.dmp directory=amar

Export: Release 10.2.0.4.0 - 64bit Production on Thursday, 23 August, 2012 15:03:20

Copyright (c) 2003, 2007, Oracle.  All rights reserved.

Connected to: Oracle Database 10g Enterprise Edition Release 10.2.0.4.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
Starting "SYSTEM"."SYS_EXPORT_TABLESPACE_01":  system/********@star tablespaces=t1 dumpfile=tst1.dmp directory=amar
Estimate in progress using BLOCKS method...
Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
Total estimation using BLOCKS method: 128 KB
Processing object type TABLE_EXPORT/TABLE/TABLE
. . exported "AMAR"."DEPT"                               5.656 KB       4 rows
. . exported "AMAR"."EMP"                                7.812 KB      14 rows
Master table "SYSTEM"."SYS_EXPORT_TABLESPACE_01" successfully loaded/unloaded
******************************************************************************
Dump file set for SYSTEM.SYS_EXPORT_TABLESPACE_01 is:
  C:\AMAR\TST1.DMP
Job "SYSTEM"."SYS_EXPORT_TABLESPACE_01" successfully completed at 15:03:28


C:\Users\Administrator>impdp system/oracle@star tablespaces=t1 remap_tablespace=t1:t2 dumpfile=tst1.dmp directory=amar

Import: Release 10.2.0.4.0 - 64bit Production on Thursday, 23 August, 2012 15:03:44

Copyright (c) 2003, 2007, Oracle.  All rights reserved.

Connected to: Oracle Database 10g Enterprise Edition Release 10.2.0.4.0 - 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options
Master table "SYSTEM"."SYS_IMPORT_TABLESPACE_01" successfully loaded/unloaded
Starting "SYSTEM"."SYS_IMPORT_TABLESPACE_01":  system/********@star tablespaces=t1 remap_tablespace=t1:t2 dumpfile=tst1.dmp directory=amar
Processing object type TABLE_EXPORT/TABLE/TABLE
ORA-39151: Table "AMAR"."EMP" exists. All dependent metadata and data will be skipped due to table_exists_action of skip
ORA-39151: Table "AMAR"."DEPT" exists. All dependent metadata and data will be skipped due to table_exists_action of skip
Processing object type TABLE_EXPORT/TABLE/TABLE_DATA
Job "SYSTEM"."SYS_IMPORT_TABLESPACE_01" completed with 2 error(s) at 15:03:46
Re: how to move all data from one tablespace to another tablespace [message #564383 is a reply to message #564381] Thu, 23 August 2012 04:58 Go to previous messageGo to next message
Michel Cadot
Messages: 68624
Registered: March 2007
Location: Nanterre, France, http://...
Senior Member
Account Moderator
Maybe you should read the documentation or at least try to execute "expdp help=y" and "impdp help=y":
Import: Release 10.2.0.4.0 - Production on Jeudi, 23 Août, 2012 11:21:06

Copyright (c) 2003, 2007, Oracle.  All rights reserved.


The Data Pump Import utility provides a mechanism for transferring data objects
between Oracle databases. The utility is invoked with the following command:

     Example: impdp scott/tiger DIRECTORY=dmpdir DUMPFILE=scott.dmp

You can control how Import runs by entering the 'impdp' command followed
by various parameters. To specify parameters, you use keywords:

     Format:  impdp KEYWORD=value or KEYWORD=(value1,value2,...,valueN)
     Example: impdp scott/tiger DIRECTORY=dmpdir DUMPFILE=scott.dmp

USERID must be the first parameter on the command line.

Keyword               Description (Default)
------------------------------------------------------------------------------
ATTACH                Attach to existing job, e.g. ATTACH [=job name].
CONTENT               Specifies data to load where the valid keywords are:
                      (ALL), DATA_ONLY, and METADATA_ONLY.
DIRECTORY             Directory object to be used for dump, log, and sql files.
DUMPFILE              List of dumpfiles to import from (expdat.dmp),
                      e.g. DUMPFILE=scott1.dmp, scott2.dmp, dmpdir:scott3.dmp.
ENCRYPTION_PASSWORD   Password key for accessing encrypted column data.
                      This parameter is not valid for network import jobs.
ESTIMATE              Calculate job estimates where the valid keywords are:
                      (BLOCKS) and STATISTICS.
EXCLUDE               Exclude specific object types, e.g. EXCLUDE=TABLE:EMP.
FLASHBACK_SCN         SCN used to set session snapshot back to.
FLASHBACK_TIME        Time used to get the SCN closest to the specified time.
FULL                  Import everything from source (Y).
HELP                  Display help messages (N).
INCLUDE               Include specific object types, e.g. INCLUDE=TABLE_DATA.
JOB_NAME              Name of import job to create.
LOGFILE               Log file name (import.log).
NETWORK_LINK          Name of remote database link to the source system.
NOLOGFILE             Do not write logfile.
PARALLEL              Change the number of active workers for current job.
PARFILE               Specify parameter file.
QUERY                 Predicate clause used to import a subset of a table.
REMAP_DATAFILE        Redefine datafile references in all DDL statements.
REMAP_SCHEMA          Objects from one schema are loaded into another schema.
REMAP_TABLESPACE      Tablespace object are remapped to another tablespace.
REUSE_DATAFILES       Tablespace will be initialized if it already exists (N).
SCHEMAS               List of schemas to import.
SKIP_UNUSABLE_INDEXES Skip indexes that were set to the Index Unusable state.
SQLFILE               Write all the SQL DDL to a specified file.
STATUS                Frequency (secs) job status is to be monitored where
                      the default (0) will show new status when available.
STREAMS_CONFIGURATION Enable the loading of Streams metadata
TABLE_EXISTS_ACTION   Action to take if imported object already exists.
                      Valid keywords: (SKIP), APPEND, REPLACE and TRUNCATE.
TABLES                Identifies a list of tables to import.
TABLESPACES           Identifies a list of tablespaces to import.
TRANSFORM             Metadata transform to apply to applicable objects.
                      Valid transform keywords: SEGMENT_ATTRIBUTES, STORAGE
                      OID, and PCTSPACE.
TRANSPORT_DATAFILES   List of datafiles to be imported by transportable mode.
TRANSPORT_FULL_CHECK  Verify storage segments of all tables (N).
TRANSPORT_TABLESPACES List of tablespaces from which metadata will be loaded.
                      Only valid in NETWORK_LINK mode import operations.
VERSION               Version of objects to export where valid keywords are:
                      (COMPATIBLE), LATEST, or any valid database version.
                      Only valid for NETWORK_LINK and SQLFILE.

The following commands are valid while in interactive mode.
Note: abbreviations are allowed

Command               Description (Default)
------------------------------------------------------------------------------
CONTINUE_CLIENT       Return to logging mode. Job will be re-started if idle.
EXIT_CLIENT           Quit client session and leave job running.
HELP                  Summarize interactive commands.
KILL_JOB              Detach and delete job.
PARALLEL              Change the number of active workers for current job.
                      PARALLEL=<number of workers>.
START_JOB             Start/resume current job.
                      START_JOB=SKIP_CURRENT will start the job after skipping
                      any action which was in progress when job was stopped.
STATUS                Frequency (secs) job status is to be monitored where
                      the default (0) will show new status when available.
                      STATUS[=interval]
STOP_JOB              Orderly shutdown of job execution and exits the client.
                      STOP_JOB=IMMEDIATE performs an immediate shutdown of the
                      Data Pump job.

Regards
Michel

[Updated on: Thu, 23 August 2012 04:59]

Report message to a moderator

Re: how to move all data from one tablespace to another tablespace [message #564405 is a reply to message #564375] Thu, 23 August 2012 08:36 Go to previous message
John Watson
Messages: 8922
Registered: January 2010
Location: Global Village
Senior Member
Instead of creating a new tablespace and moving everything into it, you could RENAME the original tablespace.
Previous Topic: how should i grant connect , resource privilege to a user (without DBA privilege)
Next Topic: expdp displays output in German
Goto Forum:
  


Current Time: Thu Mar 28 05:57:07 CDT 2024