@@ -773,13 +773,34 @@ IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1100) AND execute_indic
773773BEGIN TRY
774774
775775WITH
776+ partition_size AS
777+ (
778+ SELECT object_id ,
779+ used_page_count,
780+ row_count
781+ FROM sys .dm_db_partition_stats
782+ WHERE index_id IN (0 ,1 )
783+ UNION
784+ -- special index types
785+ SELECT it .parent_id ,
786+ ps .used_page_count ,
787+ 0 AS row_count
788+ FROM sys .dm_db_partition_stats AS ps
789+ INNER JOIN sys .internal_tables AS it
790+ ON ps .object_id = it .object_id
791+ WHERE it .internal_type_desc IN (
792+ ' XML_INDEX_NODES' ,' SELECTIVE_XML_INDEX_NODE_TABLE' , -- XML indexes
793+ ' EXTENDED_INDEXES' , -- spatial indexes
794+ ' FULLTEXT_INDEX_MAP' ,' FULLTEXT_AVDL' ,' FULLTEXT_COMP_FRAGMENT' ,' FULLTEXT_DOCID_STATUS' ,' FULLTEXT_INDEXED_DOCID' ,' FULLTEXT_DOCID_FILTER' ,' FULLTEXT_DOCID_MAP' , -- fulltext indexes
795+ ' SEMPLAT_DOCUMENT_INDEX_TABLE' ,' SEMPLAT_TAG_INDEX_TABLE' -- semantic search indexes
796+ )
797+ ),
776798object_size AS
777799(
778800SELECT object_id ,
779801 SUM (used_page_count) * 8 / 1024 . AS object_size_mb,
780802 SUM (row_count) AS object_row_count
781- FROM sys .dm_db_partition_stats
782- WHERE index_id IN (0 ,1 ) -- clustered index or heap
803+ FROM partition_size
783804GROUP BY object_id
784805),
785806guid_index AS
@@ -1327,7 +1348,7 @@ IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1400) AND execute_indic
13271348BEGIN TRY
13281349
13291350WITH
1330- object_size AS
1351+ object_row_count AS
13311352(
13321353SELECT object_id ,
13331354 SUM (row_count) AS object_row_count
@@ -1350,13 +1371,13 @@ SELECT OBJECT_SCHEMA_NAME(s.object_id) COLLATE DATABASE_DEFAULT AS schema_name,
13501371 sp .last_updated ,
13511372 sp .unfiltered_rows ,
13521373 sp .rows_sampled ,
1353- os .object_row_count ,
1374+ orc .object_row_count,
13541375 sp .modification_counter
13551376FROM sys .stats AS s
13561377INNER JOIN sys .objects AS o
13571378ON s .object_id = o .object_id
1358- INNER JOIN object_size AS os
1359- ON o .object_id = os .object_id
1379+ INNER JOIN object_row_count AS orc
1380+ ON o .object_id = orc .object_id
13601381CROSS APPLY sys .dm_db_stats_properties (s .object_id , s .stats_id ) AS sp
13611382WHERE (
13621383 o .is_ms_shipped = 0
@@ -1366,13 +1387,13 @@ WHERE (
13661387 AND
13671388 (
13681389 -- object cardinality has changed substantially since last stats update
1369- ABS (ISNULL (sp .unfiltered_rows , 0 ) - os .object_row_count ) / NULLIF (((ISNULL (sp .unfiltered_rows , 0 ) + os .object_row_count ) / 2 ), 0 ) > @StaleStatsCardinalityChangeMinDifference
1390+ ABS (ISNULL (sp .unfiltered_rows , 0 ) - orc .object_row_count) / NULLIF (((ISNULL (sp .unfiltered_rows , 0 ) + orc .object_row_count) / 2 ), 0 ) > @StaleStatsCardinalityChangeMinDifference
13701391 OR
13711392 -- no stats blob created
1372- (sp .last_updated IS NULL AND os .object_row_count > 0 )
1393+ (sp .last_updated IS NULL AND orc .object_row_count > 0 )
13731394 OR
13741395 -- naive: stats for an object with many modifications not updated for a substantial time interval
1375- (sp .modification_counter > @StaleStatsMinModificationCountRatio * os .object_row_count AND DATEDIFF (day , sp .last_updated , SYSDATETIME ()) > @StaleStatsMinAgeThresholdDays)
1396+ (sp .modification_counter > @StaleStatsMinModificationCountRatio * orc .object_row_count AND DATEDIFF (day , sp .last_updated , SYSDATETIME ()) > @StaleStatsMinAgeThresholdDays)
13761397 )
13771398)
13781399INSERT INTO @DetectedTip (tip_id, details)
@@ -1428,7 +1449,7 @@ IF EXISTS (SELECT 1 FROM @TipDefinition WHERE tip_id IN (1410) AND execute_indic
14281449BEGIN TRY
14291450
14301451WITH
1431- object_size AS
1452+ object_row_count AS
14321453(
14331454SELECT object_id ,
14341455 SUM (row_count) AS object_row_count
@@ -1444,14 +1465,14 @@ SELECT QUOTENAME(OBJECT_SCHEMA_NAME(t.object_id)) COLLATE DATABASE_DEFAULT AS sc
14441465 ISNULL (i .no_index_indicator , 0 ) = 1
14451466 AND
14461467 -- exclude small tables
1447- os .object_row_count > @NoIndexTablesMinRowCountThreshold,
1468+ orc .object_row_count > @NoIndexTablesMinRowCountThreshold,
14481469 1 ,
14491470 0
14501471 )
14511472 AS no_index_indicator
14521473FROM sys .tables AS t
1453- INNER JOIN object_size AS os
1454- ON t .object_id = os .object_id
1474+ INNER JOIN object_row_count AS orc
1475+ ON t .object_id = orc .object_id
14551476OUTER APPLY (
14561477 SELECT TOP (1 ) 1 AS no_index_indicator
14571478 FROM sys .indexes AS i
@@ -2572,6 +2593,16 @@ ON p.partition_id = ps.partition_id
25722593 p .object_id = ps .object_id
25732594 AND
25742595 p .index_id = ps .index_id
2596+ WHERE -- restrict to objects that do not have column data types not supported for CCI
2597+ NOT EXISTS (
2598+ SELECT 1
2599+ FROM sys .columns AS c
2600+ INNER JOIN sys .types AS t
2601+ ON c .system_type_id = t .system_type_id
2602+ WHERE c .object_id = p .object_id
2603+ AND
2604+ t .name IN (' text' ,' ntext' ,' image' ,' timestamp' ,' sql_variant' ,' hierarchyid' ,' geometry' ,' geography' ,' xml' )
2605+ )
25752606),
25762607candidate_partition AS
25772608(
0 commit comments