Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: TO_NUMBER
I've run into this behavior before but at the moment, I can't remember how I worked around it. I remember the workaround was not elegant.
The problem is that the optimizer merges the where clause from the query with the where clause from the view then does a full table scan. Since it is checking both conditions against every row, it fails as soon as it tries the to_number conversion on one of the non-numeric rows.
I tried to reproduce the problem on an 8.1.7.2 database but my test did not fail -- maybe Oracle changed this behavior somewhere along the way.
As a workaround, maybe you could try something like:
SELECT MSC_S_C
FROM (SELECT TO_NUMBER(MSC_SERVICE_CODE) MSC_S_C FROM msc_view)
WHERE MSC_S_C Between 1000 and 2000
Kevin Kennedy
First Point Energy Corporation
-----Original Message-----
Sent: Friday, June 28, 2002 11:05 AM
To: Multiple recipients of list ORACLE-L
LIST, I have a view like this:
CREATE OR REPLACE VIEW MSC_VIEW ( MSC_SERVICE_CODE, MSC_MTF_SERVICE_ID ) AS select MSC_SERVICE_CODE,MSC_MTF_SERVICE_ID
from MTF_SERVICE_CODE_MSC where substr(MSC_SERVICE_CODE, 1, 1) in('9','8','7','6','5','4','3','2','1','0')
when I run this query --->>
SELECT TO_NUMBER(MSC_SERVICE_CODE) FROM msc_view it works fine BUT
When I run the following query I get Invalid number(ORA-01722).
SELECT TO_NUMBER(MSC_SERVICE_CODE) FROM msc_view WHERE TO_NUMBER(MSC_SERVICE_CODE) Between 1000 and 2000
Don't undersatnd why TO_NUMBER doesn't work under WHERE clause!
Any Idea I realy Appreciate.
Thanks for Your time and Help.
Hamid Alavi
Office 818 737-0526
Cell 818 402-1987
--
Please see the official ORACLE-L FAQ: http://www.orafaq.com
--
Author: Hamid Alavi
INET: hamid.alavi_at_quovadx.com
Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Lists --------------------------------------------------------------------To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing).
Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Lists --------------------------------------------------------------------To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing). Received on Fri Jun 28 2002 - 14:31:03 CDT