DetailPage-MSS-KB

Microsoft small business knowledge base

Article ID: 240340 - Last Review: February 28, 2014 - Revision: 4.2

This article was previously published under Q240340
This article has been archived. It is offered "as is" and will no longer be updated.

On This Page

SYMPTOMS

Attempting to use a query with an Oracle linked server using the MSDAORA OLE DB provider, for example:
select * from OracleServer..demo.Product
				
may cause an error similar to the following:
Server: Msg 7306, Level 16, State 2, Line 1
Could not open table '"demo"."Product"' from OLE DB provider 'MSDAORA'. The specified table does not exist.
[OLE/DB provider returned message: The specified table does not exist]
[OLE/DB provider returned message: ORA-00942: table or view does not exist]

CAUSE

The query may not work because of case sensitivity in Oracle since SQL Server uses quoted names when it ships queries to a provider.

WORKAROUND

Use the following rules when referencing tables in an Oracle linked server:
  • If the table and column names were created in Oracle without quoted identifiers, use all uppercase names. For example, the following should work OK:
    select * from OracleServer..DEMO.PRODUCT
    						
  • If the table and column names were created in Oracle with quoted identifiers, use the same case for all letters of the names as was used when the names were created in Oracle.
Case-sensitivity is not an issue when using OpenQuery or OpenRowset function. The following should work OK:
SELECT * FROM OPENQUERY(OracleServer, 'select * from PrOdUct')
go
SELECT * FROM OPENRowset('MSDAORA', 'myOracleServer';'demo';'demo', 'select * from PrOdUct' )
go
				

MORE INFORMATION

Microsoft SQL Server version 7.0 provides the ability to perform queries against OLE DB providers. This is accomplished by using the OpenQuery or OpenRowset Transact-SQL functions or by using a query with four part names including a linked-server name. For example:
sp_addlinkedserver 'mylinkedserver', 'product_name', 'myoledbprovider', 'data_source','location', 'provider_string', 'catalog'
SELECT * FROM OPENQUERY(mylinkedserver, 'select * from table1')
				

Steps to Reproduce the Behavior

  1. Set up a linked server to Oracle server:
    EXEC sp_addlinkedserver   'OracleServer',  'Oracle',  'MSDAORA',  'myOracleServer'
    go
    EXEC sp_addlinkedsrvlogin 'OracleServer', 'FALSE', NULL, 'demo', 'demo'
    go
    						
  2. Specify a four part name query:
    SELECT * FROM OracleServer..demo.Product
    						
    Which reports the error described in the SYMPTOMS section.

REFERENCES

For additional information on SQL Server distributed queries with Oracle data source, see the SQL 7.0 Books Online topic "OLE DB Provider for Oracle" and the following articles in the Microsoft Knowledge Base:
220915  (http://support.microsoft.com/kb/220915/EN-US/ ) PRB: SQL Distributed Query with Oracle Needs Oracle Client

221552  (http://support.microsoft.com/kb/221552/EN-US/ ) PRB: SQL Distributed Query with Oracle NUMERIC Column Gives Error

APPLIES TO
  • Microsoft SQL Server 7.0 Standard Edition
  • Microsoft OLE DB Provider for Oracle Server 1.0
  • Microsoft SQL Server 2000 Standard Edition
Keywords: 
kbnosurvey kbarchive kbdatabase kboracle kbprb KB240340
Share
Additional support options
Ask The Microsoft Small Business Support Community
Contact Microsoft Small Business Support
Find Microsoft Small Business Support Certified Partner
Find a Microsoft Store For In-Person Small Business Support