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


user tables in database where the number of rows is less than 100


user tables in database where the number of rows is less than 100

Author
Message
MichaelJasson
MichaelJasson
Say Hey Kid
Say Hey Kid (698 reputation)Say Hey Kid (698 reputation)Say Hey Kid (698 reputation)Say Hey Kid (698 reputation)Say Hey Kid (698 reputation)Say Hey Kid (698 reputation)Say Hey Kid (698 reputation)Say Hey Kid (698 reputation)

Group: General Forum Members
Points: 698 Visits: 191
Hello Team,

I am trying to find out the name of the user tables in my database where the number of rows is less than 100. I am using following command to find this.

I am not good at writing queries. Can you guide me how to become proficient in writing good sql queries. Query as follows can give you a glimplse as how bad I am in writing the sql queries.

select n.name, n.count(1)
(
select count(1) from name
)
from sysobjects n where xtype = 'u'
and n.count(1) < 100

Regards,
Michael

-MJ
Please do not print mails and docx unless it is absolutely necessary. Spread environmental awareness.
Michael Earl-395764
Michael Earl-395764
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13781 Visits: 23078
For a quick solution, you can check the row count of the indexes on the tables rather than counting the actual rows.

SELECT
SO.Name
, SI.RowCnt
FROM
SysObjects SO
LEFT JOIN SysIndexes SI ON SO.ID = SI.ID AND SI.IndID = 1
WHERE
SO.Type = 'u'
AND (SI.RowCnt IS NULL OR SI.RowCnt < 100)


This will return the tables with less than 100 rows and any tables without any indexes will have a rowcount of NULL.
happycat59
happycat59
SSCrazy Eights
SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)SSCrazy Eights (8.9K reputation)

Group: General Forum Members
Points: 8941 Visits: 3281
A more accurate query is...
SELECT
SO.Name
, SI.RowCnt
FROM
SysObjects SO
INNER JOIN SysIndexes SI ON SO.ID = SI.ID
WHERE
SO.Type = 'u'
AND (SI.RowCnt IS NULL OR SI.RowCnt < 100) -- nto 100% sure but I think rowcnt will never be null
and SI.IndID IN (0, 1)

A table will only have one record in SYSINDEXES with a value of either 0 or 1. This simply depends on whether (or not) the table has a clustered index.



Michael Earl-395764
Michael Earl-395764
SSChampion
SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)SSChampion (13K reputation)

Group: General Forum Members
Points: 13781 Visits: 23078
happycat - you would need to move your additional criteria into the join.

SELECT
SO.Name
, SI.RowCnt
FROM
SysObjects SO
INNER JOIN SysIndexes SI ON SO.ID = SI.ID and SI.IndID IN (0, 1)
WHERE
SO.Type = 'u'
AND (SI.RowCnt IS NULL OR SI.RowCnt < 100) -- nto 100% sure but I think rowcnt will never be null


The NULL condition is to handle tables with no indexes. I wanted to make sure the query did not ignore heaps, so it returns rows with no sysindexes entries.
Abhijit More
Abhijit More
SSCrazy
SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)SSCrazy (2K reputation)

Group: General Forum Members
Points: 2013 Visits: 767
select distinct object_name(object_id) as Table, rows
from sys.partitions where index_id >= 1
and object_name(object_id) not like 'sys%'
and rows > 100

Abhijit - http://abhijitmore.wordpress.com
GilaMonster
GilaMonster
SSC Guru
SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)

Group: General Forum Members
Points: 233671 Visits: 46361
Abhijit More (1/13/2009)
select distinct object_name(object_id) as Table, rows
from sys.partitions where index_id >= 1
and object_name(object_id) not like 'sys%'
and rows > 100


Msg 156, Level 15, State 1, Line 1
Incorrect syntax near the keyword 'Table'.

Also, yours would miss tables that had no indexes at all, count system tables whos names don't start with sys (service broker queues as an example) and miss user tables that do start with sys

select object_name(object_id) as TableName, rows
from sys.partitions
where index_id in (0,1) -- heap or clustered index. No point in counting the nonclusters
and OBJECTPROPERTY(object_id, 'IsMSShipped')=0 -- Don't want any system tables, do want user tables that may start with sys
and rows < 100



Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


MichaelJasson
MichaelJasson
Say Hey Kid
Say Hey Kid (698 reputation)Say Hey Kid (698 reputation)Say Hey Kid (698 reputation)Say Hey Kid (698 reputation)Say Hey Kid (698 reputation)Say Hey Kid (698 reputation)Say Hey Kid (698 reputation)Say Hey Kid (698 reputation)

Group: General Forum Members
Points: 698 Visits: 191
Thanks so much. Somehow I am not able to run the command. I am sure that you would have got the correct result of your respective queries ...

Msg 208, Level 16, State 1, Line 1
Invalid object name 'sys.partitions'.

select @@version:
Microsoft SQL Server 2000 - 8.00.2050 (Intel X86) Mar 7 2008 21:29:56 Copyright (c) 1988-2003 Microsoft Corporation Enterprise Edition on Windows NT 5.2 (Build 3790: Service Pack 1)

select * from sysobjects where name like '%partition%' --> No row is selected

Your query is good for 2005 but what should I do for 2000 Sad

-M

-MJ
Please do not print mails and docx unless it is absolutely necessary. Spread environmental awareness.
GilaMonster
GilaMonster
SSC Guru
SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)SSC Guru (233K reputation)

Group: General Forum Members
Points: 233671 Visits: 46361
Please post SQL 2000-related questions in the SQL 2000 forums. If you post in the 2005 forums, you're very likely to get 2005-specific solutions. All this does is waste everyone's time.

For SQL 2000, use sysindexes. I'm not writing the entire query for you. The idea is the same as with sys.partitions, the column names differ.

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


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