-
Notifications
You must be signed in to change notification settings - Fork 0
/
Tabular Editor - Time Intelligence Pattern C# Script
203 lines (176 loc) · 7.4 KB
/
Tabular Editor - Time Intelligence Pattern C# Script
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
/*
* Generate time intelligence measures based
*
* Modified by: Reid Havens, https://havensconsulting.net
* Original Author(s): Benoit Fedit, https://datakuity.com
* Original Author(s): Bernat Agulló, www.esbrina-ba.com/blog
*
*/
// Creates popup promots to select the calendar table, and date column, to then dynamically update the scripts below
var CalendarTable = SelectTable(label: "Select your calendar table");
if(CalendarTable == null) return;
var CalendarTableDateColumn = SelectColumn(CalendarTable.Columns, label: "Select the date key column");
if(CalendarTableDateColumn == null) return;
var FactTable = SelectTable(label: "Select fact table with latest record date column");
if(FactTable == null) return;
var FactTableDateColumn = SelectColumn(FactTable.Columns, label: "Select fact table date column for the latest records");
if(FactTableDateColumn == null) return;
string CalendarTableName = CalendarTable.Name;
string CalendarTableDateColumnName = CalendarTableDateColumn.Name;
//Strings used for Dates with Transactions Flag Column
string FactTableName = FactTable.Name;
string FactTableDateColumnName = FactTableDateColumn.Name;
string dateWithSalesColumnName = "Dates With " + FactTable.Name + " Flag";
string dateWithSalesWithTable = "'" + CalendarTableName + "'[" + dateWithSalesColumnName + "]";
// Creates has transaction flag column on the calender table
if (!Model.Tables[CalendarTableName].Columns.Any(C => C.GetAnnotation("@AgulloBernat") == "Date with Data Column"))
{
string DateWithSalesCalculatedColumnExpression =
"'" + CalendarTableName + "'[" + CalendarTableDateColumnName + "] <= MAX ( '" + FactTableName + "'[" + FactTableDateColumnName + "])";
Column dateWithDataColumn = CalendarTable.AddCalculatedColumn(dateWithSalesColumnName, DateWithSalesCalculatedColumnExpression);
dateWithDataColumn.SetAnnotation("@AgulloBernat", "Date with Data Column");
};
// Creates input box for fiscal year end date
var FiscalYearEndDate = Microsoft.VisualBasic.Interaction.InputBox("Provide your fiscal year end date. E.g. 6/30/2024", "Fiscal Year End Date", "6/30/2024", 0, 0);
// For each selected measure create YTY, PY, PY YTD, YOY, YOY% measures
foreach(var m in Selected.Measures) {
// YTD
m.Table.AddMeasure(
m.Name + " YTD", // Name
"CALCULATE( "
+ m.DaxObjectName + "," +
" DATESYTD( '" + CalendarTableName + "'[" + CalendarTableDateColumnName + "] ), " +
"'" + CalendarTableName + "'[" + dateWithSalesColumnName + "] = TRUE() )",
".Time Intelligence\\" + m.Name // Display Folder
);
// PY
m.Table.AddMeasure(
m.Name + " PY", // Name
"CALCULATE(" +
" " + m.DaxObjectName + "," +
" DATEADD( '" + CalendarTableName + "'[" + CalendarTableDateColumnName + "], -1, YEAR ), " +
"'" + CalendarTableName + "'[" + dateWithSalesColumnName + "] = TRUE() )",
".Time Intelligence\\" + m.Name // Display Folder
);
// PY YTD
m.Table.AddMeasure(
m.Name + " PY YTD", // Name
"CALCULATE(" +
" ["+ m.Name + " YTD], " +
" DATEADD( '" + CalendarTableName + "'[" + CalendarTableDateColumnName + "], -1, YEAR ), " +
"'" + CalendarTableName + "'[" + dateWithSalesColumnName + "] = TRUE() )",
".Time Intelligence\\" + m.Name // Display Folder
);
// YoY
m.Table.AddMeasure(
m.Name + " YoY", // Name
"VAR CY = " + m.DaxObjectName + "VAR PY = " + "[" + m.Name + " PY] " +
"VAR Result = " + "IF( AND( CY, PY ), CY - PY )" +
"RETURN Result",
".Time Intelligence\\" + m.Name // Display Folder
).FormatString = "0.0 %";
// YoY%
m.Table.AddMeasure(
m.Name + " YoY%", // Name
"DIVIDE( [" + m.Name + " YoY], [" + m.Name + " PY] )",
".Time Intelligence\\" + m.Name // Display Folder
);
// QTD
m.Table.AddMeasure(
m.Name + " QTD", // Name
"CALCULATE( "
+ m.DaxObjectName + "," +
" DATESQTD( '" + CalendarTableName + "'[" + CalendarTableDateColumnName + "] ), " +
"'" + CalendarTableName + "'[" + dateWithSalesColumnName + "] = TRUE() )",
".Time Intelligence\\" + m.Name // Display Folder
);
// PQ
m.Table.AddMeasure(
m.Name + " PQ", // Name
"CALCULATE(" +
" " + m.DaxObjectName + "," +
" DATEADD( '" + CalendarTableName + "'[" + CalendarTableDateColumnName + "], -1, QUARTER ), " +
"'" + CalendarTableName + "'[" + dateWithSalesColumnName + "] = TRUE() )",
".Time Intelligence\\" + m.Name // Display Folder
);
// PY QTD
m.Table.AddMeasure(
m.Name + " PY QTD", // Name
"CALCULATE(" +
" ["+ m.Name + " QTD], " +
" DATEADD( '" + CalendarTableName + "'[" + CalendarTableDateColumnName + "], -1, QUARTER ), " +
"'" + CalendarTableName + "'[" + dateWithSalesColumnName + "] = TRUE() )",
".Time Intelligence\\" + m.Name // Display Folder
);
// QoQ
m.Table.AddMeasure(
m.Name + " QoQ", // Name
"VAR CQ = " + m.DaxObjectName + "VAR PQ = " + "[" + m.Name + " PQ] " +
"VAR Result = " + "IF( AND( CQ, PQ ), CQ - PQ )" +
"RETURN Result",
".Time Intelligence\\" + m.Name // Display Folder
).FormatString = "0.0 %";
// QoQ%
m.Table.AddMeasure(
m.Name + " QoQ%", // Name
"DIVIDE( [" + m.Name + " QoQ], [" + m.Name + " PQ] )",
".Time Intelligence\\" + m.Name // Display Folder
);
// MTD
m.Table.AddMeasure(
m.Name + " MTD", // Name
"CALCULATE( "
+ m.DaxObjectName + "," +
" DATESMTD( '" + CalendarTableName + "'[" + CalendarTableDateColumnName + "] ), " +
"'" + CalendarTableName + "'[" + dateWithSalesColumnName + "] = TRUE() )",
".Time Intelligence\\" + m.Name // Display Folder
);
// PM
m.Table.AddMeasure(
m.Name + " PM", // Name
"CALCULATE(" +
" " + m.DaxObjectName + "," +
" DATEADD( '" + CalendarTableName + "'[" + CalendarTableDateColumnName + "], -1, MONTH ), " +
"'" + CalendarTableName + "'[" + dateWithSalesColumnName + "] = TRUE() )",
".Time Intelligence\\" + m.Name // Display Folder
);
// PY MTD
m.Table.AddMeasure(
m.Name + " PY MTD", // Name
"CALCULATE(" +
" ["+ m.Name + " MTD], " +
" DATEADD( '" + CalendarTableName + "'[" + CalendarTableDateColumnName + "], -1, MONTH ), " +
"'" + CalendarTableName + "'[" + dateWithSalesColumnName + "] = TRUE() )",
".Time Intelligence\\" + m.Name // Display Folder
);
// MoM
m.Table.AddMeasure(
m.Name + " MoM", // Name
"VAR CM = " + m.DaxObjectName + "VAR PM = " + "[" + m.Name + " PM] " +
"VAR Result = " + "IF( AND( CM, PM ), CM - PM )" +
"RETURN Result",
".Time Intelligence\\" + m.Name // Display Folder
).FormatString = "0.0 %";
// MoM%
m.Table.AddMeasure(
m.Name + " MoM%", // Name
"DIVIDE( [" + m.Name + " MoM], [" + m.Name + " PM] )",
".Time Intelligence\\" + m.Name // Display Folder
);
// FYTD
m.Table.AddMeasure(
m.Name + " FYTD", // Name
"CALCULATE( "
+ m.DaxObjectName + "," +
" DATESYTD( '" + CalendarTableName + "'[" + CalendarTableDateColumnName + "], " + @"""" + FiscalYearEndDate + @"""" + " ), " +
"'" + CalendarTableName + "'[" + dateWithSalesColumnName + "] = TRUE() )",
".Time Intelligence\\" + m.Name // Display Folder
);
}
//Format All Measures
foreach (var m in Model.AllMeasures)
{
m.Expression = FormatDax(m.Expression);
/* Cycle over all measures in model and format
them all using DAX Formatter */
}