Monitor memory usage on User database level

  • Hi,

    We have many MS-SQLServer 2005 instances (32 bit & 64 bit) running on many Microsoft Windows systems (32 bit & 64 bit).

    Our management has decided to centralize all SQLServer instances on a Microsoft Windows Cluster 2003 R2 (64 bit) and one or two Microsoft Windows 2003 R2 (64 bit) standalone servers.

    Question:

    - Is it possible to have a clue on the memory usage per user database? Via Windows Task Manager, I can see the consumption of the SQLServer instance, but my instance contains for example 15 user databases.

    - Is it true that I can have not more then 5 instances per Windows Server?

    Thanks in advance,

    Geert

  • Hi Geert,

    Great questions!

    You can use the DMV sys.dm_os_buffer_descriptors to find out how much of the "buffer pool" memory is being used by a given database. You can use the following query in order to get you started.

    SELECT

    (CASE WHEN ([is_modified] = 1) THEN 'Dirty' ELSE 'Clean' END) AS 'Page State',

    (CASE WHEN ([database_id] = 32767) THEN 'Resource Database' ELSE DB_NAME (database_id) END) AS 'Database Name',

    COUNT (*) AS 'Page Count'

    FROM sys.dm_os_buffer_descriptors

    GROUP BY [database_id], [is_modified]

    ORDER BY [database_id], [is_modified];

    GO

    With regard to your second question, according to the SQL Server 2005 Maximum Capacity Specifications you can have up to 50 instances on all Editions excluding Workgroup Edition, which supports up to 16 instances. You should also note that SQL Server 2005 only supports up to 25 instances on a failover cluster.

    Hope this helps.

  • Thanks for the excellent reply John.

    How do I need to interpret the output?

    Page State Database Name Page Count

    Clean SUSDB 4849

    Dirty SUSDB 593

    What is the meaning of Clean/Dirty in this context?

    And how much memory do I need to foresee when I move this database to another SQL Server instance?

    Thanks in advance,

    Geert

  • Hi Geert,

    Each page in SQL Server is 8KB in size.

    Essentially, a dirty page is an in memory page that has had changes applied to it that are pending being written out (flushed) to disk.

    For further reading consult SQL Server Books Online: Pages and Extents

  • Thanks John.

    Have a nice day.

    Geert

  • You're welcome, glad to help.

  • I ran the T-SQL - very nice - I multiply the pages by 8 (for 8Kb) and then divide by 1024 for MBs

    When I then total the MBs I get ~3.5 GB. When I look in the resource monitor the sqlserv.exe is taking up ~7GB.

    Am I miscalculating or should i take some other things into consideration?

    Rgds,

    Nico

Viewing 7 posts - 1 through 6 (of 6 total)

You must be logged in to reply to this topic. Login to reply