By using this site, you agree to our updated Privacy Policy and our Terms of Use. Manage your Cookies Settings.
435,558 Members | 2,957 Online
Bytes IT Community
+ Ask a Question
Need help? Post your question and get tips & solutions from a community of 435,558 IT Pros & Developers. It's quick & easy.

Passthrough queries and RecordsAffected

P: n/a
Bri
Greetings,

I have a Passthrough Query to SQL Server that I want to know the
RecordsAffected, but it always returns 0. This worked perfectly when it
was an Access Query on the ODBC linked tables, but the query performed
so poorly that I converted it to a Passthrough. Now it runs in a
fraction of a second, but I no longer know how many records were inserted.

Thanks for any insights or solutions

--
Bri
Nov 13 '05 #1
Share this Question
Share on Google+
7 Replies


P: n/a
On Wed, 26 Jan 2005 23:20:48 GMT, Bri <no*@here.com> wrote:
Greetings,

I have a Passthrough Query to SQL Server that I want to know the
RecordsAffected, but it always returns 0. This worked perfectly when it
was an Access Query on the ODBC linked tables, but the query performed
so poorly that I converted it to a Passthrough. Now it runs in a
fraction of a second, but I no longer know how many records were inserted.

Thanks for any insights or solutions


If you're using ADO, just have your stored procedure return the number of
records affected through an output parameter, and use the Parameters
collection of the Command object to retrieve the value. If you're useing DAO,
have your stored procedure return the count of rows affected using a select
statement, and use the OpenRecordset method of the Querydef object to retrieve
the recordset with the count contained in the first row/field.

Nov 13 '05 #2

P: n/a
Bri


Steve Jorgensen wrote:
On Wed, 26 Jan 2005 23:20:48 GMT, Bri <no*@here.com> wrote:

Greetings,

I have a Passthrough Query to SQL Server that I want to know the
RecordsAffected, but it always returns 0. This worked perfectly when it
was an Access Query on the ODBC linked tables, but the query performed
so poorly that I converted it to a Passthrough. Now it runs in a
fraction of a second, but I no longer know how many records were inserted.

Thanks for any insights or solutions

If you're using ADO, just have your stored procedure return the number of
records affected through an output parameter, and use the Parameters
collection of the Command object to retrieve the value. If you're useing DAO,
have your stored procedure return the count of rows affected using a select
statement, and use the OpenRecordset method of the Querydef object to retrieve
the recordset with the count contained in the first row/field.


Steve,

I'm using DAO.

