August 20, 2012 at 2:48 pm
Hello Oracle Forum:
I've got my first linked server established from SQL Server 2008 SSMS to Oracle.
What is the proper syntax for this simple query with a date expression in the where clause?
What is the proper date delimiter?
Is there a conversion necessary?
SELECT TOP (5) SURGERY_DATE
FROM OPENQUERY(CLARITY, 'SELECT * FROM OR_LOG WHERE SURGERY_DATE = ('8/1/2012')' AS a
Many thanks ahead of time.
Phunhog
August 20, 2012 at 3:47 pm
Phunhog (8/20/2012)
Hello Oracle Forum:I've got my first linked server established from SQL Server 2008 SSMS to Oracle.
What is the proper syntax for this simple query with a date expression in the where clause?
What is the proper date delimiter?
Is there a conversion necessary?
SELECT TOP (5) SURGERY_DATE
FROM OPENQUERY(CLARITY, 'SELECT * FROM OR_LOG WHERE SURGERY_DATE = ('8/1/2012')' AS a
First, there is no TOP clause on Oracle - if you want the first five rows returned you have to wrap-up the query like this...
select *
from
(
type-here-your-query-including-order-by-clause
)
where rownum < 6;
Second, assuming SURGERY_DATE is of the DATE data type syntax should go like...
... where SURGERY_DATE = TO_DATE('08/01/2012', 'mm/dd/yyyy')
This is assuming 08 represents the month and 01 represents the day on the month.
_____________________________________
Pablo (Paul) Berzukov
Author of Understanding Database Administration available at Amazon and other bookstores.
Disclaimer: Advice is provided to the best of my knowledge but no implicit or explicit warranties are provided. Since the advisor explicitly encourages testing any and all suggestions on a test non-production environment advisor should not held liable or responsible for any actions taken based on the given advice.August 21, 2012 at 6:54 am
Many thanks Mr. Berzuko:
Your expression works quite well!
My complete pass thru query looks like this:
SELECT LOG_ID, LOG_NAME, SURGERY_DATE
FROM OPENQUERY(CLARITY, 'SELECT * FROM OR_LOG WHERE SURGERY_DATE = TO_DATE(''08/01/2012'', ''mm/dd/yyyy'')') AS a
Note the addition of the doubled up single quotation marks for delimiters. (Whats the correct term for this?)
The inner derived table is a text string delimited by single quotes. AND the date expression(s) are ALSO delimited by single quotes. So the final concatenated string has doubled up single quotation marks.
THANKS for the help!
I may have more pass thru query questions.
Phunhog
August 21, 2012 at 12:05 pm
Hint: rewrite select * to the actual field names.
August 21, 2012 at 4:35 pm
Phunhog (8/21/2012)
Many thanks Mr. Berzuko:Your expression works quite well!
/ / /
Note the addition of the doubled up single quotation marks for delimiters. (Whats the correct term for this?)
Glad it worked fine Phunhog. "Delimiter(s)" is fine.
_____________________________________
Pablo (Paul) Berzukov
Author of Understanding Database Administration available at Amazon and other bookstores.
Disclaimer: Advice is provided to the best of my knowledge but no implicit or explicit warranties are provided. Since the advisor explicitly encourages testing any and all suggestions on a test non-production environment advisor should not held liable or responsible for any actions taken based on the given advice.August 27, 2012 at 10:03 am
One last question for Pablo or the oracle forum regarding dates in this SQL
SELECT LOG_ID, LOG_NAME, SURGERY_DATE
FROM OPENQUERY(CLARITY, 'SELECT * FROM OR_LOG WHERE SURGERY_DATE = TO_DATE(''08/01/2012'', ''mm/dd/yyyy'')') AS a
What is the proper expression to select yesterdays records rather than august first?
Is it WHERE SURGERY_DATE = TO_DATE((CURRENT_DATE, ''mm/dd/yyyy'')-1)
many thanks ahead of time
Phunhog
August 27, 2012 at 12:32 pm
SELECT LOG_ID, LOG_NAME, SURGERY_DATE
FROM OPENQUERY(CLARITY, 'SELECT * FROM OR_LOG WHERE SURGERY_DATE >= trunc(sysdate-1) and SURGERY_DATE <trunc(sysdate)')
Please do not use where trunc(surgery_date)=trunc(sysdate-1) unless you have a functional-index on SURGERY_DATE.
The query above will use a normal index on SURGERY_DATE if present, stats are up to date and the datadistribution is favourable.
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply