├── Queries ├── DMV Staging Queries │ ├── ColumnsDMV.pq │ ├── CulturesDMV.pq │ ├── HierarchiesDMV.pq │ ├── HierarchyLevelsDMV.pq │ ├── KPIsDMV.pq │ ├── MeasuresDMV.pq │ ├── RolesDMV.pq │ └── TablesDMV.pq ├── Parameters │ ├── Database.pq │ └── Server.pq ├── Report Metadata │ └── Refreshed Time.pq └── Report Tables │ ├── Catalog.pq │ ├── Columns.pq │ ├── Data Sources.pq │ ├── Detail Row Definitions.pq │ ├── Hierarchies.pq │ ├── Hierarchy Levels.pq │ ├── KPIs.pq │ ├── M Expressions.pq │ ├── Measures.pq │ ├── Partitions.pq │ ├── Perspective Columns.pq │ ├── Perspective Measures.pq │ ├── Relationships.pq │ ├── Role Memberships.pq │ ├── Roles.pq │ ├── Schema Overview.pq │ ├── Table Permissions.pq │ ├── TableSizes.pq │ ├── Tables.pq │ └── Translations.pq ├── README.md ├── Tabular Model Schema Reference v1.1.pbix ├── Tabular Model Schema Reference v1.1.xlsm └── Tabular Model Schema Reference v1.1.xlsx /Queries/DMV Staging Queries/ColumnsDMV.pq: -------------------------------------------------------------------------------- 1 | let 2 | ColumnsDMV = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_COLUMNS"]), 3 | ColumnTypes = Table.TransformColumnTypes(ColumnsDMV,{{"ID", Int64.Type}, {"TableID", Int64.Type}, {"SortByColumnID", Int64.Type}}), 4 | ColumnRename = Table.RenameColumns(ColumnTypes,{{"ExplicitName", "Column Name"}, {"SourceColumn", "Source Column Name"}, 5 | {"DisplayFolder", "Display Folder"}, {"Description", "Column Description"}, {"DataCategory", "Data Category"}}), 6 | SelfJoin = Table.NestedJoin(ColumnRename,{"SortByColumnID"},ColumnRename,{"ID"},"ColumnRename",JoinKind.LeftOuter), 7 | SortByColumn = Table.ExpandTableColumn(SelfJoin, "ColumnRename", {"Column Name"}, {"Sort By Column Name"}), 8 | JoinToTables = Table.NestedJoin(SortByColumn,{"TableID"},TablesDMV,{"ID"},"Tables",JoinKind.Inner), 9 | TableColumns = Table.ExpandTableColumn(JoinToTables, "Tables", {"Table Name", "Table Description"}, {"Table Name", "Table Description"}), 10 | 11 | ColumnDataType = Table.AddColumn(TableColumns, "Data Type", each 12 | if [ExplicitDataType] = 2 then "Text" 13 | else if [ExplicitDataType] = 8 then "Decimal Number" 14 | else if [ExplicitDataType] = 10 then "Fixed Decimal Number" 15 | else if [ExplicitDataType] = 6 then "Whole Number" 16 | else if [ExplicitDataType] = 9 then "Date" 17 | else "Other", 18 | type text), 19 | 20 | ColumnType = Table.AddColumn(ColumnDataType, "Column Type", each 21 | if [Type] = 1 then "Standard Column" 22 | else if [Type] = 2 then "DAX Calculated Column" 23 | else "System Column", type text), 24 | 25 | RemoveSystemColumns = Table.SelectRows(ColumnType, each ([Column Type] <> "System Column")), 26 | 27 | EncodingHintColumn = Table.AddColumn(RemoveSystemColumns, "Encoding Hint", each 28 | if [EncodingHint] = 0 then "None" 29 | else if [EncodingHint] = 1 then "Hash Encoding" 30 | else if [EncodingHint] = 2 then "Value Encoding" 31 | else "Unknown", type text), 32 | 33 | SummarizeByColumn = Table.AddColumn(EncodingHintColumn, "Summarize By", each 34 | if [SummarizeBy] = 1 then "Default" 35 | else if [SummarizeBy] = 2 then "Do Not Summarize" 36 | else if [SummarizeBy] = 3 then "Sum" 37 | else "Other Summarization", type text) 38 | 39 | in 40 | SummarizeByColumn -------------------------------------------------------------------------------- /Queries/DMV Staging Queries/CulturesDMV.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_CULTURES"]) 3 | in 4 | Source -------------------------------------------------------------------------------- /Queries/DMV Staging Queries/HierarchiesDMV.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_HIERARCHIES"]), 3 | RenameCol = Table.RenameColumns(Source,{{"Name", "Hierarchy Name"}, {"Description", "Hierarchy Description"}}), 4 | TablesJoin = Table.NestedJoin(RenameCol,{"TableID"},TablesDMV,{"ID"},"Tables",JoinKind.Inner), 5 | TablesName = Table.ExpandTableColumn(TablesJoin, "Tables", {"Table Name"}, {"Table Name"}), 6 | HideBlankMembers = Table.AddColumn(TablesName, "Hide Blank Members", each 7 | if [HideMembers] = 1 then "TRUE" 8 | else "FALSE", type text), 9 | PreIndexSort = Table.Sort(HideBlankMembers,{{"Table Name", Order.Ascending}}), 10 | IndexCol = Table.AddIndexColumn(PreIndexSort, "Hierarchy Index ID", 1, 1), 11 | ReorderCols = Table.ReorderColumns(IndexCol,{"Hierarchy Index ID", "Table Name", "Hierarchy Name", "Hide Blank Members", "ModifiedTime", "StructureModifiedTime"}) 12 | in 13 | ReorderCols -------------------------------------------------------------------------------- /Queries/DMV Staging Queries/HierarchyLevelsDMV.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_LEVELS"]) 3 | in 4 | Source -------------------------------------------------------------------------------- /Queries/DMV Staging Queries/KPIsDMV.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_KPIS"]), 3 | #"Renamed Columns" = Table.RenameColumns(Source,{{"TargetDescription", "KPI Target Description"}, {"TargetExpression", "KPI Target DAX Expression"}, {"TargetFormatString", "KPI Target Format"}, {"StatusGraphic", "KPI Status Graphic"}, {"StatusExpression", "KPI Status Expression"}, {"Description", "KPI Description"}, {"StatusDescription", "KPI Status Description"}}) 4 | 5 | in 6 | #"Renamed Columns" -------------------------------------------------------------------------------- /Queries/DMV Staging Queries/MeasuresDMV.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_MEASURES"]), 3 | ColumnRename = Table.RenameColumns(Source,{{"Name", "Measure Name"},{"Description", "Measure Description"}, 4 | {"Expression", "DAX Expression"}, {"FormatString", "Format"}, {"DisplayFolder", "Display Folder"}}), 5 | ColTypes = Table.TransformColumnTypes(ColumnRename,{{"ID", Int64.Type}, {"TableID", Int64.Type}}), 6 | JoinToTables = Table.NestedJoin(ColTypes,{"TableID"},TablesDMV,{"ID"},"Tables",JoinKind.Inner), 7 | TableColumns = Table.ExpandTableColumn(JoinToTables, "Tables", {"Table Name", "Table Description"}, {"Table Name", "Table Description"}) 8 | 9 | in 10 | TableColumns -------------------------------------------------------------------------------- /Queries/DMV Staging Queries/RolesDMV.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_ROLES"]), 3 | RenameColumns = Table.RenameColumns(Source,{{"Name", "Role"}, {"Description", "Role Description"}}), 4 | ModelPermissionColumn = 5 | Table.AddColumn(RenameColumns, "Model Permission", each 6 | if [ModelPermission] = 2 then "Read Only" 7 | else if [ModelPermission] = 3 then "Read and Process" 8 | else if [ModelPermission] = 1 then "No Access" 9 | else if [ModelPermission] = 4 then "Process Only" 10 | else if [ModelPermission] = 5 then "Database Admin" 11 | else "Undefined", 12 | type text) 13 | 14 | in 15 | ModelPermissionColumn -------------------------------------------------------------------------------- /Queries/DMV Staging Queries/TablesDMV.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_TABLES"]), 3 | RenameColumns = Table.RenameColumns(Source,{{"Name", "Table Name"}, {"Description", "Table Description"}}), 4 | ColumnTypes = Table.TransformColumnTypes(RenameColumns,{{"ID", Int64.Type}, {"DefaultDetailRowsDefinitionID", Int64.Type}, {"TableStorageID", Int64.Type}, {"ModelID", Int64.Type}}) 5 | in 6 | ColumnTypes -------------------------------------------------------------------------------- /Queries/Parameters/Database.pq: -------------------------------------------------------------------------------- 1 | "AdWorksImport" meta [IsParameterQuery=true, Type="Any", IsParameterQueryRequired=true] -------------------------------------------------------------------------------- /Queries/Parameters/Server.pq: -------------------------------------------------------------------------------- 1 | "ATLAS" meta [IsParameterQuery=true, Type="Any", IsParameterQueryRequired=true] -------------------------------------------------------------------------------- /Queries/Report Metadata/Refreshed Time.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = DateTime.LocalNow() 3 | in 4 | Source -------------------------------------------------------------------------------- /Queries/Report Tables/Catalog.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.DBSCHEMA_CATALOGS"]), 3 | FilterByCatalog = Table.SelectRows(Source, each [CATALOG_NAME] = Database), 4 | RemoveColumns = Table.RemoveColumns(FilterByCatalog,{"DESCRIPTION", "TYPE", "VERSION", "DATABASE_ID", "DATE_QUERIED", "CURRENTLY_USED", "POPULARITY", "WEIGHTEDPOPULARITY"}), 5 | RenameColumns = Table.RenameColumns(RemoveColumns, 6 | {{"COMPATIBILITY_LEVEL", "Compatibility Level"}, 7 | {"ROLES", "Database Roles"}, {"DATE_MODIFIED", "Last Modified"}, 8 | {"CATALOG_NAME", "Database"}}), 9 | ServerColumn = Table.AddColumn(RenameColumns, "Server", each Server, type text), 10 | ColumnReorder = Table.ReorderColumns(ServerColumn,{"Server", "Database", "Database Roles", "Last Modified", "Compatibility Level"}) 11 | in 12 | ColumnReorder -------------------------------------------------------------------------------- /Queries/Report Tables/Columns.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = ColumnsDMV, 3 | RemoveCols = Table.RemoveColumns(Source,{"ID", "TableID","SummarizeBy", "InferredName", 4 | "ExplicitDataType","IsUnique","IsDefaultImage","EncodingHint", 5 | "InferredDataType", "State", "IsKey", "IsNullable", "Alignment", "TableDetailPosition", 6 | "ColumnStorageID", "ColumnOriginID", "SortByColumnID", "DisplayOrdinal", "ErrorMessage", 7 | "SourceProviderType", "KeepUniqueRows", "SystemFlags", "RefreshedTime", "IsDefaultLabel", "Type", "AttributeHierarchyID"}), 8 | PreIndexSort = Table.Sort(RemoveCols,{{"Table Name", Order.Ascending}, {"Column Name", Order.Ascending}}), 9 | AddColIndex = Table.AddIndexColumn(PreIndexSort, "Column Index ID", 1, 1), 10 | ReorderCols = Table.ReorderColumns(AddColIndex, 11 | {"Column Index ID", "Column Name", "Column Description", "Table Name", 12 | "Data Category", "IsHidden", "Source Column Name", "Expression", 13 | "FormatString", "IsAvailableInMDX","Summarize By", "ModifiedTime", "StructureModifiedTime", 14 | "Display Folder", "Sort By Column Name", "Table Description", "Data Type", "Column Type", "Encoding Hint"}) 15 | 16 | in 17 | ReorderCols -------------------------------------------------------------------------------- /Queries/Report Tables/Data Sources.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_DATA_SOURCES"]), 3 | RemoveCols = Table.RemoveColumns(Source,{"ID", "ModelID", "Description", "Account", "Password"}), 4 | ColRename = Table.RenameColumns(RemoveCols,{{"Name", "Data Source Name"},{"ConnectionString", "Connection String"}, {"Type", "Data Source Type"}, {"ImpersonationMode", "Impersonation Mode"}, {"Credential", "Data Source Credential"}, {"ContextExpression", "Context Expression"}, {"ConnectionDetails", "Connection Details"}, {"ModifiedTime", "Modified Time"}, {"MaxConnections", "Max Connections"}}), 5 | AddIndex = Table.AddIndexColumn(ColRename, "Data Source Index ID", 1, 1), 6 | ReorderCols = Table.ReorderColumns(AddIndex,{"Data Source Index ID", "Data Source Name", "Data Source Type", "Connection String", "Impersonation Mode", "Max Connections", "Isolation", "Timeout", "Provider", "Modified Time", "Connection Details", "Options", "Data Source Credential", "Context Expression"}) 7 | in 8 | ReorderCols -------------------------------------------------------------------------------- /Queries/Report Tables/Detail Row Definitions.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_DETAIL_ROWS_DEFINITIONS"]), 3 | RowDefColType = Table.AddColumn(Source,"Detail Row Type", each 4 | if [ObjectType] = 8 then "Measure Detail Row Definition" 5 | else "Default Table Detail Row Definition", type text), 6 | RenameCols = Table.RenameColumns(RowDefColType,{{"Expression", "Detail Row DAX Expression"}}), 7 | MeasureJoin = Table.NestedJoin(RenameCols,{"ID"},MeasuresDMV,{"DetailRowsDefinitionID"},"MeasuresDMV",JoinKind.LeftOuter), 8 | MeasureCols = Table.ExpandTableColumn(MeasureJoin, "MeasuresDMV", {"Measure Name", "Measure Description"}, {"Measure Name", "Measure Description"}), 9 | TablesJoin = Table.NestedJoin(MeasureCols,{"ID"},TablesDMV,{"DefaultDetailRowsDefinitionID"},"TablesDMV",JoinKind.LeftOuter), 10 | TablesCols = Table.ExpandTableColumn(TablesJoin, "TablesDMV", {"Table Name"}, {"Table Name"}), 11 | SelectCols = Table.SelectColumns(TablesCols,{"Detail Row DAX Expression", "Detail Row Type", 12 | "Measure Name", "Measure Description", "Table Name"}), 13 | PreIndexSort = Table.Sort(SelectCols,{{"Detail Row Type", Order.Ascending}, {"Table Name", Order.Ascending}}), 14 | DetailRowIndex = Table.AddIndexColumn(PreIndexSort, "Detail Row Index ID", 1, 1), 15 | ReorderCols = Table.ReorderColumns(DetailRowIndex, 16 | {"Detail Row Index ID", "Detail Row Type", "Detail Row DAX Expression", "Measure Name", 17 | "Measure Description", "Table Name"}) 18 | in 19 | ReorderCols -------------------------------------------------------------------------------- /Queries/Report Tables/Hierarchies.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = HierarchiesDMV, 3 | RemoveCols = Table.RemoveColumns(Source,{"ID", "TableID", "IsHidden","Hierarchy Description", 4 | "HideMembers", "State", "HierarchyStorageID", "RefreshedTime", "DisplayFolder"}) 5 | 6 | in 7 | RemoveCols -------------------------------------------------------------------------------- /Queries/Report Tables/Hierarchy Levels.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = HierarchyLevelsDMV, 3 | JoinToHierarchiesDMV = Table.NestedJoin(Source,{"HierarchyID"},HierarchiesDMV,{"ID"},"HierarchiesDMV",JoinKind.Inner), 4 | HierarchiesDMVCol = Table.ExpandTableColumn(JoinToHierarchiesDMV, "HierarchiesDMV", 5 | {"Table Name", "Hierarchy Name"}, {"Table Name","Hierarchy Name"}), 6 | PreIndexSort = Table.Sort(HierarchiesDMVCol,{{"Hierarchy Name", Order.Ascending}, {"Ordinal", Order.Ascending}}), 7 | IndexColumn = Table.AddIndexColumn(PreIndexSort, "Hierarchy Level Index ID", 1, 1), 8 | RemoveColumns = Table.RemoveColumns(IndexColumn,{"ID", "HierarchyID", "ColumnID", "Description"}), 9 | RenameColumns = Table.RenameColumns(RemoveColumns,{{"Name", "Hierarchy Level Column"}, {"Ordinal", "Hierarchy Level"}}), 10 | ReorderColumns = Table.ReorderColumns(RenameColumns,{"Hierarchy Level Index ID", "Hierarchy Name", "Hierarchy Level Column", "Hierarchy Level", "Table Name", "ModifiedTime"}) 11 | in 12 | ReorderColumns -------------------------------------------------------------------------------- /Queries/Report Tables/KPIs.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = KPIsDMV, 3 | KPIsToMeasuresDMV = Table.NestedJoin(Source,{"MeasureID"},MeasuresDMV,{"ID"},"MeasuresDMV",JoinKind.Inner), 4 | MeasureDMVCols = Table.ExpandTableColumn(KPIsToMeasuresDMV, "MeasuresDMV", {"Measure Name", "Measure Description", "Table Name"}, {"KPI Base Measure Name", "KPI Base Measure Description", "KPI Base Measure Table Name"}), 5 | RemoveCols = Table.RemoveColumns(MeasureDMVCols,{"ID", "MeasureID", "TrendGraphic", "TrendDescription", "TrendExpression"}), 6 | PreIndexSort = Table.Sort(RemoveCols,{{"KPI Base Measure Table Name", Order.Ascending}}), 7 | AddIndexCol = Table.AddIndexColumn(PreIndexSort, "KPI Index ID", 1, 1), 8 | ReOrderCols = Table.ReorderColumns(AddIndexCol,{"KPI Index ID", "KPI Base Measure Name", "KPI Target DAX Expression", "KPI Description", "KPI Status Expression", "KPI Status Graphic", "KPI Target Description", "KPI Target Format", "KPI Status Description", "KPI Base Measure Description", "KPI Base Measure Table Name", "ModifiedTime"}) 9 | in 10 | ReOrderCols -------------------------------------------------------------------------------- /Queries/Report Tables/M Expressions.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_EXPRESSIONS"]), 3 | RemoveCols = Table.RemoveColumns(Source,{"ID", "ModelID", "Kind"}), 4 | RenameCols = Table.RenameColumns(RemoveCols,{{"Name", "M Expression Name"}, {"Description", "M Expression Description"}, {"Expression", "M Expression"}}), 5 | AddIndex = Table.AddIndexColumn(RenameCols, "M Expression Index ID", 1, 1), 6 | OrderColumns = Table.ReorderColumns(AddIndex,{"M Expression Index ID", "M Expression Name", "M Expression Description", "M Expression", "ModifiedTime"}) 7 | in 8 | OrderColumns -------------------------------------------------------------------------------- /Queries/Report Tables/Measures.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = MeasuresDMV, 3 | RemoveCols = Table.RemoveColumns(Source,{"ID", "TableID", "DataType", "StructureModifiedTime", "KPIID", "ErrorMessage", "DetailRowsDefinitionID","State", "IsSimpleMeasure"}), 4 | PreIndexSort = Table.Sort(RemoveCols,{{"Table Name", Order.Ascending}}), 5 | IndexCol = Table.AddIndexColumn(PreIndexSort, "Measure Index ID", 1, 1), 6 | 7 | ExpressionLengthBucket = Table.AddColumn(IndexCol, "DAX Length Category", each 8 | if Text.Length([DAX Expression]) <= 20 then "20 or less chararcters" 9 | else if Text.Length([DAX Expression]) <= 40 then "21 to 40 characters" 10 | else if Text.Length([DAX Expression]) <= 60 then "41 to 60 characters" 11 | else if Text.Length([DAX Expression]) <= 80 then "61 to 80 characters" 12 | else "Over 80 characters", type text), 13 | 14 | ReorderCols = Table.ReorderColumns(ExpressionLengthBucket, 15 | {"Measure Index ID", "Table Name", "Display Folder", "Measure Name", "Measure Description", "DAX Expression", 16 | "DAX Length Category","Format", "Table Description", "IsHidden", "ModifiedTime"}), 17 | 18 | IteratorColumn = 19 | Table.AddColumn(ReorderCols, "Contains Iterator", each 20 | if 21 | Text.Contains([DAX Expression], "FILTER") or 22 | Text.Contains([DAX Expression], "Filter") or 23 | Text.Contains([DAX Expression], "X") or 24 | Text.Contains([DAX Expression], "x") then "TRUE" 25 | else "FALSE", type text), 26 | 27 | VariableColumn = 28 | Table.AddColumn(IteratorColumn, "Contains Variable", each 29 | if 30 | Text.Contains([DAX Expression], "VAR") or 31 | Text.Contains([DAX Expression], "var") or 32 | Text.Contains([DAX Expression], "Var") then "TRUE" 33 | else "FALSE", type text) 34 | 35 | in 36 | VariableColumn -------------------------------------------------------------------------------- /Queries/Report Tables/Partitions.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_PARTITIONS"]), 3 | Rename = Table.RenameColumns(Source,{{"Name", "Partition Name"},{"Description", "Partition Description"}, {"QueryDefinition", "Partition Query"}}), 4 | TablesJoin = Table.NestedJoin(Rename,{"TableID"},TablesDMV,{"ID"},"Tables",JoinKind.Inner), 5 | TablesColumns = Table.ExpandTableColumn(TablesJoin, "Tables", {"Table Name"}, {"Table Name"}), 6 | RemoveCols = Table.RemoveColumns(TablesColumns,{"ID", "TableID","Type", "DataSourceID", "State", "PartitionStorageID", "RefreshedTime", "SystemFlags", "ErrorMessage", "RetainDataTillForceCalculate"}), 7 | PreIndexSort = Table.Sort(RemoveCols,{{"Table Name", Order.Ascending}, {"Partition Name", Order.Ascending}}), 8 | IndexCol = Table.AddIndexColumn(PreIndexSort, "Partition Index ID", 1, 1), 9 | ColumnOrder = Table.ReorderColumns(IndexCol,{"Partition Index ID", "Table Name", "Partition Name", 10 | "Partition Query", "Partition Description", "Mode", "DataView", "ModifiedTime"}) 11 | in 12 | ColumnOrder -------------------------------------------------------------------------------- /Queries/Report Tables/Perspective Columns.pq: -------------------------------------------------------------------------------- 1 | let 2 | 3 | //Perspective DMVs 4 | 5 | PColumns = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_PERSPECTIVE_COLUMNS"]), 6 | PTables = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_PERSPECTIVE_TABLES"]), 7 | P = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_PERSPECTIVES"]), 8 | 9 | //Perspective and tables 10 | 11 | TableJoin = Table.NestedJoin(PTables,{"TableID"},TablesDMV,{"ID"},"Tables",JoinKind.Inner), 12 | TableName = Table.ExpandTableColumn(TableJoin, "Tables", {"Table Name"}, {"Table Name"}), 13 | PerspectiveJoin = Table.NestedJoin(TableName,"PerspectiveID",P,"ID","Perspectives",JoinKind.Inner), 14 | PerspectiveColumns = Table.ExpandTableColumn(PerspectiveJoin, "Perspectives", {"Name", "Description"}, {"Perspective", "Perspective Description"}), 15 | 16 | //Perspective columns 17 | 18 | PColJoin = Table.NestedJoin(PColumns,"ColumnID",ColumnsDMV,"ID","Columns",JoinKind.Inner), 19 | PCol = Table.ExpandTableColumn(PColJoin, "Columns", {"Column Name"}, {"Column Name"}), 20 | 21 | //Perspective column to table join 22 | 23 | PColTableJoin = Table.NestedJoin(PCol,"PerspectiveTableID",PerspectiveColumns,"ID","PTable",JoinKind.Inner), 24 | PTable = Table.ExpandTableColumn(PColTableJoin, "PTable", {"Table Name", "Perspective", "Perspective Description"}, {"Table Name", "Perspective", "Perspective Description"}), 25 | RemoveColumns = Table.RemoveColumns(PTable,{"ID", "PerspectiveTableID", "ColumnID", "Perspective Description"}), 26 | 27 | //Inded ID and Order 28 | 29 | PreIndexSort = Table.Sort(RemoveColumns,{{"Perspective", Order.Ascending}, {"Table Name", Order.Ascending}}), 30 | IndexCol = Table.AddIndexColumn(PreIndexSort, "Perspective Column Index ID", 1, 1), 31 | ColOrder = Table.ReorderColumns(IndexCol,{"Perspective Column Index ID", "Perspective", "Column Name", "Table Name", "ModifiedTime"}) 32 | in 33 | ColOrder -------------------------------------------------------------------------------- /Queries/Report Tables/Perspective Measures.pq: -------------------------------------------------------------------------------- 1 | let 2 | 3 | //Perspective DMVs 4 | 5 | PMeasures = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_PERSPECTIVE_MEASURES"]), 6 | PTables = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_PERSPECTIVE_TABLES"]), 7 | P = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_PERSPECTIVES"]), 8 | 9 | //Perspective and tables 10 | 11 | TableJoin = Table.NestedJoin(PTables,{"TableID"},TablesDMV,{"ID"},"Tables",JoinKind.Inner), 12 | TableName = Table.ExpandTableColumn(TableJoin, "Tables", {"Table Name"}, {"Table Name"}), 13 | PerspectiveJoin = Table.NestedJoin(TableName,"PerspectiveID",P,"ID","Perspectives",JoinKind.Inner), 14 | PerspectiveColumns = Table.ExpandTableColumn(PerspectiveJoin, "Perspectives", {"Name", "Description"}, {"Perspective", "Perspective Description"}), 15 | 16 | //Perspective measures 17 | 18 | PMeasuresJoin = Table.NestedJoin(PMeasures,"MeasureID",MeasuresDMV,"ID","Measures",JoinKind.Inner), 19 | PMeasureColumns = Table.ExpandTableColumn(PMeasuresJoin, "Measures", {"Measure Name"}, {"Measure Name"}), 20 | 21 | //Perspective measures to table join 22 | 23 | PMeasureTableJoin = Table.NestedJoin(PMeasureColumns,"PerspectiveTableID",PerspectiveColumns,"ID","PTable",JoinKind.Inner), 24 | PTableColumns = Table.ExpandTableColumn(PMeasureTableJoin, "PTable", {"Table Name", "Perspective", "Perspective Description"}, {"Table Name", "Perspective", "Perspective Description"}), 25 | 26 | // Perspective Measure index column 27 | 28 | PreIndexSort = Table.Sort(PTableColumns,{{"Perspective", Order.Ascending}, {"Table Name", Order.Ascending}}), 29 | IndexCol = Table.AddIndexColumn(PreIndexSort, "Perspective Measure Index ID", 1, 1), 30 | 31 | //Remove and reorder columns 32 | 33 | RemoveCols = Table.RemoveColumns(IndexCol,{"Perspective Description", "ID", "PerspectiveTableID", "MeasureID"}), 34 | ReorderCols = Table.ReorderColumns(RemoveCols,{"Perspective Measure Index ID", "Perspective", "Measure Name", "Table Name", "ModifiedTime"}) 35 | 36 | in 37 | ReorderCols -------------------------------------------------------------------------------- /Queries/Report Tables/Relationships.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_RELATIONSHIPS"]), 3 | Types = Table.TransformColumnTypes(Source,{{"ID", Int64.Type}}), 4 | FromTableJoin = Table.NestedJoin(Types,{"FromTableID"},TablesDMV,{"ID"},"Tables",JoinKind.Inner), 5 | FromTable = Table.ExpandTableColumn(FromTableJoin, "Tables", {"Table Name"}, {"From Table Name"}), 6 | ToTableJoin = Table.NestedJoin(FromTable,{"ToTableID"},TablesDMV,{"ID"},"Tables",JoinKind.Inner), 7 | ToTable = Table.ExpandTableColumn(ToTableJoin, "Tables", {"Table Name"}, {"To Table Name"}), 8 | FromColumnJoin = Table.NestedJoin(ToTable,{"FromColumnID"},ColumnsDMV,{"ID"},"Columns",JoinKind.Inner), 9 | FromColumn = Table.ExpandTableColumn(FromColumnJoin, "Columns", {"Column Name"}, {"From Column Name"}), 10 | ToColumnJoin = Table.NestedJoin(FromColumn,{"ToColumnID"},ColumnsDMV,{"ID"},"Columns",JoinKind.Inner), 11 | ToColumn = Table.ExpandTableColumn(ToColumnJoin, "Columns", {"Column Name"}, {"To Column Name"}), 12 | Crossfilter = Table.AddColumn(ToColumn, "Crossfiltering Behavior", each 13 | if [CrossFilteringBehavior] = 1 then "Single Direction" 14 | else if [CrossFilteringBehavior] = 2 then "Bidirectional Crossfiltering" 15 | else "Unknown", 16 | type text), 17 | 18 | SecurityFilterBehavior = Table.AddColumn(Crossfilter, "Security Filter Behavior", each 19 | if [SecurityFilteringBehavior] = 2 then "Bidirectional Security Filter" 20 | else if [SecurityFilteringBehavior] = 1 then "Single Direction Security Filter" 21 | else "Unknown", 22 | type text), 23 | 24 | ColumnOrder = Table.ReorderColumns(SecurityFilterBehavior,{"ID", "From Table Name", "To Table Name", "From Column Name", "To Column Name", "Crossfiltering Behavior", "ModelID", "Name", "IsActive", "Type", "CrossFilteringBehavior", "JoinOnDateBehavior", "RelyOnReferentialIntegrity", "FromTableID", "FromColumnID", "FromCardinality", "ToTableID", "ToColumnID", "ToCardinality", "State", "RelationshipStorageID", "RelationshipStorage2ID", "ModifiedTime", "RefreshedTime", "SecurityFilteringBehavior"}), 25 | RemoveCols = Table.RemoveColumns(ColumnOrder, 26 | {"ID", "ModelID", "Name", "CrossFilteringBehavior", 27 | "FromTableID", "FromColumnID", "FromCardinality", "ToTableID", "ToColumnID", "ToCardinality", "State", 28 | "RelationshipStorageID","Type", "RelationshipStorage2ID", "SecurityFilteringBehavior"}), 29 | 30 | PreIndexSort = Table.Sort(RemoveCols,{{"From Table Name", Order.Ascending}}), 31 | IndexCol = Table.AddIndexColumn(PreIndexSort, "Relationship Index ID", 1, 1), 32 | OrderColumns = Table.ReorderColumns(IndexCol,{"Relationship Index ID", "From Table Name", "To Table Name", 33 | "From Column Name", "To Column Name", "Crossfiltering Behavior", "Security Filter Behavior", "IsActive", "JoinOnDateBehavior", "RelyOnReferentialIntegrity", "ModifiedTime", "RefreshedTime" }) 34 | in 35 | OrderColumns -------------------------------------------------------------------------------- /Queries/Report Tables/Role Memberships.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_ROLE_MEMBERSHIPS"]), 3 | RenameColumns = Table.RenameColumns(Source,{{"MemberName", "Role Member"}, {"IdentityProvider", "Identity Provider"}}), 4 | JoinToRoles = Table.NestedJoin(RenameColumns,{"RoleID"},RolesDMV,{"ID"},"Roles",JoinKind.Inner), 5 | RolesColumns = Table.ExpandTableColumn(JoinToRoles, "Roles", {"Role", "Role Description"}, {"Role", "Role Description"}), 6 | RemoveColumns = Table.RemoveColumns(RolesColumns,{"ID", "RoleID","MemberID","MemberType"}), 7 | PreIndexSort = Table.Sort(RemoveColumns,{{"Role", Order.Ascending}}), 8 | IndexCol = Table.AddIndexColumn(PreIndexSort, "Role Membership Index ID", 1, 1), 9 | ColReorder = Table.ReorderColumns(IndexCol,{"Role Membership Index ID", "Role", "Role Member", "Role Description", "Identity Provider", "ModifiedTime"}) 10 | in 11 | ColReorder -------------------------------------------------------------------------------- /Queries/Report Tables/Roles.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = RolesDMV, 3 | RemoveCols = Table.RemoveColumns(Source,{"ID", "ModelID", "ModelPermission"}), 4 | SortRows = Table.Sort(RemoveCols,{{"Model Permission", Order.Ascending}}), 5 | AddIndex = Table.AddIndexColumn(SortRows, "Role Index ID", 1, 1), 6 | ReorderColumns = Table.ReorderColumns(AddIndex,{"Role Index ID", "Role", "Model Permission", "Role Description", "ModifiedTime"}) 7 | in 8 | ReorderColumns -------------------------------------------------------------------------------- /Queries/Report Tables/Schema Overview.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_MODEL"]), 3 | ColRename = Table.RenameColumns(Source,{{"Name", "Model Name"}, {"Culture", "Language"}}), 4 | StorageMode = Table.AddColumn(ColRename, "Storage Mode", each 5 | if [DefaultMode] = 1 then "DirectQuery" 6 | else if [DefaultMode] = 0 then "Import" 7 | else "Other Storage Mode", type text), 8 | RemovedColumns = Table.RemoveColumns(StorageMode,{"ID", "Description", "StorageLocation", "DefaultMode", "DefaultDataView", "Collation", "DataAccessOptions", "DefaultMeasureID"}), 9 | ReorderColumns = Table.ReorderColumns(RemovedColumns,{"Model Name", "Language", "Storage Mode", "ModifiedTime", "StructureModifiedTime", "Version"}) 10 | in 11 | ReorderColumns -------------------------------------------------------------------------------- /Queries/Report Tables/Table Permissions.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.TMSCHEMA_TABLE_PERMISSIONS"]), 3 | TableJoin = Table.NestedJoin(Source,{"TableID"},TablesDMV,{"ID"},"Tables",JoinKind.Inner), 4 | TableName = Table.ExpandTableColumn(TableJoin, "Tables", {"Table Name"}, {"Table Name"}), 5 | RolesJoin = Table.NestedJoin(TableName,{"RoleID"},RolesDMV,{"ID"},"Roles",JoinKind.Inner), 6 | RolesName = Table.ExpandTableColumn(RolesJoin, "Roles", {"Role"}, {"Role"}), 7 | TableMetadata = Table.AddColumn(RolesName, "Table Metadata Permission", each 8 | if [MetadataPermission] = 1 then "None" 9 | else "Permission", type text), 10 | RenameColumns = Table.RenameColumns(TableMetadata,{{"FilterExpression", "Table Filter Expression"}}), 11 | RemoveColumns = Table.RemoveColumns(RenameColumns,{"ID", "RoleID", "TableID", "ErrorMessage","State","MetadataPermission"}), 12 | PreIndexSort = Table.Sort(RemoveColumns,{{"Role", Order.Ascending}}), 13 | IndexCol = Table.AddIndexColumn(PreIndexSort, "Table Permission Index ID", 1, 1), 14 | ReorderColumns = Table.ReorderColumns(IndexCol,{"Table Permission Index ID", "Role", "Table Name", "Table Metadata Permission", "Table Filter Expression", "ModifiedTime"}) 15 | in 16 | ReorderColumns -------------------------------------------------------------------------------- /Queries/Report Tables/TableSizes.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = AnalysisServices.Database(Server, Database, [Query="select * from $SYSTEM.DISCOVER_STORAGE_TABLES"]), 3 | FilterSystemRows = Table.SelectRows(Source, each 4 | Text.Range([TABLE_ID],1,1) <> "$"), 5 | RemoveCols = Table.SelectColumns(FilterSystemRows,{"DIMENSION_NAME", "TABLE_PARTITIONS_COUNT", "ROWS_COUNT"}), 6 | RenameCols = Table.RenameColumns(RemoveCols,{{"DIMENSION_NAME", "Table"}, {"TABLE_PARTITIONS_COUNT", "Partitions"}, {"ROWS_COUNT", "Rows"}}), 7 | SortByRowCount = Table.Sort(RenameCols,{{"Rows", Order.Descending}}), 8 | OrderCols = Table.ReorderColumns(SortByRowCount,{"Table", "Rows", "Partitions"}) 9 | in 10 | OrderCols -------------------------------------------------------------------------------- /Queries/Report Tables/Tables.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = TablesDMV, 3 | RemoveColumns = Table.RemoveColumns(Source,{"ID", "ModelID", "DataCategory", "TableStorageID", "SystemFlags", "ShowAsVariationsOnly", "IsPrivate", "DefaultDetailRowsDefinitionID"}), 4 | AddIndexCol = Table.AddIndexColumn(RemoveColumns, "Table Index ID", 1, 1), 5 | ReorderCols = Table.ReorderColumns(AddIndexCol,{"Table Index ID", "Table Name", "Table Description", "IsHidden", "ModifiedTime", "StructureModifiedTime"}) 6 | in 7 | ReorderCols -------------------------------------------------------------------------------- /Queries/Report Tables/Translations.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = CulturesDMV, 3 | RenamedCols = Table.RenameColumns(Source,{{"Name", "Language Translation"}}), 4 | RemovedColumns = Table.RemoveColumns(RenamedCols,{"ID", "ModelID", "LinguisticMetadataID", "StructureModifiedTime"}), 5 | SortedRows = Table.Sort(RemovedColumns,{{"Language Translation", Order.Ascending}}), 6 | AddedIndex = Table.AddIndexColumn(SortedRows, "Translation Index ID", 1, 1), 7 | ReorderedColumns = Table.ReorderColumns(AddedIndex, 8 | {"Translation Index ID", "Language Translation", "ModifiedTime"}) 9 | 10 | in 11 | ReorderedColumns -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Tabular-Schema-Reference 2 | -------------------------------------------------------------------------------- /Tabular Model Schema Reference v1.1.pbix: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/BrettP76/Tabular-Schema-Reference/e7c100bd14a351faf23f784115e3316a3a4d712b/Tabular Model Schema Reference v1.1.pbix -------------------------------------------------------------------------------- /Tabular Model Schema Reference v1.1.xlsm: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/BrettP76/Tabular-Schema-Reference/e7c100bd14a351faf23f784115e3316a3a4d712b/Tabular Model Schema Reference v1.1.xlsm -------------------------------------------------------------------------------- /Tabular Model Schema Reference v1.1.xlsx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/BrettP76/Tabular-Schema-Reference/e7c100bd14a351faf23f784115e3316a3a4d712b/Tabular Model Schema Reference v1.1.xlsx --------------------------------------------------------------------------------