sp_bindcache

Description

Binds a database, table, index, text object, or image object to a data cache.

Syntax

sp_bindcache cachename, dbname
	[, [ownername.]tablename
	[, indexname | "text only"]]

Parameters

cachename

is the name of an active data cache.

dbname

is the name of the database to be bound to the cache or the name of the database containing the table, index, text or image object to be bound to the cache.

ownername

is the name of the table’s owner. If the table is owned by “dbo”, the owner name is optional.

tablename

is the name of the table to be bound to the cache, or the name of the table whose index, text object, or image object is to be bound to the cache.

indexname

is the name of the index to be bound to the cache.

text only

binds text or image objects to a cache. When this parameter is used, you cannot give an index name at the same time.

Examples

Example 1

Binds the titles table to the cache named pub_cache:

sp_bindcache pub_cache, pubs2, titles

Example 2

Binds the clustered index titles.title_id_cix to the pub_ix_cache:

sp_bindcache pub_ix_cache, pubs2, titles, title_id_cix

Example 3

Binds tempdb to the tempdb_cache:

sp_bindcache tempdb_cache, tempdb

Example 4

Binds the pubs2 transaction log, syslogs, to the cache named logcache:

sp_bindcache logcache, pubs2, syslogs

Example 5

Binds the image chain for the au_pix table to the cache named pub_cache:

sp_bindcache pub_cache, pubs2, au_pix, "text only"

Usage


Restrictions

Permissions

Only a System Administrator can execute sp_bindcache.

See also

System procedures sp_cacheconfig, sp_configure, sp_help, sp_helpcache, sp_helpdb, sp_helpindex, sp_poolconfig, sp_unbindcache, sp_unbindcache_all