-
15. Re: Simple insert into table hanging
AndrewSayer Nov 10, 2016 8:34 PM (in response to AParm)Amarprem wrote:
These are the execution plans
SELECT STATEMENT (REMOTE)
- HASH (GROUP BY) 9
- Access Predicates 9
A1.EDL_ID = A2.EDL
- TABLE ACCESS (FULL) OFFERS 981915
- TABLE ACCESS (FULL) LIST 1786967
INSERT STATEMENT
-LOAD TABLE CONVENTIONAL
- HASH (GROUP BY) 9
- Filter Predicates 9
NOT EXISTS(SEELCT 0 FROM A1 LNNVL(LIST.EDL_ID)<>:B1)
- REMOTE OFFERS 982004
- REMOTE LIST 1
How do I get the insert to use the same plan as the select?
Your statement doesn't seem that simple if it's doing a group by and a not exists (or is that really a not in?) on a remote DB.
As I've said before, to get the same plan you can either hint it (by checking the outline and note that it's probably a driving_site hint you are after)
OR you can use PLSQL..
FWIW I would consider a plan exposed using dbms_xplan much easier to read than what you have presented, you can also get it to include the full outline. If you need help doing that then google it or ask - don't just ignore the request.
-
16. Re: Simple insert into table hanging
AParm Nov 10, 2016 8:34 PM (in response to Mustafa KALAYCI)insert into OFFERS_CHECK(
EXTRCT,
ISSUE,
A_COUNT,
SITE,
SOURCE
)
select
EXTRCT,
ISSUE,
A_COUNT,
SITE,
SOURCE from
V_OFFERS_CHECK;CREATE V_OFFERS_CHECK
AS
select
'OFFERS' EXTRCT
'MISSING OFFERS' ISSUE,
count (*) A_Count,
OFFERS.SITE,
OFFERS.SOURCE
from OFFERS
WHERE OFFERS.EDL_ID not in (select EDL_ID from LIST)
and SOURCE = 'PST'
GROUP BY OFFERS.SITE,
OFFERS.SOURCE;Simple, just check for all offers not in the LIST.
The select on it's own, less than a second. The insert just hangs, I just have to kill it.
-
17. Re: Simple insert into table hanging
Mustafa KALAYCI Nov 10, 2016 8:42 PM (in response to AParm)where are the other databases ? OFFERS and LIST tables, are these on different databases ?
-
18. Re: Simple insert into table hanging
AParm Nov 10, 2016 8:49 PM (in response to Mustafa KALAYCI)No they are on the same pluggable database LIVE, the are being accessed for reporting database.
Why should it matter, they are all just pluggable database on the SAME oracle server.
-
19. Re: Simple insert into table hanging
AndrewSayer Nov 10, 2016 8:55 PM (in response to AParm)Amarprem wrote:
No they are on the same pluggable database LIVE, the are being accessed for reporting database.
Why should it matter, they are all just pluggable database on the SAME oracle server.
Remote inserts optimize differently.
Remote could be different Pdb or different server completely.
Where in the view/query are you specifying the db link? The view (I'm assuming that's what it is) is not valid DDL so I assume that wasn't copy and paste?
Have you tried the PL/SQL solution yet (I think I've mentioned it 4 times now).
begin
for rec in (select EXTRCT,
ISSUE,
A_COUNT,
SITE,
SOURCE
from V_OFFERS_CHECK
)
loop
insert into OFFERS_CHECK(EXTRCT,
ISSUE,
A_COUNT,
SITE,
SOURCE
)
values
(rec.EXTRCT,
rec.ISSUE,
rec.A_COUNT,
rec.SITE,
rec.SOURCE);
end loop;
end;
/
-
20. Re: Simple insert into table hanging
AParm Nov 10, 2016 9:01 PM (in response to AndrewSayer)OFFERS and LIST, are synonyms to tables on the 'remote' server.
Thanks for this, I will try it, I will look at dbms_xplan, and take this up again tomorrow.
-
21. Re: Simple insert into table hanging
rp0428 Nov 10, 2016 9:05 PM (in response to AParm)Why should it matter, they are all just pluggable database on the SAME oracle server.
I told you in my reply why it matters.
Each PDB is a separate and distinct database regardless of where they are physically located.
If you follow the example I provided and answer the question I ask then you will understand why it 'matters'.
-
22. Re: Simple insert into table hanging
Mustafa KALAYCI Nov 10, 2016 9:16 PM (in response to AParm)rp0428 gave us a very good example at his first reply. you might be carrying all the rows from the db where tables located to database that you will make your insert. at first I thought that OFFERS and LIST tables are on different databases too but if they are on the same db, then this could be your problem, your insert statement works on the remote db (not at the db that offers and list are in it).
-
23. Re: Simple insert into table hanging
AndrewSayer Nov 10, 2016 9:25 PM (in response to Mustafa KALAYCI)Mustafa KALAYCI wrote:
rp0428 gave us a very good example at his first reply. you might be carrying all the rows from the db where tables located to database that you will make your insert. at first I thought that OFFERS and LIST tables are on different databases too but if they are on the same db, then this could be your problem, your insert statement works on the remote db (not at the db that offers and list are in it).
The plan tells us that for the insert statement:
All the rows from offers that match the simple predicate (SOURCE = 'PST') are pulled across from the remote DB to the local DB
For each row it then fires another query against the remote DB to check the existence in LIST (FILTER operation)
It then does the group by on the local DB
For the select statement, the entire query was passed to the remote DB which has unnested the not in subquery into an antijoin. The results were then passed to the local DB. This was much better because it was able to unnest the not in subquery rather than execute an existence check for each row.
-
24. Re: Simple insert into table hanging
AParm Nov 10, 2016 10:03 PM (in response to AndrewSayer)How can I get it to use same the plan for insert as for the select?
Why does it have a cardinality of 1 for LIST in the insert plan as opposed to the 1786967 in the select, is this because it is fetching a single row at a time?
-
25. Re: Simple insert into table hanging
AndrewSayer Nov 10, 2016 10:09 PM (in response to AParm)Amarprem wrote:
How can I get it to use same the plan for insert as for the select?
Why does it have a cardinality of 1 for LIST in the insert plan as opposed to the 1786967 in the select, is this because it is fetching a single row at a time?
I've recommended two ways, if you're going to just ignore them then why should we bother to help further. I've even allowed you to be lazy enough and just use copy and paste some code.
If you want more help then you will have to do some of the work yourself, if you're struggling to understand what has been recommended then try googling first and then asking for clarification. Repeating the same question will only lead to the same response.
-
26. Re: Simple insert into table hanging
John Thorton Nov 10, 2016 10:11 PM (in response to AndrewSayer)You can lead some folks to knowledge, but you can't make them think.
-
27. Re: Simple insert into table hanging
rp0428 Nov 10, 2016 11:03 PM (in response to AParm)How can I get it to use same the plan for insert as for the select?
How can we get YOU to answer our questions?
You may not be able to get Oracle to use the same plan. The only possible option is to try using the DRIVING_SITE hint but I wouldn't expect that to work.
-
28. Re: Simple insert into table hanging
Jonathan Lewis Nov 10, 2016 11:38 PM (in response to AParm)Andrew Sayer has given you one of the solutions to the problem - try it.
A distributed (or fully remote) select statement can be optimised and executed at a site other than the one where the statement was issued - returning the result to the original site. A CTAS or an "insert as select" MUST (for no good reason offered by Oracle Corp.) execute at the site where the table is to be created or insert into - which leads to the type of issue you're seeing.
See: https://jonathanlewis.wordpress.com/2008/12/05/distributed-dml/ (and its comments and pingbacks - which will lead you to other solutions)
Regards
Jonathan Lewis
-
29. Re: Simple insert into table hanging
jgarry Nov 11, 2016 12:10 AM (in response to AParm)Amarprem wrote:
No they are on the same pluggable database LIVE, the are being accessed for reporting database.
Why should it matter, they are all just pluggable database on the SAME oracle server.
It matters because Oracle needs to communicate back and forth between the databases, and must have limits on how it does that (which don't have to make sense on the surface, though normally there are reasons when you dig enough). If you established a dblink to the same database, it would still have to obey those limits, it doesn't magically know where a remote database actually is. Sometimes hiding things in views can have additional limitations. So in addition to rp0428's concrete blocks analogy, you have to pass the concrete through a drainage pipe.
It's also not necessarily a good sign that two full table accesses are the faster way to do something that is not a cartesian join. In addition to the questions others have asked, you might describe things like how many rows you expect to select update out of how many there are. There's probably some way to limit the unnecessary work being done, and that's the secret to making it go faster. You might also search asktom.oracle.com on the subject of exists versus in. There may also be indexing solutions for "things not in."