TechNet
Export (0) Print
Expand All

OBJECTPROPERTYEX (Transact-SQL)

 

THIS TOPIC APPLIES TO: yesSQL Server (starting with 2008)yesAzure SQL DatabaseyesAzure SQL Data Warehouse yesParallel Data Warehouse

Returns information about schema-scoped objects in the current database. For a list of these objects, see sys.objects (Transact-SQL). OBJECTPROPERTYEX cannot be used for objects that are not schema-scoped, such as data definition language (DDL) triggers and event notifications.

Topic link icon Transact-SQL Syntax Conventions

  
OBJECTPROPERTYEX ( id , property )  

-- Azure SQL Data Warehouse and Parallel Data Warehouse  
OBJECTPROPERTYEX ( id , property )  

id
Is an expression that represents the ID of the object in the current database. id is int and is assumed to be a schema-scoped object in the current database context.

property
Is an expression that contains the information to be returned for the object specified by id. The return type is sql_variant. The following table shows the base data type for each property value.

System_CAPS_ICON_note.jpg Note


Unless noted otherwise, NULL is returned when property is not a valid property name, id is not a valid object ID, id is an unsupported object type for the specified property, or the caller does not have permission to view the object's metadata.

Property nameObject typeDescription and values returned
BaseTypeAny schema-scoped objectIdentifies the base type of the object. When the specified object is a SYNONYM, the base type of the underlying object is returned.

Nonnull = Object type

Base data type: char(2)
CnstIsClustKeyConstraintPRIMARY KEY constraint with a clustered index.

1 = True

0 = False

Base data type: int
CnstIsColumnConstraintCHECK, DEFAULT, or FOREIGN KEY constraint on a single column.

1 = True

0 = False

Base data type: int
CnstIsDeleteCascadeConstraintFOREIGN KEY constraint with the ON DELETE CASCADE option.

1 = True

0 = False

Base data type: int
CnstIsDisabledConstraintDisabled constraint.

1 = True

0 = False

Base data type: int
CnstIsNonclustKeyConstraintPRIMARY KEY constraint with a nonclustered index.

1 = True

0 = False

Base data type: int
CnstIsNotReplConstraintConstraint is defined by using the NOT FOR REPLICATION keywords.

1 = True

0 = False

Base data type: int
CnstIsNotTrustedConstraintConstraint was enabled without checking existing rows. Therefore, the constraint may not hold for all rows.

1 = True

0 = False

Base data type: int
CnstIsUpdateCascadeConstraintFOREIGN KEY constraint with the ON UPDATE CASCADE option.

1 = True

0 = False

Base data type: int
ExecIsAfterTriggerTriggerAFTER trigger.

1 = True

0 = False

Base data type: int
ExecIsAnsiNullsOnTransact-SQL function, Transact-SQL procedure, Transact-SQL trigger, viewThe setting of ANSI_NULLS at creation time.

1 = True

0 = False

Base data type: int
ExecIsDeleteTriggerTriggerDELETE trigger.

1 = True

0 = False

Base data type: int
ExecIsFirstDeleteTriggerTriggerThe first trigger fired when a DELETE is executed against the table.

1 = True

0 = False

Base data type: int
ExecIsFirstInsertTriggerTriggerThe first trigger fired when an INSERT is executed against the table.

1 = True

0 = False

Base data type: int
ExecIsFirstUpdateTriggerTriggerThe first trigger fired when an UPDATE is executed against the table.

1 = True

0 = False

Base data type: int
ExecIsInsertTriggerTriggerINSERT trigger.

1 = True

0 = False

Base data type: int
ExecIsInsteadOfTriggerTriggerINSTEAD OF trigger.

1 = True

0 = False

Base data type: int
ExecIsLastDeleteTriggerTriggerLast trigger fired when a DELETE is executed against the table.

1 = True

0 = False

Base data type: int
ExecIsLastInsertTriggerTriggerLast trigger fired when an INSERT is executed against the table.

1 = True

0 = False

Base data type: int
ExecIsLastUpdateTriggerTriggerLast trigger fired when an UPDATE is executed against the table.

1 = True

0 = False

Base data type: int
ExecIsQuotedIdentOnTransact-SQL function, Transact-SQL procedure, Transact-SQL trigger, viewSetting of QUOTED_IDENTIFIER at creation time.

1 = True

0 = False

Base data type: int
ExecIsStartupProcedureStartup procedure.

1 = True

0 = False

