SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


How to get the number of rows from a table reside in a linked server as fast as possible.


How to get the number of rows from a table reside in a linked server as fast as possible.

Author
Message
abhishek.sahoo
abhishek.sahoo
SSC-Enthusiastic
SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)

Group: General Forum Members
Points: 167 Visits: 37
We have table reside in a linked server having more than 15 million data. Please provide me a T -SQL which can retrieve the number of rows as fast as possible (the query should fetch count from a linked server).
krayknot
krayknot
SSCommitted
SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)

Group: General Forum Members
Points: 1822 Visits: 534
abhishek.sahoo (1/20/2009)
We have table reside in a linked server having more than 15 million data. Please provide me a T -SQL which can retrieve the number of rows as fast as possible (the query should fetch count from a linked server).


select Count(*) From count([link server address]. )

kshitij kumar
kshitij@krayknot.com
www.krayknot.com
abhishek.sahoo
abhishek.sahoo
SSC-Enthusiastic
SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)

Group: General Forum Members
Points: 167 Visits: 37
No, I expect something that can retrieve data faster. Your one will take a longer time to execute if the record count is more than 15 million.
steveb.
steveb.
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10218 Visits: 7195
This method should be faster


SELECT rows FROM sysindexes
WHERE id = OBJECT_ID('YourTableName') AND indid < 2


krayknot
krayknot
SSCommitted
SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)SSCommitted (1.8K reputation)

Group: General Forum Members
Points: 1822 Visits: 534
steveb (1/20/2009)
This method should be faster


SELECT rows FROM sysindexes
WHERE id = OBJECT_ID('YourTableName') AND indid < 2



Here the local sql server's object id will need to apply. but if you will run the same command on the linked server. again the speed isssue will arise especially for such large data

kshitij kumar
kshitij@krayknot.com
www.krayknot.com
abhishek.sahoo
abhishek.sahoo
SSC-Enthusiastic
SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)

Group: General Forum Members
Points: 167 Visits: 37
I am not sure whether we can use sys index to retrieve data from a linked server. The T-SQL you have provided works fine if the table is in same server. What if the table resides in a linked server.
steveb.
steveb.
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10218 Visits: 7195
abhishek.sahoo (1/20/2009)
I am not sure whether we can use sys index to retrieve data from a linked server. The T-SQL you have provided works fine if the table is in same server. What if the table resides in a linked server.


I would run the code on the linked server, if possible..
Ramesh Saive
Ramesh Saive
SSCertifiable
SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)SSCertifiable (6.6K reputation)

Group: General Forum Members
Points: 6554 Visits: 2643
Or you could do something like....


SELECT i.rows
FROM [linkedserver].[linkeddb].dbo.sysindexes i
INNER JOIN [linkedserver].[linkeddb].dbo.sysobjects o ON i.id = o.id
WHERE o.name = 'HereGoesTheTable'
AND i.indid < 2



--Ramesh


abhishek.sahoo
abhishek.sahoo
SSC-Enthusiastic
SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)SSC-Enthusiastic (167 reputation)

Group: General Forum Members
Points: 167 Visits: 37
Its working and the result is coming with in seconds. Thanks a lot Ramesh! Thanks All!!
Jacob Luebbers
Jacob Luebbers
Ten Centuries
Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)Ten Centuries (1.3K reputation)

Group: General Forum Members
Points: 1346 Visits: 1215
Two things:

1) Using sysindexes.rows (or any approach based on metadata from the system tables) is not guaranteed to give an accurate value. If you just need an approximate answer as quickly as possible great, otherwise use COUNT().

2) Be careful with your ON and WHERE clauses across a linked server boundary - in Ramesh's example there's a varchar-based WHERE condition, and unless you've got your collation settings matched up correctly between local and remote servers you can end up with the remote table being pulled across to the local server before the conditions are resolved. It's much better to encapsulate your linked server logic into a stored proc on the remote server so that all of its conditions are resolved on that server, and simply EXEC it from the local server. The resulting data can be either INSERT... EXECed into a local table or passed back with OUTPUT params.

Regards,

Jacob
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search