ArcGIS for Desktop

  • Documentation
  • Pricing
  • Support

  • My Profile
  • Help
  • Sign Out
ArcGIS for Desktop

ArcGIS Online

The mapping platform for your organization

ArcGIS for Desktop

A complete professional GIS

ArcGIS for Server

GIS in your enterprise

ArcGIS for Developers

Tools to build location-aware apps

ArcGIS Solutions

Free template maps and apps for your industry

ArcGIS Marketplace

Get apps and data for your organization

  • Documentation
  • Pricing
  • Support
Esri
  • Sign In
user
  • My Profile
  • Sign Out

Help

  • Home
  • Get Started
  • Map
  • Analyze
  • Manage Data
  • Tools
  • More...

Verifying the FileGroup storage for the BIS workspace in SQL Server

Ensure that the workspace was created under the correct FileGroups for proper data storage and the reduction of disk contention. Using the DBTUNE configuration that you modified previously, you can run the following script examples in SQL Server Management Studio.

Note:

Copying and pasting the examples may cause syntax errors.

Set the current database.

USE BISDB
GO

List all FileGroups and data files in a specific database.

EXEC sp_helpdb bisdb
GO

List the data files for a specific FileGroup. In this example, it will list the PRIMARY FileGroup data files.

EXEC sp_helpfilegroup 'PRIMARY'
GO

List tables by FileGroup:

SELECT USER_NAME(o.uid) [Owner],
 OBJECT_NAME(i.id) [Table Name], 
 FILEGROUP_NAME(groupid) AS [Filegroup Name]
 FROM sysindexes i inner join sysobjects o
 ON i.id = o.id
 WHERE i.indid IN (0, 1) AND OBJECTPROPERTY(i.id, 'IsMSShipped') = 0 AND
 USER_NAME(o.uid) = 'bis' 
 ORDER BY 1,3,2
GO

List indexes by table and FileGroup:

select 'owner'=user_name(o.uid) 
,'table_name'=object_name(i.id),i.indid
,'index_name'=i.name ,i.groupid
,'filegroup'=f.name ,'file_name'=d.physical_name
,'dataspace'=s.name from sys.sysindexes i
,sys.sysobjects o,sys.filegroups f 
,sys.database_files d, sys.data_spaces s
where objectproperty(i.id,'IsUserTable') = 1
and i.id = o.id
and f.data_space_id = i.groupid
and f.data_space_id = d.data_space_id
and f.data_space_id = s.data_space_id
and user_name(o.uid) = 'bis'
order by object_name(i.id),i.name,f.name
GO

If any tables or indexes are stored in the wrong FileGroup, ALTER TABLE and ALTER INDEX can be used to change the FileGroup (see SQL Server Books Online at http://msdn.microsoft.com/en-us/library/ms130214.aspx).

In SQL Server Management Studio, you can also re-create the DDL script of tables and indexes; then, within create script, you can modify the FileGroup parameter and re-create the tables and indexes in the correct FileGroups. This is particularly useful when tables are empty and you are allowed to re-create database objects.

Feedback on this topic?

ArcGIS for Desktop

  • Home
  • Documentation
  • Pricing
  • Support

ArcGIS Platform

  • ArcGIS Online
  • ArcGIS for Desktop
  • ArcGIS for Server
  • ArcGIS for Developers
  • ArcGIS Solutions
  • ArcGIS Marketplace

About Esri

  • About Us
  • Careers
  • Insiders Blog
  • User Conference
  • Developer Summit
Esri
© Copyright 2016 Environmental Systems Research Institute, Inc. | Privacy | Legal