So you're saying I need to run a second query to collect the count of
the records inserted? This doesn't seem to be as efficient as the
RecordsAffected property. So, DAO won't return any messages or things
like @@RowCount? Rats. I had hoped to not have to do it that way. :(

Bri
Nov 13 '05 #3

P: n/a
On Thu, 27 Jan 2005 00:01:50 GMT, Bri <no*@here.com> wrote:


Steve Jorgensen wrote:
On Wed, 26 Jan 2005 23:20:48 GMT, Bri <no*@here.com> wrote:

Greetings,

I have a Passthrough Query to SQL Server that I want to know the
RecordsAffected, but it always returns 0. This worked perfectly when it
was an Access Query on the ODBC linked tables, but the query performed
so poorly that I converted it to a Passthrough. Now it runs in a
fraction of a second, but I no longer know how many records were inserted.

Thanks for any insights or solutions

If you're using ADO, just have your stored procedure return the number of
records affected through an output parameter, and use the Parameters
collection of the Command object to retrieve the value. If you're useing DAO,
have your stored procedure return the count of rows affected using a select
statement, and use the OpenRecordset method of the Querydef object to retrieve
the recordset with the count contained in the first row/field.


Steve,

I'm using DAO.

So you're saying I need to run a second query to collect the count of
the records inserted? This doesn't seem to be as efficient as the
RecordsAffected property. So, DAO won't return any messages or things
like @@RowCount? Rats. I had hoped to not have to do it that way. :(

Bri


You're not running a separate query to collect the count, you're just running
a second select statement to -return- the count, so DAO can read it. It's not
that inefficient.

CREATE PROCEDURE ...

<your query here>

SELECT @@ROWCOUNT AS ROWCOUNT
Nov 13 '05 #4

P: n/a
Bri
>>Steve,

I'm using DAO.

So you're saying I need to run a second query to collect the count of
the records inserted? This doesn't seem to be as efficient as the
RecordsAffected property. So, DAO won't return any messages or things
like @@RowCount? Rats. I had hoped to not have to do it that way. :(

Bri

You're not running a separate query to collect the count, you're just running
a second select statement to -return- the count, so DAO can read it. It's not
that inefficient.

CREATE PROCEDURE ...

<your query here>

SELECT @@ROWCOUNT AS ROWCOUNT


Steve,

OK, tried that and several variations on it and it didn't work for me.

Access seems to only see the first query as the error says that there
were no records returned.

To restate things; I have a Passthrough Query with the Returns Records
Property set to No. I then run in VBA:

Dim stSQL as String, qd as DAO.QueryDef, db as DAO.Database
Set DB=CurrenttDB()
stSQL = "INSERT ...." 'my actual sql is working so I don't think it is
relevent to the problem
Set qd = db.QueryDefs("qryTempPassthroughAction")
qd.SQL = stSQL
qd.Execute dbFailOnError + dbSeeChanges
MsgBox "Signed out " & qd.RecordsAffected & " Items", vbInformation

The Message always says 'Signed out 0 Items' but all of the required
records were Inserted correctly.

Then I searched the Newsgroups and found nothing so I posted my question.

Based on your response I modified the Passthrough query (that now has
the SQL from the last succesful run) in several different versions of
the SQL, I also set the Returns Records property to Yes:

First Try
=========
INSERT ....
SELECT @@RowCount as RowCount

- Result: Error about RowCount being reserved word

Second Try
==========
INSERT ....
SELECT @@RowCount as MyRowCount

- Result: Pass-Through query with ReturnRecords property set to True did
not return any records.

Third Try
=========
CREATE PROCEDURE tmp AS
INSERT ....
SELECT @@RowCount as MyRowCount

- Result: Pass-Through query with ReturnRecords property set to True did
not return any records.

Forth Try
=========
Errors with Procedure tmp already exists

Am I missing something here? Can you give me any additional pointers?

--
Bri

Nov 13 '05 #5

P: n/a
On Thu, 27 Jan 2005 00:54:45 GMT, Bri <no*@here.com> wrote:
>>Steve,

I'm using DAO.

So you're saying I need to run a second query to collect the count of
the records inserted? This doesn't seem to be as efficient as the
RecordsAffected property. So, DAO won't return any messages or things
like @@RowCount? Rats. I had hoped to not have to do it that way. :(

Bri

You're not running a separate query to collect the count, you're just running
a second select statement to -return- the count, so DAO can read it. It's not
that inefficient.

CREATE PROCEDURE ...

<your query here>

SELECT @@ROWCOUNT AS ROWCOUNT


Steve,

OK, tried that and several variations on it and it didn't work for me.

Access seems to only see the first query as the error says that there
were no records returned.


Any stored procedure to be executed via ADO or DAO that executes more than one
statement should begin with SET NOCOUNT ON. Otherwise, all sorts of problems
occur including failing to retrieve the recordset from the final SELECT and
failing to get accurate error information in the Errors collection. Sorry - I
should have included that in my example.
Nov 13 '05 #6

P: n/a
Bri

Steve Jorgensen wrote:
On Thu, 27 Jan 2005 00:54:45 GMT, Bri <no*@here.com> wrote: <snip> Any stored procedure to be executed via ADO or DAO that executes more than one
statement should begin with SET NOCOUNT ON. Otherwise, all sorts of problems
occur including failing to retrieve the recordset from the final SELECT and
failing to get accurate error information in the Errors collection. Sorry - I
should have included that in my example.


Yahoo! That worked. I had one small thing that I'll mention for the
benefit of anyone else lurking, the Passthrough would revert to
ReturnsRecords=False when I set the SQL property, so I had to set it to
True before setting the recordset. Other than that it worked fine.

Since I am now setting a Recordset rather than Executing the query, will
I get any error messages if there is an error (ie. of the sort that
dbFailOnError gives when the Execute fails) and will an error backout
the whole batch if it is the second statement that fails?

Most of my experience with Acess to SQL has been with linked tables and
I've been dipping into Passthrough Queries (and Views and SPs) only when
I need to get better performance. The SQL Help isn't much help for this
and the SQL Server Online Books is a good reference, but not a good
learning from scratch source. Is there a website where I can learn more
about driving SQL Server from Access?

Thanks.
--
Bri

Nov 13 '05 #7

P: n/a
On Thu, 27 Jan 2005 03:00:47 GMT, Bri <no*@here.com> wrote:

Steve Jorgensen wrote:
On Thu, 27 Jan 2005 00:54:45 GMT, Bri <no*@here.com> wrote:<snip>
Any stored procedure to be executed via ADO or DAO that executes more than one
statement should begin with SET NOCOUNT ON. Otherwise, all sorts of problems
occur including failing to retrieve the recordset from the final SELECT and
failing to get accurate error information in the Errors collection. Sorry - I
should have included that in my example.


Yahoo! That worked. I had one small thing that I'll mention for the
benefit of anyone else lurking, the Passthrough would revert to
ReturnsRecords=False when I set the SQL property, so I had to set it to
True before setting the recordset. Other than that it worked fine.

Since I am now setting a Recordset rather than Executing the query, will
I get any error messages if there is an error (ie. of the sort that
dbFailOnError gives when the Execute fails) and will an error backout
the whole batch if it is the second statement that fails?


Yes, you will get the error. Rollback is controlled by the SQL Server logic,
not Access. In general, the statement within the stored procedure that had
the error will be rolled back automatically, but not any preceding statements.
You'll have to include BEGIN TRANSACTION and COMMIT TRANSACTION statements,
and error trapping with ROLLBACK TRANSACTION and RETURN if you want full,
multi-statment roll-back. Note that in T-SQL, there's nothing like ON ERROR
GOTO, so unfortunately, you need several lines of error handling code after
each logical statement.

Most of my experience with Acess to SQL has been with linked tables and
I've been dipping into Passthrough Queries (and Views and SPs) only when
I need to get better performance. The SQL Help isn't much help for this
and the SQL Server Online Books is a good reference, but not a good
learning from scratch source. Is there a website where I can learn more
about driving SQL Server from Access?

Thanks.


Nov 13 '05 #8

This discussion thread is closed

Replies have been disabled for this discussion.