Base data type: int
ExecIsTriggerDisabledTriggerDisabled trigger.

1 = True

0 = False

Base data type: int
ExecIsTriggerNotForReplTriggerTrigger defined as NOT FOR REPLICATION.

1 = True

0 = False

Base data type: int
ExecIsUpdateTriggerTriggerUPDATE trigger.

1 = True

0 = False

Base data type: int
ExecIsWithNativeCompilationTransact-SQL ProcedureApplies to: SQL Server 2014 through SQL Server 2016.

Procedure is natively compiled.

1 = True

0 = False

Base data type: int
HasAfterTriggerTable, viewTable or view has an AFTER trigger.

1 = True

0 = False

Base data type: int
HasDeleteTriggerTable, viewTable or view has a DELETE trigger.

1 = True

0 = False

Base data type: int
HasInsertTriggerTable, viewTable or view has an INSERT trigger.

1 = True

0 = False

Base data type: int
HasInsteadOfTriggerTable, viewTable or view has an INSTEAD OF trigger.

1 = True

0 = False

Base data type: int
HasUpdateTriggerTable, viewTable or view has an UPDATE trigger.

1 = True

0 = False

Base data type: int
IsAnsiNullsOnTransact-SQL function, Transact-SQL procedure, table, Transact-SQL trigger, viewSpecifies that the ANSI NULLS option setting for the table is ON, meaning all comparisons against a null value evaluate to UNKNOWN. This setting applies to all expressions in the table definition, including computed columns and constraints, for as long as the table exists.

1 = True

0 = False

Base data type: int
IsCheckCnstAny schema-scoped objectCHECK constraint.

1 = True

0 = False

Base data type: int
IsConstraintAny schema-scoped objectConstraint.

1 = True

0 = False

Base data type: int
IsDefaultAny schema-scoped objectApplies to: SQL Server 2008 through SQL Server 2016.

Bound default.

1 = True

0 = False

Base data type: int
IsDefaultCnstAny schema-scoped objectDEFAULT constraint.

1 = True

0 = False

Base data type: int
IsDeterministicScalar and table-valued functions, viewThe determinism property of the function or view.

1 = Deterministic

0 = Not Deterministic

Base data type: int
IsEncryptedTransact-SQL function, Transact-SQL procedure, table, Transact-SQL trigger, viewIndicates that the original text of the module statement was converted to an obfuscated format. The output of the obfuscation is not directly visible in any of the catalog views in SQL Server 2005. Users without access to system tables or database files cannot retrieve the obfuscated text. However, the text is available to users that can either access system tables over the DAC port or directly access database files. Also, users that can attach a debugger to the server process can retrieve the original procedure from memory at run time.

1 = Encrypted

0 = Not encrypted

Base data type: int
IsExecutedAny schema-scoped objectSpecifies the object can be executed (view, procedure, function, or trigger).

1 = True

0 = False

Base data type: int
IsExtendedProcAny schema-scoped objectExtended procedure.

1 = True

0 = False

Base data type: int
IsForeignKeyAny schema-scoped objectFOREIGN KEY constraint.

1 = True

0 = False

Base data type: int
IsIndexedTable, viewA table or view with an index.

1 = True

0 = False

Base data type: int
IsIndexableTable, viewA table or view on which an index may be created.

1 = True

0 = False

Base data type: int
IsInlineFunctionFunctionInline function.

1 = Inline function

0 = Not inline function

Base data type: int
IsMSShippedAny schema-scoped objectAn object created during installation of SQL Server.

1 = True

0 = False

Base data type: int
IsPreciseComputed column, function, user-defined type, viewIndicates whether the object contains an imprecise computation, such as floating point operations.

1 = Precise

0 = Imprecise

Base data type: int
IsPrimaryKeyAny schema-scoped objectPRIMARY KEY constraint.

1 = True

0 = False

Base data type: int
IsProcedureAny schema-scoped objectProcedure.

1 = True

0 = False

Base data type: int
IsQuotedIdentOnCHECK constraint, DEFAULT definition, Transact-SQL function, Transact-SQL procedure, table, Transact-SQL trigger, viewSpecifies that the quoted identifier setting for the object is ON, meaning double quotation marks delimit identifiers in all expressions involved in the object definition.

1 = True

0 = False

Base data type: int
IsQueueAny schema-scoped objectService Broker Queue

1 = True

0 = False

Base data type: int
IsReplProcAny schema-scoped objectReplication procedure.

