The Problem
It was motivated by a client's regular need during a transition phase from non-Exadata to Exadata to create literally thousands of indexes with potentially a multitude of (sub-)partitions as fast as possible - as part of a full datapump import job of a multi-terabyte database running 11.1.0.7 and 11.2.0.1 (Exadata V2).
There are actually two issues regarding the index creation part of a large database import:
1. The datapump import performs the index creation only by a single worker thread even when using the PARALLEL worker thread import feature. Although an index could be created in parallel if you have thousands of smaller index objects this single worker thread potentially does not make efficient use of the available hardware resources with high-end configurations, including and in particular Exadata.
2. There is a nasty bug 8604502 that has been introduced with 11.1.0.7 that affects also 11.2.0.1 (fixed in 11.2.0.2 and a generic one-off patch is available on My Oracle Support for 11.1.0.7 and 11.2.0.1): The IMPDP creates all indexes serially, even those supposed to be created in parallel, and only after the creation ALTERs them to the defined PARALLEL degree. Note that the fix actually only fixes the problem at actual execution time, even with the fix installed (and in 11.2.0.2) the SQLFILE option of IMPDP still generates CREATE INDEX DDLs that will always have the parallel degree set to PARALLEL 1 (see MOS document 1289032.1 and bug 10408313 - INDEXES ARE CREATED WITH PARALLEL DEGREE 1 DURING IMPORT which has been closed as not being a bug). This "not-being-a-bug" also affects all other versions that support the datapump utility - the SQLFILE option always generates CREATE INDEX scripts with the parallel degree set to 1 no matter what the actual degree of the index is supposed to be. It's only the ALTER INDEX DDL command following the CREATE INDEX command that sets the parallel degree correctly.
These two issues in combination meant to them that a full database import job took ages to complete the index creation step after loading quite quickly the vast amount of table data in parallel.
In case of partitioned indexes there is another complication independently from the mentioned issues: Oracle uses only one parallel slave per partition for creation - in case of large and/or few partitions this again doesn't make efficient use of the available resources.
Oracle therefore provides several means to speed up index creation and rebuild tasks, in particular the documented DBMS_PCLXUTIL package that is around since the Oracle 8 days to overcome the above mentioned limitation of partitioned index creation by spawning multiple jobs each rebuilding an index partition in parallel.
Another, undocumented feature is the DBMS_INDEX_UTL package that is obviously used internally as part of several maintenance operations, for example those DDLs that include the "UPDATE INDEXES" clause. According to the spec it allows to rebuild multiple indexes concurrently by spawning multiple jobs - however since it is undocumented it might not be safe to use in production-like configurations - furthermore it might be changed in future releases without further notice and therefore is potentially unreliable.
A Solution
Since the client wanted a quick solution that ideally addressed all of the above issues I came up with a simple implementation that uses Advanced Queueing and background jobs to create as many indexes as desired concurrently.
The solution is targeted towards the client's scenario, so the following is assumed:
- There is a SQL file that contains the CREATE INDEX statements. This can easily be generated via IMPDP based on the dump files using the SQLFILE option.
- To address the CREATE INDEX (not-being-a-)bug (the bugfix for the bug 8604502 still generates incorrect CREATE INDEX DDLs with the SQLFILE option of IMPDP as mentioned above) I've created a combination of "sed" and "awk" unix scripts that take the IMPDP SQLFILE potentially including all DDLs commands as input and create a output file that consists solely of the CREATE INDEX commands with correct PARALLEL clauses based on the ALTER INDEX command following the CREATE INDEX in the script
- To address the lengthy index creation process I've created a small PL/SQL package that sets up the required AQ infrastructure, takes the CREATE INDEX DDL file as input, populates a queue with the index creation commands and spawns as many worker threads as specified that will take care of the actual index creation (that in turn might be a parallel index creation)
As a side note it is interesting that Oracle actually allows to build several indexes concurrently on the same segment (which makes totally sense but does probably not happen too often in practice).
Note that in principle this code could be used as a general template to execute arbitrary DDLs concurrently (of course with corresponding modifications).
The following link allows to download an archive that contains the following subdirectories:
- correct_parallel_clause: This directory contains the Unix scripts mentioned above that allow to process a SQLFILE generated by IMPDP and output a DDL file that solely consists of the CREATE INDEX commands contained in the SQLFILE. The generated CREATE INDEX statements also use a correct PARALLEL clause - the degree is taken from the ALTER INDEX DDL command following the CREATE INDEX in the SQLFILE. For further details refer to the README.txt in that directory. Note that the script at present does not handle Domain Indexes, only conventional and bitmap.
- source: Contains the package source for the concurrent index creation, furthermore a package that is required by the provided automated unit testing (see below for more details) and a script that prompts for the required details to initiate a concurrent index creation. The README.txt in that directory provides a quick start guide how to use the concurrent index creation.
- test: Contains two flavours of test harnesses for automated unit testing of the package. One based on the unit testing feature implemented in SQLDeveloper 2.1.1, and another one based on "dbunit", an open-source unit testing framework based on jUnit. The README.txt in the respective subdirectories explain how to use these unit tests.
How to use it
The usage is split into two parts: The first part deals with preparing a suitable text file that consists of the CREATE INDEX commands, the second part is about processing this text file with as many worker threads as desired.
Preparing the file is straightforward: You can use the "transform_all_sql.sh" script to generate the required CREATE INDEX script from a DDL script created via IMPDP SQLFILE.
The script has been tested primarily with bash, sed and awk under Cygwin 1.7.1 and OEL5, different Unix flavors might have different versions of the shell, awk or sed and therefore might behave differently.
Simply put all four Unix scripts in the "correct_parallel_clause" directory into the same directory, mark them as executable and run the "transform_all_sql.sh" like that:
./transform_all_sql.sh < input_file > output_file
where "input_file" is the file generated via IMPDP SQLFILE option and "output_file" will be the result.
In order to perform the parallel index creation, you need an account that has suitable privileges granted. Since it is assumed that the indexes will have to be created in different schemas this account will have to have extended privileges granted. The package is implemented using invoker's rights so granting these privileges via roles is sufficient. A quick and dirty solution could be creating a temporary account and granting simply the DBA role to it (this is what I used to do to test it). Note that the account also requires EXECUTE privileges on the DBMS_AQ and DBMS_AQADM packages for the AQ stuff. It also needs a simple logging table where errors and progress will be written to as well as a type that is used as payload of the queue. Obviously the account also needs to be able to create jobs - in this version of the package this is done via DBMS_SCHEDULER. At execution time the package is going to create a queue plus queue table that also needs to be stored in a tablespace - so you should make sure that the account (or at least the database) that executes the index creation has an appropriate default tablespace defined.
You can simply run the "pk_create_index_concurrent.sql" script (located in the "source" directory) in such a suitable account which will deinstall/install all required objects.
The execution of the index creation is then straightforward (taken from the package specification):
/**
* The main entry point to create indexes via parallel threads / AQ
* @param p_directory_name The directory where the file resides that contains the CREATE INDEX DDLs
* @param p_file_name The file name in the directory above
* @param p_parallel_degree_set_1 The number threads to start for the worker thread 1 which usually
represents the SERIAL_INDEX threads - G_AUTO_PARALLEL_DEGREE means use the CPU_COUNT and
CLUSTER_DATABASE_INSTANCES parameter to determine number of threads automatically
* @param p_parallel_degree_set_2 The number threads to start for the worker thread 2 which usually
represents the PARALLEL_INDEX threads - G_AUTO_PARALLEL_DEGREE means get the CPU_COUNT and
CLUSTER_DATABASE_INSTANCES parameter to determine number of threads automatically,
however 1 is the default here since we assume that these indexes use parallel DDL
* @param p_job_submit_delay The number of seconds each job will be delayed to allow Oracle
proper load balancing in a cluster, default 30 seconds (commented out at present due to
odd locking issues on the queue table in RAC environments)
* @param p_sleep_seconds The number of seconds to wait for the threads to startup
before attempting to teardown the AQ infrastructure again
* @param p_optional_init Optionally a SQL can be passed usually used to initialize the session
for example forcing a particular parallel degree
* @param p_worker_set_id_1
The character identifier used to identify the indexes to process by the first worker thread set
Default value is "SERIAL_INDEX"
* @param p_worker_set_id_2
The character identifier used to identify the indexes to process by the second worker thread set
Default value is "PARALLEL_INDEX"
**/
procedure create_index_concurrent(
p_directory_name in varchar2
, p_file_name in varchar2
, p_parallel_degree_set_1 in integer default G_AUTO_PARALLEL_DEGREE
, p_parallel_degree_set_2 in integer default 1
, p_job_submit_delay in integer default 30
, p_sleep_seconds in integer default 10
, p_optional_init in varchar2 default null
, p_worker_set_id_1 in varchar2 default G_WORKER_SET_ID_1
, p_worker_set_id_2 in varchar2 default G_WORKER_SET_ID_2
);
Note that the "p_job_submit_delay" parameter is currently not used - there were some odd locking issues on the AQ table in case of a RAC environment when using that option so I have commented out its usage at present - I haven't had a chance yet to investigate further what the problem actually was.
So the only required input to the CREATE_INDEX_CONCURRENT procedure is the name of the directory object that points to the directory where the file to process resides and the name of the file itself.
You probably want to specify the number of worker threads for the two sets: The idea here is to distinguish between the creation of serial and parallel indexes. The first parameter specifies the number of worker threads used for serial indexes, the second one the number of concurrent threads for parallel indexes.
The default is CPU_COUNT * INSTANCES threads for serial indexes and a single thread for parallel indexes.
If you don't want/need this separation of serial and parallel indexes simple use the same "worker_set_id" for both parameters "p_worker_set_id_1" and "p_worker_set_id_2" and specify the desired total parallel degree in one of the degree parameters and set the other one to 0 (the 0 is required otherwise one of the DBMS_SCHEDULER.CREATE_JOB calls will fail with a "duplicate job name/job name already exists").
The "p_sleep_seconds" parameter is only used to allow the jobs spawned to put a lock on the queue table - the teardown is then going to wait until all locks have been removed and therefore all queue processing has ended. The default of 10 seconds was sufficient in all cases I've encountered.
Since the package requires as prerequisite a directory where the file to process resides, I've prepared the script "create_index_concurrent.sql" that guides through the required inputs and takes care of that step as well.
It takes the full O/S path to the file and the file name as input, creates a directory CREATE_INDEX_CONCURRENT_DIR pointing to that directory and prompts then for the two degrees as input and the names of the two worker thread sets before calling the CREATE_INDEX_CONCURRENT stored procedure.
Caveats
Please note that you should double-check not to pass a non-transformed SQLFILE generated via IMPDP to the procedure - the results may be dire since the generated SQLFILE always contains much more than the bare CREATE INDEX commands, no matter what options you use for IMPDP. Always use the provided Unix scripts to post-process the SQLFILE before initiating the index creation.
Furthermore you need to be aware of the current limitation of the package that it does not attempt to tokenize the file contents. It simply uses a semicolon as delimiter to separate the DDL commands. This should be sufficient for most cases, but in case you have a function-based index using a string expression containing a semicolon as part of the index definition this will not work as expected. Also if you plan to use this package for other DDL execution activities like CTAS statements you might again hit this limitation if the DDL text contains semicolons.
Note that creating indexes using this tool results potentially in different index statistics than creating the indexes using IMPDP since IMPDP by default also imports the index statistics whereas the indexes created using this tool will end up with the current index statistics automatically generated during index creation (from 10g onwards, and the code requires at least 10.2). If you want to have the index statistics imported you can run IMPDP after the index creation using the INCLUDE=INDEX_STATISTICS option. This should complete fairly quickly and will import the index statistics only.
If you have SERVEROUTPUT enabled by default then you will very likely see some errors that will be printed by the initial attempt to tear down the AQ infrastructure. These errors are expected if the previous run was completed successfully or in case of the initial run and can be ignored (and will be catched/ignored by the default implementation).
Note also that all provided scripts except for the Unix shell scripts use DOS file format - under OEL this isn't a problem but it might be on your platform.
Finally the inevitable disclaimer: Although this has been tested thoroughly it comes with absolutely no warranty. Use it at your own risk and test it in your environment before attempting any runs against anything important.
Monitoring the execution
The code logs errors and progress into the table CREATE_INDEX_CONCURRENT_LOG. At present the code logs every attempt to execute DDL into the table as well as any errors that are raised during that DDL execution.
So the table can be used for both, monitoring the progress as well as checking for errors. The code currently continues the execution in case of errors encountered using the dreaded WHEN OTHERS THEN NULL construct, but the code is already prepared for a more granular error handling if required - see the defined exceptions and commented out exception handler.
You can view the queue contents in the corresponding queue view created by the AQ setup (AQ$CREATE_INDEX_QUEUE) in order to see the data to process. Note that due to the fact that all worker threads do not commit the queue transaction you won't be able to see the progress in the queue table until all worker threads committed. If you don't like that you can remove the wait and "teardown_aq" call at the end of the main procedure "create_index_concurrent" and uncomment the dequeue option "visibility=immediate" in the "create_index_thread" procedure. You would need then to call "teardown_aq" in a separate step as desired. With this modification you can monitor the progress by monitoring the queue, but the provided automated unit testing won't work with that variant since it relies on the main call to wait for all worker threads to complete before validating the results.
However you can see the progress also in the log table using the following sample query:
select
to_char(log_timestamp, 'DD-MON-YYYY HH24:MI:SS.FF') as log_timestamp
, sql_statement
, message
from
create_index_concurrent_log
order by
log_timestamp desc;
If you want to perform more sophisticated queries on the that table you might need to use some casts similar to the following, because the text columns are defined as CLOBs in order to be able to hold the complete DDLs and error messages in case of errors. The casts allow you to perform for example GROUP BYs etc.
select
to_char(log_timestamp, 'DD-MON-YYYY HH24:MI:SS.FF') as log_timestamp
, cast(substr(sql_statement, 1, 30) as varchar2(30)) as index_name
, cast(substr(message, 1, 128) as varchar2(128)) as worker_set_id
from
create_index_concurrent_log
order by
log_timestamp desc;
The Unit Testing
Here we come to a completely different issue that is off-topic for this post, however in my experience so far it seems to be a very important one and I hopefully will have the time to cover it in the future with separate posts.
Generally speaking I've seen to many shops that don't follow best-practice when it comes to database deployment and development, therefore here is what you should know/do about it ideally - in a nutshell:
- Treat your database like source code, which means put everything related to the database under version control. This includes not only the obvious database source code but also DDL and DML scripts for schema evolution
- Use unit testing to test database code. Automate this unit testing
- Automate the deployment of your database related changes
- Install a continuous integration environment that runs the automated deployment and unit tests regularly, for example every night
- Automate deployment everywhere - starting from the development databases up to the production environment
- Follow your guidelines strictly - for example any hotfix-like adhoc change should still go through the established processes - code changes, testing, deployment etc.
I've helped several clients in the past to setup corresponding tools and processes for implementing above - if you are interested, get in touch with me.
So as a bonus, if you haven't spent too much time yet with above mentioned topics, in order to get you started at least with automated unit testing, I've included two different examples for this small source provided, one using the built-in unit test feature of SQLDeveloper and the other one using "dbunit". You can find both in the corresponding subdirectories of the "test" folder in the archive.
The unit testing is based on the "pk_create_index_concur_test.sql" package that is used to setup and teardown the environment for running the unit test. It assumes at present the existence of a directory "C:\app\oracle\admin\orcl112\dpdump" on O/S level. It will create a directory object for the path and attempt to create/write a file used for the unit test runs. You can pass any valid O/S directory path to the "pk_create_index_concur_test.setup" procedure if you want/need to use a different one.
All provided automated tests assume that both scripts, "pk_create_index_concurrent.sql" and "pk_create_index_concur_test.sql" have been run in the schema that should be used for test runs.
You can use the SQLDeveloper Unit Test feature to run the provided Unit Test. You can either use the GUI to import and run the test, or you can use a command line version that is actually using ANT to run the UTUTIL command line tool that comes with SQLDeveloper. You can read and follow the instructions in the "README.txt" in the test/SQLDeveloper directory how to do so. You'll need to setup a unit test repository initially if you want to use SQLDeveloper's unit testing feature either way (GUI or UTUTIL command line). See the SQLDeveloper's user's guide or online help how to do that (Hint: Menu item "Extras->Unit Testing" gets you started).
If you don't like the SQLDeveloper unit test approach or you are simply to lazy to install the tool, the unit test repository etc., you can alternatively try the automated unit testing using "dbunit". Follow the instructions in the "README.txt" in the test/dbunit directory how to run the unit tests using "dbunit".
This version of the package has successfully been tested using these unit tests on 10.2.0.4, 10.2.0.5, 11.1.0.7, 11.2.0.1 and 11.2.0.2 (after all it's dead easy with automated unit testing :-).
Summary
The provided tool set should represent a solid foundation for the given task of concurrent index creation. In particular it has been designed with the following in mind:
- Efficient use of privileges granted via roles: The package uses invoker's rights and most operations use dynamic SQL to avoid compilation issues, therefore granting the required privileges to the account used via roles should be sufficient
- The Unix scripts should be able to deal with table-, schema- and database-level datapump formats from Oracle 10g and 11g (all these variants use slightly different texts to identify the relevant sections of the generated SQLFILE by IMPDP)
- Optional use of two separate worker thread sets: This allows the concurrent creation of a multitude of indexes, be it serial or parallel, with clear distinction between the handling of serial (possibly many worker threads) and parallel indexes (usually only a few worker threads)
- Support for arbitrarily sized SQL: The DDL commands for (sub-)partitioned indexes can become quite large due to the way the Oracle meta data API generates the SQL. Therefore these generated SQLs can easily exceed the usual 32KB limit for PL/SQL character strings. The implementation uses CLOBs for the processed SQLs (and DBMS_SQL in versions lower than 11 to handle these piecewise) to support these potentially very large SQLs
- RAC/Grid/Cluster support via DBMS_SCHEDULER: The usage of DBMS_SCHEDULER allows a fine grained control of the resource consumption by the optional use of job classes (not implemented yet but can easily be added - it is a simple additional parameter to the CREATE_JOB procedure) that allow to specify a resource consumer group and a specific service name for the spawned worker threads
- Automated Unit Testing support: The provided unit test harness allows for easy testing of modifications to the code
Randolf
ReplyDeleteQuestion for you. So, when do you run this scripts for concurrent index creation parallelly when the data pump import job is in progress?
Thanks
The idea is to skip the index creation part of the datapump import (e.g. using the EXCLUDE=INDEX option), and afterwards as a separate step run this procedure to create the indexes.
ReplyDeleteSo the "concurrent" in the title refers to the ability to create multiple indexes at the same time - it does not refer to a "concurrent" operation while the datapump import is running.
Hope this helps,
Randolf
Randolf,
ReplyDeleteWhen the impdp is done creating the tables and starts the Index creation phase - we can stop the job - Run process you have outlined above to create indexes and - Resume the impdp job. This way we can be really sure that wont miss anything and also constraints will be enabled at the end.
Regards,
Sanjeev.
Sanjeev,
ReplyDeletethanks, sounds like a good approach. Have you tried it and what does IMPDP with the fact that all the indexes are already created that it tries to create then?
Does it handle that gracefully and just logs the "already exists" error or are there any other side effects of this approach to be aware of?
Randolf
Randolf,
ReplyDeleteWe have gone through your approach and have not test in our environment yet, but we have tried doing index creation manually from outside(in parallel sqlplus sessions) and resumed datapump job and did not have any issues.
Will keep you posted on how our environment testing goes with the approach you suggested.
Regards
Hi Randolf
ReplyDeleteI am trying this approach. I am running the transform script and it is taking sometime. I have around 1000 indexes in this schema i wanted to try first.
Will keep you posted.
-- Kumar
Hi Randolf
ReplyDeleteI am trying to create some missing indexes using this approach. But the sql file has all 'create index' statements. So when the job executes there are errors(name already used by existing object) which is ok. Some indexes get created but I get error like this
ORA-27477: "KMADDURI.KUMAR_1" already exists
These are the parameters I pass for the sql file
OS Path : /linux_migration/OF2INT
Filename : xxdl_indexes2.sql
Serial Degree : NULL
Parallel Degree : 1
Worker Thread 1 Name: KUMAR
Worker Thread 2 Name: KUMAR
Kumar,
ReplyDeleteI think I'm having trouble understanding what exactly your problem is.
You seem to try to create some missing indexes, and the script that you supply includes also indexes that already exist.
Therefore I would expect such errors to be shown in the log since the indexes that already exist will raise this error during processing, but I think in the version of the provided logic a worker thread that encounters such an error should continue, since it catches the error and attempts to go ahead with the next entry from the queue.
So what exactly is your point? Do you try to express that some of the missing indexes have not been created, or that you get the "already exists" error for indexes that you think are missing?
Randolf
Hi Randolf:
ReplyDeleteI verified after I posted the comment and the indexes are created as expected. I also read the README in which you did mention about the logic where if an index already exists or if there is an error, the script would continue.
But I had to run the sql script couple of times and the first time it failed with
ORA-27477: "KMADDURI.SERIAL_INDEX_20" already exists
and the table or directory were not dropped.
I run the second time again and this time it created additional indexes that were missed because of the failed prior run and exited again though with this error ORA-27477: "KMADDURI.KUMAR_1" already exists
So I run the sql script again and this time it did not have any indexes to be created because the first two runs already created the indexes and this time the program exits cleanly and drops the directory in the end.
I was trying to udnerstand why I got the ORA-27477 error (I choose the default values for all the prompts except the name of the job in the second run which i Put KUMAR).
Thank you for your time..
Kumar
Hi Kumar,
ReplyDeleteI think I get your problem now. You are not referring to an error in the log but you get an error from the "coordinator" session where you attempt to start the jobs.
The error is caused by the DBMS_SCHEDULER.CREATE_JOB call - a scheduler job is actually a database object and therefore needs to have a unique name.
The error tells you that there is already a job with that name.
For your second attempt the error can be explained - as I've outlined in the text if you use the same name for both worker threads then you need to specify "0" (not "NULL" - note that "NULL" and "0" have different meanings in general and in particular here) for one of the worker thread degrees, otherwise you'll end up with exactly that error because the script will attempt to create two sets of jobs with overlapping names.
However it doesn't explain why you got a similar error at initial invocation, I can't tell with the information provided why that error occurred when running the script for the first time.
In principle it means that there is already such a job - however when running for the very first time there should not be such a job.
If you had used the same name for the two worker threads also in your initial attempt without setting one of the degrees to 0, this would explain the problem as outlined in the blog post.
Randolf
Thank you Randolf. I will try again and see. I will keep you posted.
ReplyDeleteKumar
Hi Randolf,
ReplyDeleteI have used this method and able to import the indexes. But your transform_all_sql.sh is not taking care of Domain Indexes. Hence i have tried creating the domain indexes manually. But i get the below error.
SQL> create index AR.hz_class_code_denorm_t1_1 on AR.HZ_CLASS_CODE_DENORM(CLASS_CODE_MEANING) indextype is ctxsys.context ;
create index AR.hz_class_code_denorm_t1_1
*
ERROR at line 1:
ORA-29855: error occurred in the execution of ODCIINDEXCREATE routine
ORA-20000: Oracle Text error:
DRG-00100: internal error, arguments : [51021],[drwaf.c],[1607],[],[]
ORA-06512: at "CTXSYS.DRUE", line 160
ORA-06512: at "CTXSYS.TEXTINDEXMETHODS", line 366
I have tried workarounds from several Metalink notes but i am still having the problem.
Is this something you have a workaround already ? If so, can you tell me the workaround please.
Regards,
Nagendra.
Hi Nagendra,
ReplyDeletethanks for reminding me of Domain Indexes. These are indeed not covered by the current version of the script.
Regarding your specific problem creating the Domain Index: Unfortunately I don't know more about this particular error. Probably a case you have to sort out with Oracle Support I guess.
Randolf
@Nagendra,
ReplyDeletemaybe in your case is a way to exclude CTX schema and recreate it later again ...
i.e.:
http://www.databasedesign-resource.com/oracle-indexes.html
Hop this helps,
Damir
Hi - this is an excellent blog post and I am looking forward to trying it out. However the zipfile is unavailable - is your site down?
ReplyDeleteThanks!
Mark
Hi Mark,
ReplyDeletethe link works for me - note however that my site uses a non-default port of 7676 rather than 80, therefore you might have trouble behind some corporate firewalls.
Randolf
You are right - it works fine from home. I am merging your code with some additional procedures invoking dbms_datapump so that it can be invoked without database server access - for example - for use by developers. Also have you considered using dbms_metadata.get_dll to extract the "create index" commands? The benefit would be to keep all processing inside pl/sql - time permitting I will probably try it out and let you know how it goes.
ReplyDeleteI don't quite understand the problem, if there are a 100 indexes to create and I am running the data pump with 8 worker threads, wouldn't each of the worker threads work on one index, ie: 8 indexes are being created in parallel, instead of one index being created by 8 threads in parallel. So in effect at a give time the same amount of work is getting done. Did I miss something?
ReplyDelete> I am running the data pump with 8 worker threads, wouldn't each of the worker threads work on one index, ie: 8 indexes are being created in parallel, instead of one index being created by 8 threads in parallel
ReplyDeleteHave you tried it? No matter how many worker threads you define, when it comes to index creation only a single worker thread will be active. On top of that there is this problem in some versions with PARALLEL indexes that don't get rebuild in parallel.
So these are the reasons for this post.
Randolf
Hello randolf
ReplyDeleteDoes your concurrent index creation process be used on a 10gR2 standard edition ?
I have to import a 1To 10.2.0.4 EE to a 10.2.0.4 SE where parallel option is not allowed...
thank you
Noel
Noel,
ReplyDeletehonestly I haven't tried the procedure yet on a Standard Edition.
But since this is simply a specific implementation of a process spawning multiple threads to perform a task concurrently the main building blocks are:
- Advanced Queueing
- Scheduler
Hence if these components are supported by Standard Edition this should work. Each thread will then only be able to create an index serially.
I don't know what is going to happen to indexes that have been defined as parallel in your Enterprise Edition source database - whether Standard Edition simply ignores the PARALLEL attribute or throws an error, but then you can influence the script that is being processed and remove the PARALLEL clause if necessary.
Randolf
hello randolph
ReplyDeleteIt seems that advanced queuing and scheduler are available in SE. my first import test with EXCLUDE=INDEX option show that unique indexes are created cause I don't exclude primary keys constraints, so the question is :
do we must include unique indexes in your process, with EXLUDE=CONSTRAINT ?
In this case we must test if we can create constraint by script without rebuilding unique indexes, my import of one schema of 600Gig took 7h00, but the constraint took 5h30...
thank you
Noel,
ReplyDeletethat sounds like a reasonable approach. If you can include the creation of the indexes supporting the constraints into the scripts used to populate the queues for the worker threads, then you should be able to create the corresponding constraints afterwards on top of the already existing indexes without the need to rebuild / recreate any of them.
Randolf
Hello randolf
ReplyDeletejust to jeep you informed, your process works fine in Standard edition, i rebuild the 28000 indexes of my JDE DB in just 1h40, including unique indexes, I use 40 process, on a P740 with 4 cores and 4 threads per core, on the new production server we will have 12 cores...so hope to run the full import in less than 6h, compared to 20h with the non optimized process...
So thank you a lot, randolf, you saved my migration process !...
Best regards
Noel
Hi Noel,
ReplyDeletethanks for the update. It's nice to hear that the information provided here helps you!
Thanks,
Randolf
Hello randolf
ReplyDeleteImportant precision : the concurrent process does not work in RESTRICT MODE,
the instance must be fully open...
Thank you
Noel
Hi Randolf,
ReplyDeleteThanks for sharing your efforts. This really helped me save some serious time. Datapump is not using parallel for enabling on constraints (pk as well as ref-constraints) and spends a huge amount of time. I think we can save a lot of time by running the constraints in parallel mode using 'alter session enable parallel ddl'. I am not good at sed/awk. Do you have any plans to extend your script for Constraints too? It will be a great help if you could. Thanks again for helping out!
Hi Ram,
ReplyDeletethanks for your comment.
Apologies for the delayed response, but I was on vacation for the last couple of days.
I haven't looked into the details of Datapump and constraint enabling resp. validation.
At present I would assume that I won't spend time on that topic in the near future, so don't expect anything in that regard.
Randolf
Files aren't available, could you please re-post it?
ReplyDeleteThe files are still available, but probably you try to download from behind a firewall that prevents downloads from non-default ports - the site hosting the files uses non-default port 7676 (see previous comments).
ReplyDeleteRandolf
I must thank you for the efforts you've put in penning this site.
ReplyDeleteI am hoping to see the same high-grade blog posts from you in the future
as well. In truth, your creative writing abilities has inspired
me to get my own site now ;)