Notice: This website is an unofficial Microsoft Knowledge Base (hereinafter KB) archive and is intended to provide a reliable access to deleted content from Microsoft KB. All KB articles are owned by Microsoft Corporation. Read full disclaimer for more details.

ACC2000: Query with Time Criteria Returns No Records from Microsoft SQL Server


View products that this article applies to.

This article was previously published under Q207700
Moderate: Requires basic macro, coding, and interoperability skills.

This article applies only to a Microsoft Access database (.mdb).

↑ Back to the top


Symptoms

When you run a query based on a linked Microsoft SQL Server table that contains a Date/Time field, and the criteria for the Date/Time field contains a literal time value, Microsoft Access returns an empty recordset.

↑ Back to the top


Cause

When a linked SQL Server table contains a field with a data type of Date/Time, and you insert a time value, such as 12:35:00 PM, into the table, the following calls are made by the SQL Server ODBC driver:
   SQLPrepare:
      INSERT INTO "dbo"."tblTimeTest" VALUES (?)

   SQLBindParam:
      12:35:00
				
Microsoft SQL Server then converts the value 12:35:00 to the following:
   1899-12-30 12:35:00.00
				
When you run a query in which the Criteria row for the Time field contains a literal value such as #12:35:00 PM# against this linked table, the SQL Server ODBC driver sends the following command to the SQL Server:
   SQLExecDirect:
     SELECT "dbo"."tblTimeTest"."TimeTest" FROM "dbo"."tblTimeTest" WHERE _
         ("TimeField" = {t '12:35:00'})
				

↑ Back to the top


Resolution

Use either of the following methods to resolve this problem.

Method 1

Create a parameter query in Microsoft Access. You can use the query-by-form technique and specify a control on a form as a parameter; you can also define the parameter in the query itself and specify its data type as Date/Time. For example:
   Field: TimeField
   Criteria: [Enter Time]
				
For additional information about the query-by-form technique, please click the article number below to view the article in the Microsoft Knowledge Base:
209645 ACC2000: How to Use the Query-by-Form (QBF) Technique

Method 2

Create the following expression in the query to extract the time portion of the field:
Expr1: CVDate(Format([<Name of Time Field>],"hh:mm:ss AM/PM"))
You can then enter the literal time value enclosed in number signs (#) on the Criteria row of this expression.

↑ Back to the top


Status

Microsoft has confirmed that this is a problem in the Microsoft products that are listed at the beginning of this article.

↑ Back to the top


More information

Steps to Reproduce Problem

1.In a Microsoft SQL Server utility (such as isql/w), run the following commands:
   create table tblTimeTest (ID int, TimeField datetime)
   go
   create unique index tblTimeTest_ndx on tblTimeTest (ID)
					
2.Start Microsoft Access and create a new database.
3.On the File menu, point to Get External Data, and then click Link Tables.
4.In the Link dialog box, click ODBC Databases in the Files of type box.
5.In the Select Data Source dialog box, click the data source to connect to your SQL Server database, and then click OK. Supply any necessary logon information, and click OK.
6.In the Link Tables dialog box, select the tblTimeTest table that you created in Step 1, and then click OK.
7.View the table in Datasheet view. Add the following values to the table:
   ID   TimeField
   --  ----------
    1    12:35:00
					
8.Create a new query based on the linked SQL Server table:
   Query: qryTest
   -------------------------
   Type: Select Query

   Field: ID
      Table: dbo_tblTimeTest
   Field: TimeField
      Table: dbo_tblTimeTest
      Criteria: #12:35:00#
					
9.Close and save the qryTest query that you created in step 8.
10.Run the qryTest query. Note that Microsoft Access returns an empty recordset.

↑ Back to the top


References

For more information about specifying the data type of query parameters, click Microsoft Access Help on the Help menu, type specify the data type of a parameter in a parameter query in the Office Assistant or the Answer Wizard, and then click Search to view the topic.

↑ Back to the top


Keywords: KB207700, kbprb, kbinterop

↑ Back to the top

Article Info
Article ID : 207700
Revision : 2
Created on : 7/15/2004
Published on : 7/15/2004
Exists online : False
Views : 339