1 = True

0 = False

Base data type: int
IsRuleAny schema-scoped objectBound rule.

1 = True

0 = False

Base data type: int
IsScalarFunctionFunctionScalar-valued function.

1 = Scalar-valued function

0 = Not scalar-valued function

Base data type: int
IsSchemaBoundFunction, Procedure, viewA schema bound function or view created by using SCHEMABINDING.

1 = Schema-bound

0 = Not schema-bound

Base data type: int
IsSystemTableTableSystem table.

1 = True

0 = False

Base data type: int
IsSystemVerifiedComputed column, function, user-defined type, viewThe precision and determinism properties of the object can be verified by SQL Server.

1 = True

0 = False

Base data type: int
IsTableTableTable.

1 = True

0 = False

Base data type: int
IsTableFunctionFunctionTable-valued function.

1 = Table-valued function

0 = Not table-valued function

Base data type: int
IsTriggerAny schema-scoped objectTrigger.

1 = True

0 = False

Base data type: int
IsUniqueCnstAny schema-scoped objectUNIQUE constraint.

1 = True

0 = False

Base data type: int
IsUserTableTableUser-defined table.

1 = True

0 = False

Base data type: int
IsViewViewView.

1 = True

0 = False

Base data type: int
OwnerIdAny schema-scoped objectOwner of the object.

 Note: The schema owner is not necessarily the object owner. For example, child objects (those where parent_object_id is nonnull) will always return the same owner ID as the parent.

Nonnull = Database user ID of the object owner.

NULL = Unsupported object type, or object ID is not valid.

Base data type: int
SchemaIdAny schema-scoped objectThe ID of the schema associated with the object.

Nonnull = Schema ID of the object.

Base data type: int
SystemDataAccessFunction, viewObject accesses system data, system catalogs or virtual system tables, in the local instance of SQL Server.

0 = None

1 = Read

Base data type: int
TableDeleteTriggerTableTable has a DELETE trigger.

>1 = ID of first trigger with the specified type.

Base data type: int
TableDeleteTriggerCountTableThe table has the specified number of DELETE triggers.

Nonnull = Number of DELETE triggers

Base data type: int
TableFullTextMergeStatusTableApplies to: SQL Server 2008 through SQL Server 2016.

Whether a table that has a full-text index that is currently in merging.

0 = Table does not have a full-text index, or the full-text index is not in merging.

1 = The full-text index is in merging.
TableFullTextBackgroundUpdateIndexOnTableApplies to: SQL Server 2008 through SQL Server 2016.

The table has full-text background update index (autochange tracking) enabled.

1 = TRUE

0 = FALSE

Base data type: int
TableFulltextCatalogIdTableApplies to: SQL Server 2008 through SQL Server 2016.

ID of the full-text catalog in which the full-text index data for the table resides.

Nonzero = Full-text catalog ID, associated with the unique index that identifies the rows in a full-text indexed table.

0 = Table does not have a full-text index.

Base data type: int
TableFullTextChangeTrackingOnTableApplies to: SQL Server 2008 through SQL Server 2016.

Table has full-text change-tracking enabled.

1 = TRUE

0 = FALSE

Base data type: int
TableFulltextDocsProcessedTableApplies to: SQL Server 2008 through SQL Server 2016.

Number of rows processed since the start of full-text indexing. In a table that is being indexed for full-text search, all the columns of one row are considered as part of one document to be indexed.

0 = No active crawl or full-text indexing is completed.

> 0 = One of the following (A or B): A) The number of documents processed by insert or update operations since the start of full, incremental, or manual change tracking population; B) The number of rows processed by insert or update operations since change tracking with background update index population was enabled, the full-text index schema changed, the full-text catalog rebuilt, or the instance of SQL Server restarted, and so on.

NULL = Table does not have a full-text index.

Base data type: int

 Note This property does not monitor or count deleted rows.
TableFulltextFailCountTableApplies to: SQL Server 2008 through SQL Server 2016.

The number of rows that full-text search did not index.

0 = The population has completed.

>0 = One of the following (A or B): A) The number of documents that were not indexed since the start of Full, Incremental, and Manual Update change tracking population; B) For change tracking with background update index, the number of rows that were not indexed since the start of the population, or the restart of the population. This could be caused by a schema change, rebuild of the catalog, server restart, and so on

NULL = Table does not have a Full-Text index.

Base data type: int
TableFulltextItemCountTableApplies to: SQL Server 2008 through SQL Server 2016.

