示例:使用 SQL 查找属性域使用情况
关系查询介绍了如何使用 GDB_ItemRelationships 表文件查找那些使用特定的属性域进行验证的要素类和表。不过,您也可能需要查找更多详细信息,比如属性域要应用到的字段以及哪个子类型使用此属性域(如果子类型存在)。以下步骤概述了查找这些信息的一种方法:
- 将与特定属性域关联的所有项的名称和定义插入临时记录集。
- 提取所有在类级别上使用属性域的项目的字段名称 (/*/GPFieldInfoExs/GPFieldInfoEx/DomainName)。
- 提取所有在类级别上使用属性域的项目的字段和子类型名称 (/*/Subtypes/Subtype/FieldInfos/SubtypeFieldInfo/DomainName)。
- 将这两个结果集进行合并。
以下示例演示了在 SQL Server 的地理数据库中查询名为 Material 的属性域。
--Queries an sde-schema geodatabase in SQL Server DECLARE @DOMAIN_NAME NVARCHAR(MAX); SET @DOMAIN_NAME = 'Material'; DECLARE @CLASS_DEFS TABLE ( Name nvarchar(max), Definition XML ) --Insert records to temporary record set INSERT INTO @CLASS_DEFS SELECT sde.gdb_items.Name, sde.gdb_items.Definition FROM -- Get the domain item's UUID. ((SELECT GDB_ITEMS.UUID AS UUID FROM sde.gdb_items INNER JOIN sde.gdb_itemtypes ON sde.gdb_items.Type = sde.gdb_itemtypes.UUID WHERE sde.gdb_items.Name = @DOMAIN_NAME AND sde.gdb_itemtypes.Name IN ('Coded Value Domain','Range Domain')) AS Domain -- Find the relationships with the domain as the DestinationID. INNER JOIN sde.gdb_itemrelationships ON Domain.UUID = sde.gdb_itemrelationships.DestID) -- Find the names of the origin items in the relationships. INNER JOIN sde.gdb_items ON Domain.UUID = sde.gdb_itemrelationships.DestID -- Extract the field definitions. SELECT ClassDefs.Name AS "Class Name", fieldDef.value('Name[1]', 'nvarchar(max)') AS "Field Name", NULL AS "Subtype Name" FROM @CLASS_DEFS AS ClassDefs CROSS APPLY Definition.nodes('/*/GPFieldInfoExs/GPFieldInfoEx') AS FieldDefs(fieldDef) WHERE fieldDef.value('DomainName[1]', 'nvarchar(max)') = @DOMAIN_NAME UNION SELECT ClassDefs.Name AS "Class Name", fieldDef.value('FieldName[1]', 'nvarchar(max)') AS "Field Name", fieldDef.value('(../../SubtypeName)[1]', 'nvarchar(max)') AS "Subtype Name" FROM @CLASS_DEFS AS ClassDefs CROSS APPLY Definition.nodes('/*/Subtypes/Subtype/FieldInfos/SubtypeFieldInfo') AS FieldDefs(fieldDef) WHERE fieldDef.value('DomainName[1]', 'nvarchar(max)') = @DOMAIN_NAME
以下示例演示了在 Oracle 的地理数据库中查询名为 AncillaryRoleDomain 的属性域:
--Queries a geodatabase in Oracle CREAT TABLE CLASS_DEFS ( name varchar2(32), definition XMLType ); --Insert records to temporary record set INSERT INTO CLASS_DEFS SELECT sde.gdb_items_vw.Name, XMLType(sde.gdb_items_vw.Definition) FROM( ( -- Get the domain item's UUID. SELECT GDB_ITEMS_VW.UUID AS UUID FROM sde.gdb_items_vw INNER JOIN sde.gdb_itemtypes ON sde.gdb_items_vw.Type = sde.gdb_itemtypes.UUID WHERE sde.gdb_items_vw.Name = 'AncillaryRoleDomain' AND sde.gdb_itemtypes.Name IN ('Coded Value Domain','Range Domain') ) Domain -- Find the relationships with the domain as the DestinationID. INNER JOIN sde.gdb_itemrelationships ON Domain.UUID = sde.gdb_itemrelationships.DestID ) -- Find the names of the origin items in the relationships. INNER JOIN sde.gdb_items_vw ON sde.gdb_items_vw.UUID = sde.gdb_itemrelationships.OriginID; -- Extract the field definitions. SELECT CLASS_DEFS.Name AS "Class Name", EXTRACTVALUE(fields.Column_Value, '/GPFieldInfoEx/Name') AS "Field Name", null AS "Subtype Name" FROM CLASS_DEFS, TABLE(XMLSEQUENCE(Extract(CLASS_DEFS.definition, '/*/GPFieldInfoExs/GPFieldInfoEx'))) fields UNION SELECT table_name AS "Class Name", EXTRACTVALUE(subtypes_fields.Column_value, '/SubtypeFieldInfo/FieldName') as column_name, subtype_name AS "Subtype Name" FROM ( SELECT CLASS_DEFS.Name AS table_name, subtypes.COLUMN_VALUE XMLVal, EXTRACTVALUE(subtypes.COLUMN_VALUE, '/Subtype/SubtypeName') AS subtype_name, EXTRACTVALUE(subtypes.COLUMN_VALUE, '/Subtype/SubtypeCode') AS subtype_value FROM CLASS_DEFS, TABLE(XMLSEQUENCE(Extract(CLASS_DEFS.definition, '/DEFeatureClassInfo/Subtypes/Subtype'))) subtypes ) subtypes_fields, TABLE(XMLSEQUENCE(subtypes_fields.XMLVal.Extract('/Subtype/FieldInfos/SubtypeFieldInfo'))) subtypes_fields; DROP TABLE CLASS_DEFS;
3/7/2012