Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: SQL*Net message from client
Now you have your proof. The response time numbers--in particular the time
consumed unnecessarily by SNMFC events--is what that decision is costing
your business.
Cary Millsap
Hotsos Enterprises, Ltd.
http://www.hotsos.com
* Nullius in verba *
Upcoming events:
- Performance Diagnosis 101: 6/22 Pittsburgh, 7/20 Cleveland, 8/10 Boston
-----Original Message-----
From: oracle-l-bounce_at_freelists.org [mailto:oracle-l-bounce_at_freelists.org]
On Behalf Of Subbiah, Stalin
Sent: Thursday, June 03, 2004 8:16 PM
To: 'oracle-l_at_freelists.org'
Subject: RE: SQL*Net message from client
Thanks Stephane.
This is exactly what I wanted to do rather doing all individual insert/updated statements from a loop, just have one insert select and update to sync the data and generates less redo/undo too.
From: oracle-l-bounce_at_freelists.org [mailto:oracle-l-bounce_at_freelists.org]
On Behalf Of Stephane Faroult
Sent: Thursday, June 03, 2004 2:19 AM
To: oracle-l_at_freelists.org
Subject: Re: SQL*Net message from client
Stalin,
I recognize a familiar pattern ... Could it be the dreaded usual
select count(*) into boink
from yaddayadda
where ...
if (boink = 0)
then
insert into yaddayadda ..
else
update yaddayadda ...
end if;
The bad news is that you won't get much improvement (if any) without
touching the code.
The good news is that you can probably improve performance by a magical
factor with not much rewriting.
The myopic advice would be to use UPDATE/test ROWCOUNT/INSERT if 0.
However, in your special case, that would mean running the GROUP BY one the
HITS_FACT table twice for INSERTs (because you would do it for the failed
UPDATE first). It can be viable if INSERTs are few relative to UPDATEs -
since SQL*Net latency is your problem, it would reduce database calls by a
factor of almost two.
However, I feel more concerned by your :p1 and :p2 parameter. I fear that
you are running all this in a loop.
If I were you, I would get rid of the loop and execute first
UPDATE summary_hits_fact shf
SET (hit_count) =
(SELECT count(*)
FROM hits_fact hf
WHERE shf.page_hit_key = hf.page_hit_key
AND shf.hit_date_key = hf.hit_date_key);
(assuming that there is no (page_hit_key, hit_date_key) pair in the summary table which cannot be found in the main table) - not stellar, but definitely not worse than what you currently have -
then
INSERT into summary_hits_fact
SELECT hf.page_hit_key, hf.hit_date_key, count(*)
FROM hits_fact hf
WHERE (hf.page_hit_key, hf.hit_date_key)
not in (select /*+ MERGE_AJ */ page_hit_key, hit_date_key from summary_hits_fact)GROUP BY hf.page_hit_key, hf.hit_date_key
Only two statements, and no more network problem ...
A pity you are on 8.1.7, on 9.X you could have used MERGE and a single statement.
HTH, Stephane Faroult
On Wed, 2 Jun 2004 19:15 , 'Subbiah, Stalin' <SSubbiah_at_netopia.com> sent:
SELECT count (*) from summary_hits_fact shf where shf.page_hit_key = :p1 AND shf.hit_date_key = :p2 INSERT INTO summary_hits_fact (page_hit_key, hit_date_key, hit_count) SELECT hf.page_hit_key, hf.hit_date_key, count(*) FROM hits_fact hf WHERE hf.page_hit_key = :p1 AND hf.hit_date_key = :p2 GROUP BY hf.page_hit_key, hf.hit_date_key UPDATE summary_hits_fact shf SET (hit_count) = (SELECT count(*) FROM hits_fact hf WHERE shf.page_hit_key = hf.page_hit_key AND shf.hit_date_key = hf.hit_date_key) WHERE shf.page_hit_key = :p1 AND shf.hit_date_key = :p2 ---------------------------------------------------------------- Please seethe official ORACLE-L FAQ: http://www.orafaq.com
---------------------------------------------------------------- Tounsubscribe send email to: oracle-l-request_at_freelists.org put 'unsubscribe' in the subject line. -- Archives are at
http://www.freelists.org/help/fom-serve/cache/1.html ----------------------------------------------------------------- ----------------------------------------------------------------Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- Archives are at http://www.freelists.org/archives/oracle-l/ FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html ----------------------------------------------------------------- ---------------------------------------------------------------- Please see the official ORACLE-L FAQ: http://www.orafaq.com ---------------------------------------------------------------- To unsubscribe send email to: oracle-l-request_at_freelists.org put 'unsubscribe' in the subject line. -- Archives are at http://www.freelists.org/archives/oracle-l/ FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html -----------------------------------------------------------------Received on Thu Jun 03 2004 - 23:17:09 CDT