Nonnull = Number of rows that were full-text indexed successfully.

NULL = Table does not have a full-text index.

Base data type: int
TableFulltextKeyColumnTableApplies to: SQL Server 2008 through SQL Server 2016.

ID of the column associated with the single-column unique index that is part of the definition of a full-text index and semantic index.

0 = Table does not have a full-text index.

Base data type: int
TableFulltextPendingChangesTableApplies to: SQL Server 2008 through SQL Server 2016.

Number of pending change tracking entries to process.

0 = change tracking is not enabled.

NULL = Table does not have a full-text index.

Base data type: int
TableFulltextPopulateStatusTableApplies to: SQL Server 2008 through SQL Server 2016.

0 = Idle.

1 = Full population is in progress.

2 = Incremental population is in progress.

3 = Propagation of tracked changes is in progress.

4 = Background update index is in progress, such as autochange tracking.

5 = Full-text indexing is throttled or paused.

6 = An error has occurred. Examine the crawl log for details. For more information, see the Troubleshooting Errors in a Full-Text Population (Crawl) section of Populate Full-Text Indexes.

Base data type: int
TableFullTextSemanticExtractionTableApplies to: SQL Server 2012 through SQL Server 2016.

Table is enabled for semantic indexing.

1 = True

0 = False

Base data type: int
TableHasActiveFulltextIndexTableApplies to: SQL Server 2008 through SQL Server 2016.

Table has an active full-text index.

1 = True

0 = False

Base data type: int
TableHasCheckCnstTableTable has a CHECK constraint.

1 = True

0 = False

Base data type: int
TableHasClustIndexTableTable has a clustered index.

1 = True

0 = False

Base data type: int
TableHasDefaultCnstTableTable has a DEFAULT constraint.

1 = True

0 = False

Base data type: int
TableHasDeleteTriggerTableTable has a DELETE trigger.

1 = True

0 = False

Base data type: int
TableHasForeignKeyTableTable has a FOREIGN KEY constraint.

1 = True

0 = False

Base data type: int
TableHasForeignRefTableTable is referenced by a FOREIGN KEY constraint.

1 = True

0 = False

Base data type: int
TableHasIdentityTableTable has an identity column.

1 = True

0 = False

Base data type: int
TableHasIndexTableTable has an index of any type.

1 = True

0 = False

Base data type: int
TableHasInsertTriggerTableObject has an INSERT trigger.

1 = True

0 = False

Base data type: int
TableHasNonclustIndexTableThe table has a nonclustered index.

1 = True

0 = False

Base data type: int
TableHasPrimaryKeyTableTable has a primary key.

1 = True

0 = False

Base data type: int
TableHasRowGuidColTableTable has a ROWGUIDCOL for a uniqueidentifier column.

1 = True

0 = False

Base data type: int
TableHasTextImageTableTable has a text, ntext, or image column.

1 = True

0 = False

Base data type: int
TableHasTimestampTableTable has a timestamp column.

1 = True

0 = False

Base data type: int
TableHasUniqueCnstTableTable has a UNIQUE constraint.

1 = True

0 = False

Base data type: int
TableHasUpdateTriggerTableThe object has an UPDATE trigger.

1 = True

0 = False

Base data type: int
TableHasVarDecimalStorageFormatTableTable is enabled for vardecimal storage format.

1 = True

0 = False
TableInsertTriggerTableTable has an INSERT trigger.

>1 = ID of first trigger with the specified type.

Base data type: int
TableInsertTriggerCountTableThe table has the specified number of INSERT triggers.

>0 = The number of INSERT triggers.

Base data type: int
TableIsFakeTableTable is not real. It is materialized internally on demand by the Database Engine.

1 = True

0 = False

Base data type: int
TableIsLockedOnBulkLoadTableTable is locked because a bcp or BULK INSERT job.

1 = True

0 = False

Base data type: int
TableIsMemoryOptimizedTableApplies to: SQL Server 2014 through SQL Server 2016.

Table is memory optimized

1 = True

0 = False

Base data type: int

For more information, see In-Memory OLTP (In-Memory Optimization).
TableIsPinnedTableTable is pinned to be held in the data cache.

0 = False

This feature is not supported in SQL Server 2005 and later versions.
TableTextInRowLimitTableTable has text in row option set.

> 0 = Maximum bytes allowed for text in row.

0 = text in row option is not set.

Base data type: int
TableUpdateTriggerTableTable has an UPDATE trigger.

