|  | 
	| 
		
			| Re: SQL Tune [message #429923 is a reply to message #429917] | Fri, 06 November 2009 05:35   |  
			| 
				
				
					| JRowbottom Messages: 5933
 Registered: June 2006
 Location: Sunny North Yorkshire, ho...
 | Senior Member |  |  |  
	| Quote: Database Vesion 10 R2 (10.2.0.4) but SQL Query running from 9i R2
 
 What does this mean?
 Either the query is running on a 10g database or it isn't.
 
 An alternative query that should get the same result, but only hit the table once is:
 select sum(case when row_number() over (partition by BIN, ORG, LOGO) > 1 then 1
                when nvl(bin,0) = 0 then 1
                when nvl(org,0) = 0 then 1
                when nvl(logo,0)= 0 then 1
                else 0 end)
FROM   STATEMENTS.STATEMENTS_BINS
 Can you post the plan from when the query runs slowly?
 |  
	|  |  | 
	| 
		
			| Re: SQL Tune [message #429925 is a reply to message #429923] | Fri, 06 November 2009 05:50   |  
			| 
				
				
					| babuknb Messages: 1736
 Registered: December 2005
 Location: NJ
 | Senior Member |   
 |  |  
	| Database version 10.2.0.4 but end user executing sql query from 9i client connect to 10g database. 
 
 
SQL> 
SQL> set timing on 
SQL> 
SQL> select sum(case when row_number() over (partition by BIN, ORG, LOGO) > 1 then 1
                when nvl(bin,0) = 0 then 1
                when nvl(org,0) = 0 then 1
                when nvl(logo,0)= 0 then 1
                else 0 end)
FROM   STATEMENTS.STATEMENTS_BINS
  2    3    4    5    6    7  
SQL> /
select sum(case when row_number() over (partition by BIN, ORG, LOGO) > 1 then 1
                     *
ERROR at line 1:
ORA-30483: window  functions are not allowed here
Elapsed: 00:00:00.00
 Getting some issue. Please review your sql statement.
 
 Thank you in advance.
 [Updated on: Fri, 06 November 2009 05:51] Report message to a moderator |  
	|  |  | 
	|  | 
	| 
		
			| Re: SQL Tune [message #429930 is a reply to message #429925] | Fri, 06 November 2009 06:07   |  
			| 
				
				
					| JRowbottom Messages: 5933
 Registered: June 2006
 Location: Sunny North Yorkshire, ho...
 | Senior Member |  |  |  
	| Looks like your 9i client is doing some parsing - what is the client that your're using? 
 You can use this as a workround:
 SELECT SUM(val)
FROM  (SELECT CASE WHEN row_number() OVER (PARTITION BY BIN, ORG, LOGO ORDER BY NULL) > 1 THEN 1
                   WHEN NVL(bin,0) = 0 THEN 1
                   WHEN NVL(org,0) = 0 THEN 1
                   WHEN NVL(logo,0)= 0 THEN 1
                   ELSE 0 END val
       FROM <TABLE>)
 Hw often does the original query run slowly, and is there anything going on in the Db when this happens?
 
 |  
	|  |  | 
	|  | 
	| 
		
			| Re: SQL Tune [message #429949 is a reply to message #429932] | Fri, 06 November 2009 08:04   |  
			| 
				
				
					| JRowbottom Messages: 5933
 Registered: June 2006
 Location: Sunny North Yorkshire, ho...
 | Senior Member |  |  |  
	| Well, that's got your consistent gets down by 3 orders of magnitude. 
 
 There's not a lot we can do without more information from you.
 
 Quote:
 what is the client that your're using? Quote:
 ...and is there anything going on in the Db when this happens? Quote:
 Can you post the plan from when the query runs slowly? |  
	|  |  | 
	|  |