├── .gitignore ├── Basic ├── Autogenerate SUM Measures.csx ├── Create countrows measures.csx ├── Format All Measures.csx ├── Hide columns on the many side of a relationship.csx └── Move All Columns to a DisplayFolder.csx ├── Demos └── FabCon 2025 │ ├── AutoPopulateMeasureDescriptionsFromOpenAIWithDelay.csx │ ├── CheckReportsForInvalidObjectRefs.csx │ ├── SemanticModelValidationPipeline.yaml │ └── Ultimate productivity.pptx ├── Intermediate ├── Clean object names.csx ├── Create Time Intelligence Measures Using Calculation Groups.csx ├── CreateExplicitMeasures.csx └── Dynamic measure selector.csx ├── LICENSE └── README.md /.gitignore: -------------------------------------------------------------------------------- 1 | ################################################################################ 2 | # This .gitignore file was automatically created by Microsoft(R) Visual Studio. 3 | ################################################################################ 4 | 5 | /.vs 6 | -------------------------------------------------------------------------------- /Basic/Autogenerate SUM Measures.csx: -------------------------------------------------------------------------------- 1 | /* 2 | * Title: Auto-generate SUM measures from columns 3 | * 4 | * Author: Daniel Otykier, twitter.com/DOtykier 5 | * 6 | * This script, when executed, will loop through the currently selected columns, 7 | * creating one SUM measure for each column and also hiding the column itself. 8 | */ 9 | 10 | // Loop through all currently selected columns: 11 | foreach(var c in Selected.Columns) 12 | { 13 | var newMeasure = c.Table.AddMeasure( 14 | "Sum of " + c.Name, // Name 15 | "SUM(" + c.DaxObjectFullName + ")", // DAX expression 16 | c.DisplayFolder // Display Folder 17 | ); 18 | 19 | // Set the format string on the new measure: 20 | newMeasure.FormatString = "0.00"; 21 | 22 | // Provide some documentation: 23 | newMeasure.Description = "This measure is the sum of column " + c.DaxObjectFullName; 24 | 25 | // Hide the base column: 26 | c.IsHidden = true; 27 | } 28 | -------------------------------------------------------------------------------- /Basic/Create countrows measures.csx: -------------------------------------------------------------------------------- 1 | /* 2 | * Title: Auto-generate COUNTROWS measures from tables 3 | * 4 | * Author: Edgar Walther, twitter.com/edgarwalther 5 | * 6 | * This script, when executed, will loop through the currently selected tables, 7 | * creating one COUNTROWS measure for each table. 8 | */ 9 | 10 | // Loop through all currently selected tables: 11 | foreach(var table in Selected.Tables) { 12 | 13 | var newMeasure = table.AddMeasure( 14 | "# Rows in " + table.Name, // Name 15 | "COUNTROWS(" + table.DaxObjectFullName + ")" // DAX expression 16 | ); 17 | 18 | // Set the format string on the new measure: 19 | newMeasure.FormatString = "0"; 20 | 21 | // Provide some documentation: 22 | newMeasure.Description = "This measure is the number of rows in table " + table.DaxObjectFullName; 23 | 24 | } -------------------------------------------------------------------------------- /Basic/Format All Measures.csx: -------------------------------------------------------------------------------- 1 | /* 2 | * Title: Format All Measures 3 | * 4 | * Author: Matt Allington, https://exceleratorbi.com.au 5 | * 6 | * This script loops through all the measures in your model and calls out to daxformatter.com 7 | * in order to format them. 8 | * 9 | * CAUTION: If your model has many measures (> 100) please use with care, as this will perform 10 | * many requests against the www.daxformatter.com web service. It will take some time to run, 11 | * and also, we don't want to DDoS attack daxformatter.com :-) 12 | */ 13 | 14 | //Format All Measures 15 | foreach (var m in Model.AllMeasures) 16 | { 17 | m.Expression = FormatDax(m.Expression); 18 | /* Cycle over all measures in model and format 19 | them all using DAX Formatter */ 20 | } 21 | -------------------------------------------------------------------------------- /Basic/Hide columns on the many side of a relationship.csx: -------------------------------------------------------------------------------- 1 | /* 2 | * Title: Hide columns on the many side of a relationship 3 | * 4 | * Author: Matt Allington, https://exceleratorbi.com.au 5 | * 6 | * it is dangerous to use columns on the many side of a relationship as it can 7 | * produce unexpected results, so it is a best practice to hide these columns 8 | * to discourage their use in reports. 9 | */ 10 | 11 | // Hide all columns on many side of a join 12 | foreach (var r in Model.Relationships) 13 | { // hide all columns on the many side of a join 14 | var c = r.FromColumn.Name; 15 | var t = r.FromTable.Name; 16 | Model.Tables[t].Columns[c].IsHidden = true; 17 | } 18 | -------------------------------------------------------------------------------- /Basic/Move All Columns to a DisplayFolder.csx: -------------------------------------------------------------------------------- 1 | /* 2 | * Title: Move All Columns to a DisplayFolder 3 | * 4 | * Author: Matt Allington, https://exceleratorbi.com.au 5 | * 6 | * move all columns into a display folder. 7 | * read why at https://exceleratorbi.com.au/column-sub-folders-better-than-measure-sub-folders/ 8 | */ 9 | 10 | 11 | //Move all columns to display folder 12 | foreach (var c in Model.AllColumns) 13 | { 14 | c.DisplayFolder = "_Columns"; 15 | } 16 | -------------------------------------------------------------------------------- /Demos/FabCon 2025/AutoPopulateMeasureDescriptionsFromOpenAIWithDelay.csx: -------------------------------------------------------------------------------- 1 | #r "System.Net.Http" 2 | 3 | // --------------------------------------------------- 4 | // GENERATE MEASURE DESCRIPTIONS USING OPEN AI 5 | // --------------------------------------------------- 6 | // Original author: Darren Gosbell, 7 | // https://darren.gosbell.com/2023/02/automatically-generating-measure-descriptions-for-power-bi-and-analysis-services-with-chatgpt-and-tabular-editor/ 8 | // --------------------------------------------------- 9 | 10 | 11 | using System.Net.Http; 12 | using System.Text; 13 | using Newtonsoft.Json.Linq; 14 | 15 | // You need to signin to https://platform.openai.com/ and create an API key for your profile. Then, save the 16 | // API key as an environment variable with the name below, or simply paste it in: 17 | string apiKey = Environment.GetEnvironmentVariable("TE_OpenAI_APIKey"); 18 | // const string apiKey = ""; 19 | const string uri = "https://api.openai.com/v1/completions"; 20 | const string question = "Explain the following calculation in a few sentences in simple business terms without using DAX function names:\n\n"; 21 | 22 | const int oneMinute = 60000; // the number of milliseconds in a minute 23 | const int apiLimit = 20; // a free account is limited to 20 calls per minute, change this if you have a paid account 24 | const bool dontOverwrite = true; // this prevents existing descriptions from being overwritten 25 | 26 | using (var client = new HttpClient()) { 27 | client.DefaultRequestHeaders.Clear(); 28 | client.DefaultRequestHeaders.Add("Authorization", "Bearer " + apiKey); 29 | 30 | int callCount = 0; 31 | 32 | // if any measures are currently selected add those 33 | // to our collection 34 | List myMeasures = new List(); 35 | myMeasures.AddRange( Selected.Measures ); 36 | 37 | // if no measures were selected grab all of the 38 | // measures in the model 39 | if ( myMeasures.Count == 0) 40 | { 41 | myMeasures.AddRange(Model.Tables.Where(t => t.Measures.Count() > 0).SelectMany(t => t.Measures)); 42 | } 43 | 44 | 45 | foreach ( var m in myMeasures) 46 | { 47 | // if we are not overwriting existing descriptions then skip to the 48 | // next measure if this one is not an empty string 49 | if (dontOverwrite && !string.IsNullOrEmpty(m.Description)) {continue; } 50 | 51 | // Only uncomment the following when running from the command line or the script will 52 | // show a popup after each measure 53 | //Info("Processing " + m.DaxObjectFullName) 54 | //var body = new requestBody() { prompt = question + m.Expression }; 55 | var body = 56 | "{ \"prompt\": " + JsonConvert.SerializeObject(question + m.Expression ) + 57 | ",\"model\": \"gpt-3.5-turbo-instruct\" " + 58 | ",\"temperature\": 1 " + 59 | ",\"max_tokens\": 2048 " + 60 | ",\"stop\": \".\" }"; 61 | 62 | var res = client.PostAsync(uri, new StringContent(body, Encoding.UTF8,"application/json")); 63 | res.Result.EnsureSuccessStatusCode(); 64 | var result = res.Result.Content.ReadAsStringAsync().Result; 65 | var obj = JObject.Parse(result); 66 | var desc = obj["choices"][0]["text"].ToString().Trim(); 67 | m.Description = desc + "\n=====\n" + m.Expression; 68 | 69 | callCount++; // increment the call count 70 | if ( callCount % apiLimit == 0) System.Threading.Thread.Sleep( oneMinute ); 71 | 72 | } 73 | } -------------------------------------------------------------------------------- /Demos/FabCon 2025/CheckReportsForInvalidObjectRefs.csx: -------------------------------------------------------------------------------- 1 | // =========================================== 2 | // Check reports for invalid object references 3 | // =========================================== 4 | // Author: Daniel Otykier, github.com/otykier 5 | // 6 | // Requirements: 7 | // Tabular Editor 2 v. 2.26.0 or newer 8 | // Tabular Eidtor 3 v. 3.21.0 or newer 9 | // 10 | // Script usage: 11 | // [x] Command line 12 | // [x] Interactive (model scope) 13 | // 14 | // Description: 15 | // This script can be used to check Power BI report files using the Enhanced PBIR format for 16 | // invalid measure references against the currently loaded semantic model. You can run the 17 | // script interactively (i.e. from TE2/TE3 UI), or from a command line. 18 | // 19 | // When the current model in Tabular Editor is loaded from a Power BI Project (PBIP) folder 20 | // structure, the script will automatically locate any reports in the workspace folder, that 21 | // point to the current model (by examining the definition.pbir file in each - note, this 22 | // file must specify a datasetReference "by path", for this to work). 23 | // 24 | // Alternatively, the script (in interactive mode) will prompt for the root of the workspace 25 | // folder of reports to scan. In command line mode, you can also specify this root folder 26 | // by setting an environment variable with the name: TE_WSFolder 27 | // 28 | // In command line mode, the script will output Warning messages (loglevel=warning) for each 29 | // invalid reference found. In interactive mode, the script will show a summary of issues 30 | // after scanning all report files. 31 | // 32 | // See also: 33 | // https://learn.microsoft.com/en-us/power-bi/developer/projects/projects-report#pbir-format 34 | // https://learn.microsoft.com/en-us/power-bi/developer/projects/projects-report#definitionpbir 35 | 36 | using System.IO; 37 | using System.Windows.Forms; 38 | using Newtonsoft.Json.Linq; 39 | 40 | string pbipModelName = null; 41 | string rootFolder = null; 42 | 43 | // Hack to determine if the script is running in command line mode or not: 44 | var commandLineMode = Application.OpenForms.Count == 0; 45 | var result = string.Empty; 46 | var issues = 0; 47 | 48 | rootFolder = Environment.GetEnvironmentVariable("TE_WSFolder"); 49 | 50 | if (rootFolder == null && Model.MetadataSource.Pbip == null) 51 | { 52 | if(commandLineMode) 53 | { 54 | Error("Could not determine workspace folder. Set environment variable TE_WSFolder before running this script.", 0, true); 55 | return; 56 | } 57 | Info("Model not loaded from PBIP folder structure. Script will assume all scanned reports use this model."); 58 | } 59 | else 60 | { 61 | // Find all report folders that point to the current model: 62 | pbipModelName = Model.MetadataSource.Pbip.Name; 63 | rootFolder = Model.MetadataSource.Pbip.RootFolder; 64 | } 65 | 66 | // Cache measures by name just to speed up checks: 67 | var measureCache = Model.AllMeasures.ToDictionary(m => m.Name, m => m, StringComparer.OrdinalIgnoreCase); 68 | 69 | // Prompt user for workspace folder if we couldn't determine it from the model location: 70 | if (rootFolder == null) 71 | { 72 | var fbd = new FolderBrowserDialog() { 73 | Description = "Select workspace folder to scan for Power BI report items", 74 | #if TE3 75 | UseDescriptionForTitle = true 76 | #endif 77 | }; 78 | if(fbd.ShowDialog() == DialogResult.Cancel) return; 79 | rootFolder = fbd.SelectedPath; 80 | } 81 | 82 | // ------------- Define a few helper functions ---------------- 83 | 84 | Func ValidReportDefinition = (string reportDefinitionFilePath) => 85 | { 86 | var definitionJson = File.ReadAllText(reportDefinitionFilePath); 87 | return (pbipModelName == null || definitionJson.Contains(pbipModelName)) && definitionJson.Contains("4.0"); 88 | }; 89 | 90 | Action OutputError = (string errorMessage, string jsonFileName, JToken token) => 91 | { 92 | var fileDetails = "in " + jsonFileName + " (line " + (token as IJsonLineInfo).LineNumber + ")"; 93 | if(commandLineMode) 94 | { 95 | Error(errorMessage + " " + fileDetails + " " + token.Path, 0, true); 96 | } 97 | else 98 | { 99 | result += " " + errorMessage + Environment.NewLine; 100 | result += " " + fileDetails + Environment.NewLine; 101 | result += " " + token.Path + Environment.NewLine; 102 | } 103 | issues++; 104 | }; 105 | 106 | Action CheckMeasureRef = (string file, JValue measureRef) => 107 | { 108 | // Check if the provided JValue 109 | var parentObj = measureRef.Parent.Parent as JObject; 110 | var sourceRefObj = parentObj.SelectToken("Expression.SourceRef") as JObject; 111 | // This means that the measure is a report-level measure, so we don't need to check if it exists in the model: 112 | if(sourceRefObj.ContainsKey("Schema") && sourceRefObj["Schema"].ToString() == "extension") return; 113 | 114 | var tableRef = sourceRefObj["Entity"]; 115 | var tableName = tableRef.ToString(); 116 | var measureName = measureRef.ToString(); 117 | Measure measure; 118 | if(!measureCache.TryGetValue(measureName, out measure)) 119 | { 120 | OutputError(string.Format("Measure not found: [{0}]", measureName), file, measureRef); 121 | return; 122 | } 123 | else if(!measure.Table.Name.EqualsI(tableName)) 124 | { 125 | OutputError(string.Format("Measure [{0}] not found on table '{1}', actual table: '{2}'", measureName, tableName, measure.Table.Name), file, tableRef); 126 | } 127 | }; 128 | 129 | Action ScanReport = (string reportFolder) => 130 | { 131 | if(commandLineMode) 132 | Info("Scanning " + reportFolder + "..."); 133 | else 134 | result += "Scanning " + reportFolder + "..." + Environment.NewLine; 135 | 136 | // Loop through all visual json files in the folder structure, to find invalid semantic model object refs: 137 | foreach(var jsonFile in Directory.EnumerateFiles(Path.Combine(reportFolder, "definition"), "*.json", SearchOption.AllDirectories)) 138 | { 139 | var parsed = JObject.Parse(File.ReadAllText(jsonFile)); 140 | var measureRefs = parsed.SelectTokens("$..Measure.Property").OfType(); 141 | foreach(var measureRef in measureRefs) CheckMeasureRef(jsonFile.Substring(rootFolder.Length), measureRef); 142 | } 143 | }; 144 | // ---------------------------------------------- 145 | 146 | var reportFolders = Directory.EnumerateFiles(rootFolder, "definition.pbir", SearchOption.AllDirectories) 147 | .Where(ValidReportDefinition) 148 | .Select(f => new FileInfo(f).Directory.FullName).ToList(); 149 | 150 | // Loop through all report folders and check each: 151 | foreach(var reportFolder in reportFolders) ScanReport(reportFolder); 152 | 153 | if(!commandLineMode) 154 | { 155 | result += Environment.NewLine + "Issues found: " + issues; 156 | result.Output(); 157 | } 158 | else 159 | { 160 | if(issues == 0) Info("No issues found!"); 161 | else Warning("Issues found: " + issues, 0, true); 162 | } -------------------------------------------------------------------------------- /Demos/FabCon 2025/SemanticModelValidationPipeline.yaml: -------------------------------------------------------------------------------- 1 | trigger: none 2 | 3 | pool: 4 | vmimage: 'windows-latest' 5 | 6 | stages: 7 | - stage: Build 8 | jobs: 9 | 10 | - job: Build_Datasets 11 | steps: 12 | - checkout: self 13 | path: 'self' 14 | - task: PowerShell@2 15 | displayName: 'Download Tabular Editor and Default Rules' 16 | inputs: 17 | targetType: inline 18 | script: | 19 | $path = "$(Build.SourcesDirectory)" 20 | $tempPath = "$path\_temp" 21 | $toolPath = "$path\_tools\TE" 22 | New-Item -ItemType Directory -Path $tempPath -ErrorAction SilentlyContinue | Out-Null 23 | 24 | Write-Host "##[debug]Downloading Tabular Editor binaries" 25 | $downloadUrl = "https://github.com/TabularEditor/TabularEditor/releases/latest/download/TabularEditor.Portable.zip" 26 | $zipFile = "$tempPath\TabularEditor.zip" 27 | Invoke-WebRequest -Uri $downloadUrl -OutFile $zipFile 28 | Expand-Archive -Path $zipFile -DestinationPath $toolPath -Force 29 | 30 | Write-Host "##[debug]Downloading Dataset default rules" 31 | $downloadUrl = "https://raw.githubusercontent.com/microsoft/Analysis-Services/master/BestPracticeRules/BPARules.json" 32 | Invoke-WebRequest -Uri $downloadUrl -OutFile "$tempPath\Rules-Dataset.json" 33 | - task: PowerShell@2 34 | displayName: 'Check invalid object refs' 35 | inputs: 36 | targetType: inline 37 | script: | 38 | $path = "$(Build.SourcesDirectory)" 39 | $tempPath = "$path\_temp" 40 | $toolPath = "$path\_Tools\TE\TabularEditor.exe" 41 | $scriptPath = "$path\scripts\CheckReportsForInvalidObjectRefs.csx" 42 | 43 | $itemsFolders = Get-ChildItem -Path $path -recurse -include definition.pbism 44 | foreach($itemFolder in $itemsFolders) 45 | { 46 | $itemPath = "$($itemFolder.Directory.FullName)\definition\database.tmdl" 47 | Write-Host "##[group]Running invalid object ref check for reports pointing to: '$itemPath'" 48 | Start-Process -FilePath "$toolPath" -ArgumentList """$itemPath"" -s ""$scriptPath"" -V" -NoNewWindow -Wait 49 | Write-Host "##[endgroup]" 50 | } 51 | - task: PowerShell@2 52 | displayName: 'Run Best Practice Analyzer' 53 | inputs: 54 | targetType: inline 55 | script: | 56 | $path = "$(Build.SourcesDirectory)" 57 | $tempPath = "$path\_temp" 58 | $toolPath = "$path\_Tools\TE\TabularEditor.exe" 59 | $rulesPath = "$path\Rules-Dataset.json" 60 | 61 | if (!(Test-Path $rulesPath)) 62 | { 63 | Write-Host "Running downloaded rules" 64 | $rulesPath = "$tempPath\Rules-Dataset.json" 65 | } 66 | 67 | $itemsFolders = Get-ChildItem -Path $path -recurse -include definition.pbism 68 | foreach($itemFolder in $itemsFolders) 69 | { 70 | $itemPath = "$($itemFolder.Directory.FullName)\definition\database.tmdl" 71 | Write-Host "##[group]Running rules for: '$itemPath'" 72 | Start-Process -FilePath "$toolPath" -ArgumentList """$itemPath"" -A ""$rulesPath"" -V" -NoNewWindow -Wait 73 | Write-Host "##[endgroup]" 74 | } -------------------------------------------------------------------------------- /Demos/FabCon 2025/Ultimate productivity.pptx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/TabularEditor/Scripts/d1787144cb3d42b3d228f1a1f2921eba57b32656/Demos/FabCon 2025/Ultimate productivity.pptx -------------------------------------------------------------------------------- /Intermediate/Clean object names.csx: -------------------------------------------------------------------------------- 1 | #r "System.Text.RegularExpressions" 2 | 3 | /* 4 | * Title: Clean Object Names 5 | * 6 | * Author: Darren Gosbell, twitter.com/DarrenGosbell 7 | * 8 | * This script, when executed, will loop through your model and update the 9 | * names of any tables and columns with CamelCaseNames and insert spaces before upper 10 | * case characters so you end up with 11 | * 12 | * before: CalendarYearNum 13 | * after: Calendar Year Num 14 | * 15 | * This script ignores any columns that already have spaces in the names 16 | * and any hidden columns. It also skips adjacent upper case characters 17 | * so "MyTXTColumn" becomes "My TXT Column" 18 | */ 19 | 20 | // this regular expression splits strings on underscores and changes from lower to upper case 21 | // so "my_column_name" becomes an array like {"my", "_", "column", "_", "name"} 22 | // and "MyOtherColumnName" becomes an array like {"My", "Other", "Column", "Name"} 23 | var rex = new System.Text.RegularExpressions.Regex( "(^[a-z]+|[A-Z]+(?![a-z])|[A-Z][a-z]+|[^A-Z,a-z]+|[_]|[a-z]+)"); 24 | 25 | // if any of the following are the first word of a table name they will be stripped out 26 | List tablePrefixesToIgnore = new List() {"dim","fact", "vw","tbl","vd","td","tf","vf"}; 27 | 28 | // if any of the following ar ethe last word of a table name they will be stripped out 29 | List tableSuffixesToIgnore = new List() {"dim", "fact"}; 30 | 31 | foreach (var tbl in Model.Tables) 32 | { 33 | if (!tbl.IsHidden && !tbl.Name.Contains(" ")) 34 | { 35 | string name = tbl.Name; 36 | var matches = rex.Matches(name); 37 | var firstWord = matches[0]; 38 | var lastWord = matches[matches.Count-1]; 39 | string[] words = matches 40 | .OfType() 41 | .Where(m => 42 | // skip words that are just underscores so that they are replaced with spaces 43 | m.Value != "_" 44 | // skip the first word if it matches one of the prefixes to ignore 45 | && !(m == firstWord && tablePrefixesToIgnore.Contains(m.Value,System.StringComparer.OrdinalIgnoreCase)) 46 | // skip the last word if it matches one of the suffixes to ignore 47 | && !(m == lastWord && tableSuffixesToIgnore.Contains(m.Value,System.StringComparer.OrdinalIgnoreCase )) 48 | ) 49 | .Select(m => char.ToUpper(m.Value.First()) + m.Value.Substring(1)) 50 | .ToArray(); 51 | string result = string.Join(" ", words); 52 | tbl.Name = result; 53 | } 54 | 55 | foreach (var col in tbl.Columns) 56 | { 57 | if (!col.IsHidden && !col.Name.Contains(" ")) 58 | { 59 | string name = col.Name; 60 | string[] words = rex.Matches(name) 61 | .OfType() 62 | // skip underscores 63 | .Where(m => m.Value != "_" ) 64 | .Select(m => char.ToUpper(m.Value.First()) + m.Value.Substring(1)) 65 | .ToArray(); 66 | string result = string.Join(" ", words); 67 | col.Name = result; 68 | } 69 | } 70 | } -------------------------------------------------------------------------------- /Intermediate/Create Time Intelligence Measures Using Calculation Groups.csx: -------------------------------------------------------------------------------- 1 | /* 2 | * Generate time intelligence measures based on calculation group items alredy created 3 | * 4 | * Author: Benoit Fedit, https://datakuity.com/ 5 | * 6 | * You must have created the calculation group items beforehand (see link below) 7 | * https://docs.microsoft.com/en-us/analysis-services/tabular-models/calculation-groups?view=asallproducts-allversions 8 | * To add more measure simply copy/paste the YTD script and replace YTD by your calculation item name 9 | */ 10 | 11 | 12 | // For each selected measure create MOM; MOM%, PM, PQ, MTD, QTD, YTD, PY, PY MTD, PY QTD, PY YTD, QOQ, QOQ%, YOY, YOY% measures 13 | foreach(var m in Selected.Measures) { 14 | 15 | // MTD 16 | m.Table.AddMeasure( 17 | m.Name + " MTD", // Name 18 | "Calculate(" + m.DaxObjectName + ", 'Time Intelligence'[Time Calculation]=\"MTD\")", 19 | m.DisplayFolder // Display Folder 20 | ); 21 | 22 | // MOM 23 | m.Table.AddMeasure( 24 | m.Name + " MOM", // Name 25 | "Calculate(" + m.DaxObjectName + ", 'Time Intelligence'[Time Calculation]=\"MOM\")", 26 | m.DisplayFolder // Display Folder 27 | ); 28 | 29 | // MOM% 30 | m.Table.AddMeasure( 31 | m.Name + " MOM%", // Name 32 | "Calculate(" + m.DaxObjectName + ", 'Time Intelligence'[Time Calculation]=\"MOM%\")", 33 | m.DisplayFolder // Display Folder 34 | ).FormatString = "0.0 %"; 35 | 36 | // PM 37 | m.Table.AddMeasure( 38 | m.Name + " PM", // Name 39 | "Calculate(" + m.DaxObjectName + ", 'Time Intelligence'[Time Calculation]=\"PM\")", 40 | m.DisplayFolder // Display Folder 41 | ); 42 | 43 | // PQ 44 | m.Table.AddMeasure( 45 | m.Name + " PQ", // Name 46 | "Calculate(" + m.DaxObjectName + ", 'Time Intelligence'[Time Calculation]=\"PQ\")", 47 | m.DisplayFolder // Display Folder 48 | ); 49 | 50 | // QTD 51 | m.Table.AddMeasure( 52 | m.Name + " QTD", // Name 53 | "Calculate(" + m.DaxObjectName + ", 'Time Intelligence'[Time Calculation]=\"QTD\")", 54 | m.DisplayFolder // Display Folder 55 | ); 56 | 57 | // YTD 58 | m.Table.AddMeasure( 59 | m.Name + " YTD", // Name 60 | "Calculate(" + m.DaxObjectName + ", 'Time Intelligence'[Time Calculation]=\"YTD\")", 61 | m.DisplayFolder // Display Folder 62 | ); 63 | 64 | // PY 65 | m.Table.AddMeasure( 66 | m.Name + " PY", // Name 67 | "Calculate(" + m.DaxObjectName + ", 'Time Intelligence'[Time Calculation]=\"PY\")", 68 | m.DisplayFolder // Display Folder 69 | ); 70 | 71 | // PY MTD 72 | m.Table.AddMeasure( 73 | m.Name + " PY MTD", // Name 74 | "Calculate(" + m.DaxObjectName + ", 'Time Intelligence'[Time Calculation]=\"PY MTD\")", 75 | m.DisplayFolder // Display Folder 76 | ); 77 | 78 | // PY QTD 79 | m.Table.AddMeasure( 80 | m.Name + " PY QTD", // Name 81 | "Calculate(" + m.DaxObjectName + ", 'Time Intelligence'[Time Calculation]=\"PY QTD\")", 82 | m.DisplayFolder // Display Folder 83 | ); 84 | 85 | // PY YTD 86 | m.Table.AddMeasure( 87 | m.Name + " PY YTD", // Name 88 | "Calculate(" + m.DaxObjectName + ", 'Time Intelligence'[Time Calculation]=\"PY YTD\")", 89 | m.DisplayFolder // Display Folder 90 | ); 91 | 92 | // YOY 93 | m.Table.AddMeasure( 94 | m.Name + " YOY", // Name 95 | "Calculate(" + m.DaxObjectName + ", 'Time Intelligence'[Time Calculation]=\"YOY\")", 96 | m.DisplayFolder // Display Folder 97 | ); 98 | 99 | // QOQ 100 | m.Table.AddMeasure( 101 | m.Name + " QOQ", // Name 102 | "Calculate(" + m.DaxObjectName + ", 'Time Intelligence'[Time Calculation]=\"QOQ\")", 103 | m.DisplayFolder // Display Folder 104 | ); 105 | 106 | // YOY% 107 | m.Table.AddMeasure( 108 | m.Name + " YOY%", // Name 109 | "Calculate(" + m.DaxObjectName + ", 'Time Intelligence'[Time Calculation]=\"YOY%\")", 110 | m.DisplayFolder // Display Folder 111 | ).FormatString = "0.0 %"; 112 | 113 | // QOQ% 114 | m.Table.AddMeasure( 115 | m.Name + " QOQ%", // Name 116 | "Calculate(" + m.DaxObjectName + ", 'Time Intelligence'[Time Calculation]=\"QOQ%\")", 117 | m.DisplayFolder // Display Folder 118 | ).FormatString = "0.0 %"; 119 | } 120 | -------------------------------------------------------------------------------- /Intermediate/CreateExplicitMeasures.csx: -------------------------------------------------------------------------------- 1 | // Title: Auto-create explicit measures from all columns in all tables that have qualifying aggregation functions assigned 2 | // 3 | // Author: Tom Martens, twitter.com/tommartens68 4 | // 5 | // This script, when executed, will loop through all the tables and creates explicit measure for all the columns with qualifying 6 | // aggregation functions. 7 | // The qualifiyng aggregation functions are SUM, COUNT, MIN, MAX, AVERAGE. 8 | // This script can create a lot of measures, as by default the aggregation function for columns with a numeric data type is SUM. 9 | // So, it is a good idea to check all columns for the proper aggregation type, e.g. the aggregation type of id columns 10 | // should be set to None, as it does not make any sense to aggregate id columns. 11 | // An annotation:CreatedThrough is created with a value:CreateExplicitMeasures this will help to identify the measures createed 12 | // using this script. 13 | // What is missing, the list below shows what might be coming in subsequent iterations of the script: 14 | // - the base column property hidden is not set to true 15 | // - no black list is used to prevent the creation of unwanted measures 16 | 17 | // *************************************************************************************************************** 18 | //the following variables are allowing controling the script 19 | var overwriteExistingMeasures = 0; // 1 overwrites existing measures, 0 preserves existing measures 20 | 21 | var measureNameTemplate = "{0} ({1}) - {2}"; // String.Format is used to create the measure name. 22 | //{0} will be replaced with the columnname (c.Name), {1} will be replaced with the aggregation function, and last but not least 23 | //{2} will be replaced with the tablename (t.Name). Using t.Name is necessary to create a distinction between measure names if 24 | //columns with the same name exist in different tables. 25 | //Assuming the column name inside the table "Fact Sale" is "Sales revenue" and the aggregation function is SUM 26 | //the measure name will be: "Sales revenue (Sum) - Fact Sale" 27 | 28 | //store aggregation function that qualify for measure creation to the hashset aggFunctions 29 | var aggFunctions = new HashSet{ 30 | AggregateFunction.Default, //remove this line, if you do not want to mess up your measures list by automatically created measures for all the columns that have the Default AggregateFunction assigned 31 | AggregateFunction.Sum, 32 | AggregateFunction.Count, 33 | AggregateFunction.Min, 34 | AggregateFunction.Max, 35 | AggregateFunction.Average 36 | }; 37 | 38 | //You have to be aware that by default this script will just create measures using the aggregate functions "Sum" or "Count" if 39 | //the column has the aggregate function AggregateFunction.Default assigned, this is checked further down below. 40 | //Also, if a column has the Default AggregateFunction assigned and is of the DataType 41 | //DataType.Automatic, DataType.Unknown, or DataType.Variant, no measure is created automatically, this is checked further down below. 42 | //dictDataTypeAggregateFunction = new Dictionary(); 43 | //see this article for all the available data types: https://docs.microsoft.com/en-us/dotnet/api/microsoft.analysisservices.tabular.datatype?view=analysisservices-dotnet 44 | //Of course you can change the aggregation function that will be used for different data types, 45 | //as long as you are using "Sum" and "Count" 46 | //Please be careful, if you change the aggregation function you might end up with multiplemeasures 47 | var dictDataTypeAggregateFunction = new Dictionary(); 48 | dictDataTypeAggregateFunction.Add( DataType.Binary , AggregateFunction.Count ); //adding a key/value pair(s) to the dictionary using the Add() method 49 | dictDataTypeAggregateFunction.Add( DataType.Boolean , AggregateFunction.Count ); 50 | dictDataTypeAggregateFunction.Add( DataType.DateTime , AggregateFunction.Count ); 51 | dictDataTypeAggregateFunction.Add( DataType.Decimal , AggregateFunction.Sum ); 52 | dictDataTypeAggregateFunction.Add( DataType.Double , AggregateFunction.Sum ); 53 | dictDataTypeAggregateFunction.Add( DataType.Int64 , AggregateFunction.Sum ); 54 | dictDataTypeAggregateFunction.Add( DataType.String , AggregateFunction.Count ); 55 | 56 | // *************************************************************************************************************** 57 | //all the stuff below this line should not be altered 58 | //of course this is not valid if you have to fix my errors, make the code more efficient, 59 | //or you have a thorough understanding of what you are doing 60 | 61 | //store all the existing measures to the list listOfMeasures 62 | var listOfMeasures = new List(); 63 | foreach( var m in Model.AllMeasures ) { 64 | listOfMeasures.Add( m.Name ); 65 | } 66 | 67 | //loop across all tables 68 | foreach( var t in Model.Tables ) { 69 | 70 | //loop across all columns of the current table t 71 | foreach( var c in t.Columns ) { 72 | 73 | var currAggFunction = c.SummarizeBy; //cache the aggregation function of the current column c 74 | var useAggFunction = AggregateFunction.Sum; 75 | var theMeasureName = ""; // Name of the new Measure 76 | var posInListOfMeasures = 0; //check if the new measure already exists <> -1 77 | 78 | if( aggFunctions.Contains(currAggFunction) ) //check if the current aggregation function qualifies for measure aggregation 79 | { 80 | //check if the current aggregation function is Default 81 | if( currAggFunction == AggregateFunction.Default ) 82 | { 83 | // check if the datatype of the column is considered for measure creation 84 | if( dictDataTypeAggregateFunction.ContainsKey( c.DataType ) ) 85 | { 86 | 87 | //some kind of sanity check 88 | if( c.DataType == DataType.Automatic || c.DataType == DataType.Unknown || c.DataType == DataType.Variant ) 89 | { 90 | Output("No measure will be created for columns with the data type: " + c.DataType.ToString() + " (" + c.DaxObjectFullName + ")"); 91 | continue; //moves to the next item in the foreach loop, the next colum in the current table 92 | } 93 | 94 | //cache the aggregation function from the dictDataTypeAggregateFunction 95 | useAggFunction = dictDataTypeAggregateFunction[ c.DataType ]; 96 | 97 | //some kind of sanity check 98 | if( useAggFunction != AggregateFunction.Count && useAggFunction != AggregateFunction.Sum ) 99 | { 100 | Output("No measure will be created for the column: " + c.DaxObjectFullName); 101 | continue; //moves to the next item in the foreach loop, the next colum in the current table 102 | } 103 | theMeasureName = String.Format( measureNameTemplate , c.Name , useAggFunction.ToString() , t.Name ); // Name of the new Measure 104 | posInListOfMeasures = listOfMeasures.IndexOf( theMeasureName ); //check if the new measure already exists <> -1 105 | 106 | } else { 107 | 108 | continue; //moves to the next item in the foreach loop, the next colum in the current table 109 | } 110 | 111 | } else { 112 | 113 | useAggFunction = currAggFunction; 114 | theMeasureName = String.Format( measureNameTemplate , c.Name , useAggFunction.ToString() , t.Name ); // Name of the new Measure 115 | posInListOfMeasures = listOfMeasures.IndexOf( theMeasureName ); //check if the new measure already exists <> -1 116 | 117 | } 118 | 119 | //sanity check 120 | if(theMeasureName == "") 121 | { 122 | continue; //moves to the next item in the foreach loop, the next colum in the current table 123 | } 124 | 125 | // create the measure 126 | if( ( posInListOfMeasures == -1 || overwriteExistingMeasures == 1 )) 127 | { 128 | if( overwriteExistingMeasures == 1 ) 129 | { 130 | foreach( var m in Model.AllMeasures.Where( m => m.Name == theMeasureName ).ToList() ) 131 | { 132 | m.Delete(); 133 | } 134 | } 135 | 136 | var newMeasure = t.AddMeasure 137 | ( 138 | theMeasureName // Name of the new Measure 139 | , "" + useAggFunction.ToString().ToUpper() + "(" + c.DaxObjectFullName + ")" // DAX expression 140 | ); 141 | 142 | newMeasure.SetAnnotation( "CreatedThrough" , "CreateExplicitMeasures" ); // flag the measures created throught this script 143 | 144 | } 145 | } 146 | } 147 | } -------------------------------------------------------------------------------- /Intermediate/Dynamic measure selector.csx: -------------------------------------------------------------------------------- 1 | /* 2 | * Title: Dynamic measure selector 3 | * 4 | * Author: Daniel Otykier, twitter.com/DOtykier 5 | * 6 | * Use this script to auto-generate a disconnected measure selector table 7 | * along with a single SWITCH measure, for a selection of measures. 8 | * More info: https://tabulareditor.com/2020/08/24/Generating-a-dynamic-measure-selector.html 9 | */ 10 | 11 | // (1) Name of disconnected selector table: 12 | var selectorTableName = "Measure Selector"; 13 | 14 | // (2) Name of column on selector table: 15 | var selectorTableColumnName = "Measure"; 16 | 17 | // (3) Name of dynamic switch measure: 18 | var dynamicMeasureName = "Dynamic Measure"; 19 | 20 | // (4) Name of dynamic switch measure's parent table: 21 | var dynamicMeasureTableName = "Measure Selector"; 22 | 23 | // (5) Fallback DAX expression: 24 | var fallbackDax = "BLANK()"; 25 | 26 | // ----- Do not modify script below this line ----- 27 | 28 | if(Selected.Measures.Count == 0) { 29 | Error("Select one or more measures"); 30 | return; 31 | } 32 | 33 | // Get or create selector table: 34 | CalculatedTable selectorTable; 35 | if(!Model.Tables.Contains(selectorTableName)) Model.AddCalculatedTable(selectorTableName); 36 | selectorTable = Model.Tables[selectorTableName] as CalculatedTable; 37 | 38 | // Get or create dynamic measure: 39 | Measure dynamicMeasure; 40 | if(!Model.Tables[dynamicMeasureTableName].Measures.Contains(dynamicMeasureName)) 41 | Model.Tables[dynamicMeasureTableName].AddMeasure(dynamicMeasureName); 42 | dynamicMeasure = Model.Tables[dynamicMeasureTableName].Measures[dynamicMeasureName]; 43 | 44 | // Generate DAX for disconnected table: 45 | // SELECTCOLUMNS({"Measure 1", "Measure 2", ...}, "Measure", [Value]) 46 | var selectorTableDax = "SELECTCOLUMNS(\n {\n " + 47 | string.Join(",\n ", Selected.Measures.Select(m => "\"" + m.Name + "\"").ToArray()) + 48 | "\n },\n \"" + selectorTableColumnName + "\", [Value]\n)"; 49 | 50 | // Generate DAX for dynamic metric: 51 | // VAR _s = SELECTEDVALUE('Metric Selection'[Value]) RETURN SWITCH(_s, ...) 52 | var dynamicMeasureDax = 53 | "VAR _s =\n SELECTEDVALUE('" + selectorTableName + "'[" + selectorTableColumnName + "])\n" + 54 | "RETURN\n SWITCH(\n _s,\n " + 55 | string.Join(",\n ", Selected.Measures.Select(m => "\"" + m.Name + "\", " + m.DaxObjectFullName).ToArray()) + 56 | ",\n " + fallbackDax + "\n )"; 57 | 58 | // Assign DAX expressions: 59 | selectorTable.Expression = selectorTableDax; 60 | dynamicMeasure.Expression = dynamicMeasureDax; -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2020 Tabular Editor 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Scripts 2 | Community repository for sharing and discussing scripts for use with Tabular Editor. 3 | 4 | ## Using scripts from this repository 5 | If you'd like to use a script from this repository, simply copy the script content into the Advanced Scripting pane of Tabular Editor. For more details about scripting, [read this article](https://github.com/otykier/TabularEditor/wiki/Advanced-Scripting). You may also [store scripts as Custom Actions](https://github.com/otykier/TabularEditor/wiki/Custom-Actions) that are integrated in Tabular Editor's UI. 6 | 7 | **DISCLAIMER:** THE SCRIPTS IN THIS REPOSITORY ARE PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND. You are responsible for ensuring that any scripts you execute does not contain malicious code, or does not cause unwanted changes to your tabular models. If you do not understand what the code does, do not blindly execute it! A script has access to the full power of the .NET platform, meaning it can theoretically alter system files, download stuff from the internet, etc. Do not execute a script from sources you do not trust. 8 | 9 | ## How to contribute 10 | Fork the repo, add your scripts and submit a pull request - it's that simple! 11 | 12 | Scripts should use the `.csx` file extension. If you plan to submit a collection of multiple scripts, feel free to put them into a subfolder and provide a `README.md` file with additional documentation. 13 | 14 | Please ensure that your script is thoroughly documented with a comment section at the top of the file. Feel free to use the following snippet as a template: 15 | 16 | ```csharp 17 | /* 18 | * Title: Auto-generate SUM measures from columns 19 | * 20 | * Author: Daniel Otykier, twitter.com/DOtykier 21 | * 22 | * This script, when executed, will loop through the currently selected columns, 23 | * creating one SUM measure for each column and also hiding the column itself. 24 | */ 25 | 26 | // Loop through all currently selected columns: 27 | foreach(var c in Selected.Columns) 28 | { 29 | var newMeasure = c.Table.AddMeasure( 30 | "Sum of " + c.Name, // Name 31 | "SUM(" + c.DaxObjectFullName + ")", // DAX expression 32 | c.DisplayFolder // Display Folder 33 | ); 34 | 35 | // Set the format string on the new measure: 36 | newMeasure.FormatString = "0.00"; 37 | 38 | // Provide some documentation: 39 | newMeasure.Description = "This measure is the sum of column " + c.DaxObjectFullName; 40 | 41 | // Hide the base column: 42 | c.IsHidden = true; 43 | } 44 | ``` 45 | --------------------------------------------------------------------------------