> 1 = ID of first trigger with the specified type.

Base data type: int
TableUpdateTriggerCountTableTable has the specified number of UPDATE triggers.

> 0 = The number of UPDATE triggers.

Base data type: int
UserDataAccessFunction, ViewIndicates the object accesses user data, user tables, in the local instance of SQL Server.

1 = Read

0 = None

Base data type: int
TableHasColumnSetTableTable has a column set.

0 = False

1 = True

For more information, see Use Column Sets.
CardinalityTable (system or user-defined), view, or indexApplies to: SQL Server 2012 through SQL Server 2016.

The number of rows in the specified object.
TableTemporalTypeTableApplies to: SQL Server 2016 through SQL Server 2016.

Specifies the type of table.

0 = non-temporal table

1 = history table for system-versioned table

2 = system-versioned temporal table

sql_variant

Returns NULL on error or if a caller does not have permission to view the object.

A user can only view the metadata of securables that the user owns or on which the user has been granted permission. This means that metadata-emitting, built-in functions such as OBJECTPROPERTYEX may return NULL if the user does not have any permission on the object. For more information, see Metadata Visibility Configuration.

The Database Engine assumes that object_id is in the current database context. A query that references an object_id in another database will return NULL or incorrect results. For example, in the following query the current database context is the master database. The Database Engine will try to return the property value for the specified object_id in that database instead of the database that is specified in the query. The query returns incorrect results because the view vEmployee is not in the master database.

USE master;  
GO  
SELECT OBJECTPROPERTYEX(OBJECT_ID(N'AdventureWorks2012.HumanResources.vEmployee'), 'IsView');  
GO  

OBJECTPROPERTYEX(view_id, 'IsIndexable') may consume significant computer resources because evaluation of IsIndexable property requires the parsing of view definition, normalization, and partial optimization. Although the IsIndexable property identifies tables or views that can be indexed, the actual creation of the index still might fail if certain index key requirements are not met. For more information, see CREATE INDEX (Transact-SQL).

OBJECTPROPERTYEX (table_id, 'TableHasActiveFulltextIndex') will return a value of 1 (true) when at least one column of a table is added for indexing. Full-text indexing becomes active for population as soon as the first column is added for indexing.

Restrictions on metadata visibility are applied to the result set. For more information, see Metadata Visibility Configuration.

A. Finding the base type of an object

The following example creates a SYNONYM MyEmployeeTable for the Employee table in the AdventureWorks2012 database and then returns the base type of the SYNONYM.

USE AdventureWorks2012;  
GO  
CREATE SYNONYM MyEmployeeTable FOR HumanResources.Employee;  
GO  
SELECT OBJECTPROPERTYEX ( object_id(N'MyEmployeeTable'), N'BaseType')AS [Base Type];  
GO  

The result set shows that the base type of the underlying object, the Employee table, is a user table.

Base Type

--------

U

B. Returning a property value

The following example returns the number of UPDATE triggers on the specified table.

USE AdventureWorks2012;  
GO  
SELECT OBJECTPROPERTYEX(OBJECT_ID(N'HumanResources.Employee'), N'TABLEUPDATETRIGGERCOUNT');  
GO  
  

C. Finding tables that have a FOREIGN KEY constraint

The following example uses the TableHasForeignKey property to return all the tables that have a FOREIGN KEY constraint.

USE AdventureWorks2012;  
GO  
SELECT name, object_id, schema_id, type_desc  
FROM sys.objects   
WHERE OBJECTPROPERTYEX(object_id, N'TableHasForeignKey') = 1  
ORDER BY name;  
GO  
  

D: Finding the base type of an object

The following example returns the base type of dbo.DimReseller object.

-- Uses AdventureWorks  
  
SELECT OBJECTPROPERTYEX ( object_id(N'dbo.DimReseller'), N'BaseType')AS BaseType;  

The result set shows that the base type of the underlying object, the dbo.DimReseller table, is a user table.

BaseType   
--------   
U   

CREATE SYNONYM (Transact-SQL)
Metadata Functions (Transact-SQL)
OBJECT_DEFINITION (Transact-SQL)
OBJECT_ID (Transact-SQL)
OBJECT_NAME (Transact-SQL)
sys.objects (Transact-SQL)
ALTER AUTHORIZATION (Transact-SQL)
TYPEPROPERTY (Transact-SQL)

Community Additions

ADD
Show:
© 2016 Microsoft