├── DateTable.m ├── FilterByList.m ├── README.md └── fx ├── README.md ├── fxColorHSVToHSL.m ├── fxColorRGBToHSV.m ├── fxErrorCheckForDuplicates.m ├── fxGetBMPImagePixelColors.m ├── fxGetDataflowTable.m ├── fxGetListOfAllErrReplacements.m ├── fxHex2Dec.m ├── fxOpenAI.m └── fxSplitAndProperCaseColumnName.m /DateTable.m: -------------------------------------------------------------------------------- 1 | //============================================ 2 | // Date Table (Calendar and Fiscal Periods) 3 | // Useful Links: 4 | // https://gorilla.bi/power-query/create-iso-week-and-iso-year/ 5 | // https://www.sqlbi.com/articles/reference-date-table-in-dax-and-power-bi/ 6 | // https://radacad.com/power-bi-date-or-calendar-table-best-method-dax-or-power-query 7 | // https://www.linkedin.com/posts/brianjuliusdc_stop-using-janky-black-box-dax-functions-activity-7083649958771347456-pUoN/ 8 | //============================================ 9 | let 10 | // CONFIGURATION 11 | // Choose between MANUAL ENTRY or PERIOD FROM DATA TABLES by uncommenting the appropriate section 12 | // MANUAL ENTRY PERIOD 13 | // Uncomment the following lines to manually set the start and end dates for the period 14 | // Start date (manually entered) 15 | _Date_Start = #date(2022, 1, 1), 16 | // End date (manually entered) 17 | _Date_End = #date(2025, 12, 31), 18 | // PERIOD FROM DATA TABLES 19 | // Uncomment the following lines if you want the period to be dynamically calculated based on the data in your tables 20 | // Fact table date column (replace Financials[Month] with your actual date column) 21 | //Source = Financials[Month], 22 | //Buffer the list of distinct dates for performance improvement 23 | //ListDistinct = List.Buffer(List.Distinct(Source)), 24 | // Start date (calculated from the minimum date in the data) 25 | //_Date_Start = Date.StartOfYear(List.Min(ListDistinct)), 26 | // End date (calculated from the maximum date in the data) 27 | //_Date_End = Date.EndOfYear(List.Max(ListDistinct)), 28 | // OTHER SETTINGS 29 | // First day of the week (set to Monday by default, can be changed to any day: Day.Monday to Day.Sunday) 30 | _FirstDayOfWeek = Day.Monday, 31 | // First month of the fiscal year (set to July by default, can be changed to any month, 1 = January, 12 = December) 32 | _FirstMonthOfFiscalYear = 7, 33 | // Today 34 | _Today = DateTime.Date(DateTime.FixedLocalNow()), 35 | // END CONFIGURATION 36 | // Complete list of dates (All days from January 1st of the first year to December 31st of the last year) 37 | List_Dates = List.Dates(_Date_Start, Number.From(_Date_End) - Number.From(_Date_Start) + 1, #duration(1, 0, 0, 0)), 38 | // Convert list of dates to a table 39 | Table_From_List = Table.FromList(List_Dates, Splitter.SplitByNothing(), {"Date"}, null, ExtraValues.Error), 40 | // Set the data type for the Date column 41 | Changed_Type_Date = Table.TransformColumnTypes(Table_From_List, {{"Date", type date}}), 42 | // Add day number (days since 1989-12-30) 43 | Add_DayNumber = Table.AddColumn(Changed_Type_Date, "Days since 1899-12-30", each Number.From([Date]), Int64.Type), 44 | // Add relative day number (days from today) 45 | Add_RelativeDays = Table.AddColumn( 46 | Add_DayNumber, "Offset Days", each Number.From([Date]) - Number.From(_Today), Int64.Type 47 | ), 48 | // Add YYYYMMDD as an integer (e.g., 20240814) 49 | Add_YYYYMMDD_Number = Table.AddColumn( 50 | Add_RelativeDays, "YYYYMMDD Number", each Number.From(Date.ToText([Date], "yyyyMMdd")), Int64.Type 51 | ), 52 | // Add day of the year (1..366) 53 | AddDayOfYear = Table.AddColumn(Add_YYYYMMDD_Number, "Day of Year", each Date.DayOfYear([Date]), Int64.Type), 54 | // Add day of the month (1..31) 55 | AddDayOfMonth = Table.AddColumn(AddDayOfYear, "Day of Month", each Date.Day([Date]), Int64.Type), 56 | // Add year as an integer (e.g., 2024) 57 | Add_YearNumber = Table.AddColumn(AddDayOfMonth, "Year", each Date.Year([Date]), Int64.Type), 58 | // Add the first day of the year 59 | AddYearStart = Table.AddColumn(Add_YearNumber, "Start of Year", each Date.StartOfYear([Date]), type date), 60 | // Add the last day of the year 61 | AddYearEnd = Table.AddColumn(AddYearStart, "End of Year", each Date.EndOfYear([Date]), type date), 62 | // Add year-month number (e.g., 202408) 63 | Add_YYYY_MM_Number = Table.AddColumn( 64 | AddYearEnd, "YYYYMM Number", each Date.Year([Date]) * 100 + Date.Month([Date]), Int64.Type 65 | ), 66 | // Add year-month (e.g., 2024-08) 67 | Add_YYYY_MM = Table.AddColumn(Add_YYYY_MM_Number, "YYYY-MM", each Date.ToText([Date], "yyyy-MM"), type text), 68 | // Add month as an integer (1..12) 69 | AddMonthNumber = Table.AddColumn(Add_YYYY_MM, "Month Number", each Date.Month([Date]), Int64.Type), 70 | // Add full month name (e.g., August) 71 | AddMonthName = Table.AddColumn(AddMonthNumber, "Month Long", each Date.MonthName([Date], "EN-us"), type text), 72 | // Add short month name (e.g., Aug) 73 | AddMonthNameShort = Table.AddColumn( 74 | AddMonthName, "Month Short", each Date.ToText([Date], "MMM", "EN-us"), type text 75 | ), 76 | // Add the first day of the month 77 | AddMonthStart = Table.AddColumn(AddMonthNameShort, "Start of Month", each Date.StartOfMonth([Date]), type date), 78 | // Add the last day of the month 79 | AddMonthEnd = Table.AddColumn(AddMonthStart, "End of Month", each Date.EndOfMonth([Date]), type date), 80 | // Add number of days in the month 81 | AddDaysInMonth = Table.AddColumn(AddMonthEnd, "Days in Month", each Date.DaysInMonth([Date]), Int64.Type), 82 | // Add ISO week number 83 | AddISOWeek = Table.AddColumn( 84 | AddDaysInMonth, 85 | "ISO Week Number", 86 | each 87 | let 88 | CurrentThursday = Date.AddDays([Date], 3 - Date.DayOfWeek([Date], Day.Monday)), 89 | YearCurrentThursday = Date.Year(CurrentThursday), 90 | FirstThursdayOfYear = Date.AddDays( 91 | #date(YearCurrentThursday, 1, 7), -Date.DayOfWeek(#date(YearCurrentThursday, 1, 1), Day.Friday) 92 | ), 93 | ISOWeek = Duration.Days(CurrentThursday - FirstThursdayOfYear) / 7 + 1 94 | in 95 | ISOWeek, 96 | Int64.Type 97 | ), 98 | // Add ISO year (integer) 99 | AddISOYear = Table.AddColumn( 100 | AddISOWeek, "ISO Year", each Date.Year(Date.AddDays([Date], 26 - [ISO Week Number])), Int64.Type 101 | ), 102 | // Add ISO year and week (number) (e.g., 202433) 103 | AddISOYear_WeekNumber = Table.AddColumn( 104 | AddISOYear, "ISO Year-Week Number", each [ISO Year] * 100 + [ISO Week Number], Int64.Type 105 | ), 106 | // Add ISO year and week (e.g., 2024-W33) 107 | AddISOYear_Week = Table.AddColumn( 108 | AddISOYear_WeekNumber, 109 | "ISO Year-Week", 110 | each Text.From([ISO Year]) & "-W" & Number.ToText([ISO Week Number], "00"), 111 | type text 112 | ), 113 | // Add the first day of the week (based on _FirstDayOfWeek) 114 | AddWeekStart = Table.AddColumn( 115 | AddISOYear_Week, "Start of Week", each Date.StartOfWeek([Date], _FirstDayOfWeek), type date 116 | ), 117 | // Add the last day of the week (based on _FirstDayOfWeek) 118 | AddWeekEnd = Table.AddColumn( 119 | AddWeekStart, "End of Week", each Date.EndOfWeek([Date], _FirstDayOfWeek), type date 120 | ), 121 | // Add day of the week number (1..7, based on _FirstDayOfWeek) 122 | AddDayOfWeekNumber = Table.AddColumn( 123 | AddWeekEnd, "Day of Week Number", each Date.DayOfWeek([Date], _FirstDayOfWeek), Int64.Type 124 | ), 125 | // Add a flag for weekends (1 for Saturday or Sunday, 0 for weekdays) 126 | AddIsWeekend = Table.AddColumn( 127 | AddDayOfWeekNumber, "Is Weekend", each if Date.DayOfWeek([Date], Day.Monday) >= 5 then 1 else 0, Int64.Type 128 | ), 129 | // Add a flag for weekdays (1 for Monday-Friday, 0 for weekends) 130 | AddIsWeekday = Table.AddColumn( 131 | AddIsWeekend, "Is Weekday", each if Date.DayOfWeek([Date], Day.Monday) < 5 then 1 else 0, Int64.Type 132 | ), 133 | // Add week number of the year 134 | AddWeekNumber = Table.AddColumn( 135 | AddIsWeekday, "Week Number", each Date.WeekOfYear([Date], _FirstDayOfWeek), Int64.Type 136 | ), 137 | // Add year-week (e.g., 202433) 138 | AddYearWeekNumber = Table.AddColumn( 139 | AddWeekNumber, "Year-Week Number", each [Year] * 100 + [Week Number], Int64.Type 140 | ), 141 | // Add year-week (e.g., 2024-W33) 142 | AddYear_Week = Table.AddColumn( 143 | AddYearWeekNumber, "Year-Week", each Text.From([Year]) & "-W" & Number.ToText([Week Number], "00"), type text 144 | ), 145 | // Add full day of the week name (e.g., Wednesday) 146 | AddDayOfWeekLong = Table.AddColumn( 147 | AddYear_Week, "Day of Week Long", each Date.DayOfWeekName([Date], "EN-us"), type text 148 | ), 149 | // Add short day of the week name (3 characters, e.g., Wed) 150 | AddDayOfWeekShort3 = Table.AddColumn( 151 | AddDayOfWeekLong, "Day of Week Short 3", each Date.ToText([Date], "ddd", "EN-us"), type text 152 | ), 153 | // Add 2-character day of the week name (e.g., We) 154 | AddDayOfWeekShort2 = Table.AddColumn( 155 | AddDayOfWeekShort3, "Day of Week Short 2", each Text.Start([Day of Week Short 3], 2), type text 156 | ), 157 | // Add quarter number (1..4) 158 | AddQuarterNumber = Table.AddColumn( 159 | AddDayOfWeekShort2, "Quarter Number", each Date.QuarterOfYear([Date]), Int64.Type 160 | ), 161 | // Add quarter (e.g., Q3) 162 | AddQuarter = Table.AddColumn( 163 | AddQuarterNumber, "Quarter", each "Q" & Text.From(Date.QuarterOfYear([Date])), type text 164 | ), 165 | // Add year and quarter (e.g., 20243) 166 | AddYearQuarterNumber = Table.AddColumn( 167 | AddQuarter, "Year-Quarter Number", each Date.Year([Date]) * 10 + Date.QuarterOfYear([Date]), Int64.Type 168 | ), 169 | // Add year and quarter (e.g., 2024-Q3) 170 | AddYearQuarter = Table.AddColumn( 171 | AddYearQuarterNumber, 172 | "Year-Quarter", 173 | each Text.From(Date.Year([Date])) & "-Q" & Text.From(Date.QuarterOfYear([Date])), 174 | type text 175 | ), 176 | // Add Start of Quarter 177 | AddStartOfQuarter = Table.AddColumn( 178 | AddYearQuarter, "Start of Quarter", each Date.StartOfQuarter([Date]), type date 179 | ), 180 | // Add End of Quarter 181 | AddEndOfQuarter = Table.AddColumn(AddStartOfQuarter, "End of Quarter", each Date.EndOfQuarter([Date]), type date), 182 | // Add fiscal year (integer) 183 | AddFiscalYear = Table.AddColumn( 184 | AddEndOfQuarter, 185 | "Fiscal Year", 186 | each 187 | Date.Year( 188 | Date.AddMonths(#date(Date.Year([Date]) + 1, Date.Month([Date]), 1), -_FirstMonthOfFiscalYear + 1) 189 | ), 190 | Int64.Type 191 | ), 192 | // Add fiscal year (e.g., FY2025) 193 | AddFY_YYYY = Table.AddColumn(AddFiscalYear, "FY-YYYY", each "FY-" & Text.From([Fiscal Year]), type text), 194 | // Add fiscal year (e.g., FY25) 195 | AddFY_YY = Table.AddColumn( 196 | AddFY_YYYY, 197 | "FY-YY", 198 | each 199 | "FY-" 200 | & Date.ToText( 201 | Date.AddMonths(#date(Date.Year([Date]) + 1, Date.Month([Date]), 1), -_FirstMonthOfFiscalYear + 1), 202 | "yy", 203 | "EN-us" 204 | ), 205 | type text 206 | ), 207 | // Add fiscal month number 208 | AddFiscalMonthNumber = Table.AddColumn( 209 | AddFY_YY, 210 | "Fiscal Month Number", 211 | each 212 | if [Month Number] >= _FirstMonthOfFiscalYear then 213 | [Month Number] - _FirstMonthOfFiscalYear + 1 214 | else 215 | [Month Number] + 12 - _FirstMonthOfFiscalYear + 1, 216 | Int64.Type 217 | ), 218 | // Add offset for this month (-1 = previous, 0 = current, 1 = next) 219 | AddOffsetMonth = Table.AddColumn( 220 | AddFiscalMonthNumber, 221 | "Offset Months", 222 | each ([Year] * 12 + [Month Number]) - (Date.Year(_Today) * 12 + Date.Month(_Today)), 223 | Int64.Type 224 | ), 225 | // Add offset for this quarter (-1 = previous, 0 = current, 1 = next) 226 | AddOffsetQuarter = Table.AddColumn( 227 | AddOffsetMonth, 228 | "Offset Quarters", 229 | each ([Year] * 4 + [Quarter Number]) - (Date.Year(_Today) * 4 + Date.QuarterOfYear(_Today)), 230 | Int64.Type 231 | ), 232 | // Add offset for this year (-1 = previous, 0 = current, 1 = next) 233 | AddOffsetYear = Table.AddColumn(AddOffsetQuarter, "Offset Years", each [Year] - Date.Year(_Today), Int64.Type), 234 | // Add offset for this fiscal year (-1 = previous, 0 = current, 1 = next) 235 | AddOffsetFiscalYear = Table.AddColumn( 236 | AddOffsetQuarter, 237 | "Offset Fiscal Years", 238 | each 239 | [Fiscal Year] - Date.Year( 240 | Date.AddMonths(#date(Date.Year(_Today) + 1, Date.Month(_Today), 1), -_FirstMonthOfFiscalYear + 1) 241 | ), 242 | Int64.Type 243 | ), 244 | // Add isAfterToday (1 = in the future, 0 = today or past) 245 | AddIsAfterToday = Table.AddColumn( 246 | AddOffsetFiscalYear, "isAfterToday", each if [Date] > _Today then 1 else 0, Int64.Type 247 | ), 248 | // Add offset for this week (1 = next week, -1 = previous week) 249 | AddWeekOffset = Table.AddColumn( 250 | AddIsAfterToday, 251 | "Offset Weeks", 252 | each Number.RoundDown(Duration.Days([Date] - Date.StartOfWeek(_Today, _FirstDayOfWeek)) / 7), 253 | Int64.Type 254 | ) 255 | in 256 | AddWeekOffset 257 | -------------------------------------------------------------------------------- /FilterByList.m: -------------------------------------------------------------------------------- 1 | // This code adds a logical column to check if each value in [ColumnToFilterBy] exists in Table[Column], filters the rows where this condition is true, and then removes the helper column. 2 | // To be used when filtering an SQL table by a small list of hardcoded (in another query) values (or values coming from another source) to ensure the non-breaking of query folding. 3 | 4 | // Instructions for Replacing Placeholders 5 | // PreviousStep: Replace this with the name of your previous query step or source table. This is the table you want to filter. 6 | // [ColumnToFilterBy]: Replace this with the name of the column in PreviousStep that you want to check against another table. 7 | // Table[Column]: Replace Table with the name of the table you're comparing against, and Column with the specific column in that table. 8 | 9 | // Step 1: Add a logical column that checks if each [ColumnToFilterBy] value exists in Table[Column] 10 | AddColumn_Is_ColumnToFilterBy_InTheList = Table.AddColumn( 11 | PreviousStep, 12 | "Is_ColumnToFilterBy_InTheList", 13 | each List.Contains(List.Buffer(Table[Column]), [ColumnToFilterBy]), 14 | type logical 15 | ), 16 | 17 | // Step 2: Filter rows where the new logical column is true 18 | FilterBy_Is_ColumnToFilterBy_InTheList = Table.SelectRows( 19 | AddColumn_Is_ColumnToFilterBy_InTheList, 20 | each [Is_ColumnToFilterBy_InTheList] = true 21 | ), 22 | 23 | // Step 3: Remove the helper logical column as it's no longer needed 24 | Remove_Is_ColumnToFilterBy_InTheList = Table.RemoveColumns( 25 | FilterBy_Is_ColumnToFilterBy_InTheList, 26 | {"Is_ColumnToFilterBy_InTheList"} 27 | ), 28 | 29 | /* 30 | // Step 1 will folded into the following SQL code 31 | case 32 | when [_].[ColumnToFilterBy] in ('Item1', 'Item2', 'Item3') 33 | then 1 34 | when not ([_].[ColumnToFilterBy] in ('Item1', 'Item2', 'Item3')) 35 | then 0 36 | else null 37 | end as [Is_ColumnToFilterBy_InTheList], 38 | */ 39 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # M language functions and code snippets for Power Query 2 | 3 | ## [[fx]](https://github.com/avatorl/M/blob/master/fx) 4 | Various custom functions 5 | 6 | ## [DateTable.m](https://github.com/avatorl/M/blob/master/DateTable.m) 7 | Date table 8 | 9 | ## [FilterByList.m](https://github.com/avatorl/M/blob/master/FilterByList.m) 10 | Filter by list (filter data table by a list of manually entered items) 11 | -------------------------------------------------------------------------------- /fx/README.md: -------------------------------------------------------------------------------- 1 | # M language functions for Power Query 2 | 3 | ### [fxOpenAI.m](https://github.com/avatorl/M/blob/master/fx/fxOpenAI.m) 4 | Call Open AI API from Power Query. Supports structured output (JSON format of the GPT response). [Read more...](https://www.powerofbi.org/2024/10/06/m-language-function-to-call-open-ai-api-from-power-query/) 5 | 6 | ### [fxGetDataflowTable.m](https://github.com/avatorl/M/blob/master/fx/fxGetDataflowTable.m) 7 | Retrieves data from a specified entity (table) within a dataflow in a Power BI workspace. 8 | 9 | ### [fxErrorCheckForDuplicates.m](https://github.com/avatorl/M/blob/master/fx/fxErrorCheckForDuplicates.m) 10 | Check if the specified column in the InputTable contains duplicate values. Returns the InputTable if no duplicates are found; otherwise, raises an error. Can be used for data validation. 11 | 12 | ### [fxGetListOfAllErrReplacements.m](https://github.com/avatorl/M/blob/master/fx/fxGetListOfAllErrReplacements.m) 13 | Build a list of all table columns for Table.ReplaceErrorValues() 14 | Output: {{"Column1", null}, {"Column2", null}} 15 | Usage: Table.ReplaceErrorValues(table as table, errorReplacement as list) as table 16 | 17 | ### [fxSplitAndProperCaseColumnName.m](https://github.com/avatorl/M/blob/master/fx/fxSplitAndProperCaseColumnName.m) 18 | Function to convert a column name from 'thiIsColumnName' format to 'This Is Column Name' format. 19 | 20 | ### [fxHex2Dec.m](https://github.com/avatorl/M/blob/master/fx/fxHex2Dec.m) 21 | Convert a hexadecimal value (as text) to a decimal value. 22 | 23 | ## Images and Colors 24 | 25 | ### [fxColorHSVToHSL.m](https://github.com/avatorl/M/blob/master/fx/fxColorHSVToHSL.m) 26 | Convert HSV (Hue, Saturation, Value) color into HSL (Hue, Saturation, Lightness) color. 27 | 28 | ### [fxColorRGBToHSV.m](https://github.com/avatorl/M/blob/master/fx/fxColorRGBToHSV.m) 29 | Convert RGB (Red, Green, Blue) color into HSV (Hue, Saturation, Value) color. 30 | 31 | ### [fxGetBMPImagePixelColors.m](https://github.com/avatorl/M/blob/master/fx/fxGetBMPImagePixelColors.m) 32 | Get pixel colors from BMP file (binary => table). 33 | -------------------------------------------------------------------------------- /fx/fxColorHSVToHSL.m: -------------------------------------------------------------------------------- 1 | // Convert HSV (Hue, Saturation, Value) color into HSL (Hue, Saturation, Lightness) color 2 | // HSL and HSV: https://en.wikipedia.org/wiki/HSL_and_HSV 3 | // Returns a record with [HSL_H, HSL_S, HSL_L] values 4 | (HSV_H as number, HSV_S as number, HSV_V as number) => 5 | let 6 | // Normalize the Saturation (S) and Value (V) from the HSV model to a 0-1 scale 7 | _s = HSV_S / 100, 8 | _v = HSV_V / 100, 9 | 10 | // Hue remains the same in both HSV and HSL models 11 | H = HSV_H, 12 | 13 | // Calculate the Lightness (L) 14 | // Lightness is calculated by taking the value and adjusting it based on the saturation 15 | L = _v - (_v * _s / 2), 16 | 17 | // Calculate the new Saturation (S) for the HSL model 18 | // Saturation in HSL is adjusted based on Lightness 19 | S = if (L = 0 or L = 1) then 20 | 0 // If Lightness is 0 (black) or 1 (white), Saturation is 0 21 | else 22 | (_v - L) / List.Min({L, 1 - L}), // Otherwise, it's based on the ratio of Value and Lightness 23 | 24 | // Create the result as a record with HSL_H, HSL_S, and HSL_L values 25 | Result = [HSL_H = H, HSL_S = S * 100, HSL_L = L * 100] 26 | in 27 | Result 28 | -------------------------------------------------------------------------------- /fx/fxColorRGBToHSV.m: -------------------------------------------------------------------------------- 1 | // Convert RGB (Red, Green, Blue) color into HSV (Hue, Saturation, Value) color 2 | // HSL and HSV: https://en.wikipedia.org/wiki/HSL_and_HSV 3 | // RGB: https://en.wikipedia.org/wiki/RGB_color_model 4 | // Returns a record with [H, S, V] values 5 | (R as number, G as number, B as number) => 6 | 7 | let 8 | // Normalize the RGB values to a scale of 0 to 1 9 | _r = R / 255, 10 | _g = G / 255, 11 | _b = B / 255, 12 | 13 | // Calculate the maximum and minimum of the normalized RGB values 14 | cmax = List.Max({_r, _g, _b}), 15 | cmin = List.Min({_r, _g, _b}), 16 | diff = cmax - cmin, // Calculate the difference between max and min, which is used to determine saturation and hue 17 | 18 | // Calculate the Hue (H) 19 | // Hue is determined by the dominant color (cmax) and its relation to the other colors 20 | h = if cmax = cmin then 21 | 0 // If there is no difference, hue is 0 (undefined) 22 | else if cmax = _r then 23 | 60 * ((_g - _b) / diff + 0) // If red is the dominant color 24 | else if cmax = _g then 25 | 60 * ((_b - _r) / diff + 2) // If green is the dominant color 26 | else if cmax = _b then 27 | 60 * ((_r - _g) / diff + 4) // If blue is the dominant color 28 | else 29 | -1, // Error case (should not occur), 30 | 31 | // Calculate the Saturation (S) 32 | // Saturation is calculated based on the difference between the max and min values 33 | s = if cmax = 0 then 34 | 0 // If the max value is 0 (black), saturation is 0 35 | else 36 | (diff / cmax) * 100, // Otherwise, saturation is the ratio of the difference to the max, scaled to 100 37 | 38 | // Calculate the Value (V) 39 | // Value is simply the maximum of the RGB components, scaled to 100 40 | v = cmax * 100, 41 | 42 | // Adjust hue to be within the 0-360 range 43 | h360 = if h < 0 then 44 | h + 360 // If hue is negative, add 360 to wrap it around 45 | else 46 | h, 47 | 48 | // Create the result as a record with H, S, and V values 49 | Result = [H = h360, S = s, V = v] 50 | in 51 | Result 52 | -------------------------------------------------------------------------------- /fx/fxErrorCheckForDuplicates.m: -------------------------------------------------------------------------------- 1 | // Check if the specified column in the InputTable contains duplicate values. 2 | // Returns the InputTable if no duplicates are found; otherwise, raises an error. 3 | ( 4 | InputTable as table, // Parameter for the input table 5 | ColumnName as text // Parameter for the column name to check for duplicates 6 | ) => 7 | let 8 | // Count the number of rows in the original table 9 | _CountRows1 = Table.RowCount(InputTable), 10 | 11 | // Remove duplicate rows based on the specified column 12 | #"Removed Duplicates" = Table.Distinct(InputTable, {ColumnName}), 13 | 14 | // Count the number of rows after removing duplicates 15 | _CountRows2 = Table.RowCount(#"Removed Duplicates"), 16 | 17 | // Define the error to be raised if duplicates are found 18 | _Error = 19 | error [ 20 | Reason = "DuplicateRecords", 21 | Message = "Duplicate records", 22 | Detail = "Duplicate records found in the data" 23 | ], 24 | 25 | // Output the original table if no duplicates are found; otherwise, raise the error 26 | _Output = if _CountRows2 = _CountRows1 then InputTable else _Error 27 | in 28 | _Output 29 | -------------------------------------------------------------------------------- /fx/fxGetBMPImagePixelColors.m: -------------------------------------------------------------------------------- 1 | // Get pixel colors from BMP file (binary => table) 2 | // Note: Simplified version that works with square images only (where width = height) 3 | // BMP file format reference: https://en.wikipedia.org/wiki/BMP_file_format 4 | (bmp as binary) => 5 | let 6 | // Convert binary data to a hexadecimal string representation 7 | Source = Binary.ToText(bmp, BinaryEncoding.Hex), 8 | 9 | // Extract the size of the image (width and height in pixels) 10 | // The size is stored at bytes 18-21 in the BMP header 11 | _Size = fxHexToDec(Text.Range(Source, 20*2, 2) & Text.Range(Source, 18*2, 2)), 12 | 13 | // Calculate the offset (starting address) where the pixel array begins in the file 14 | // The offset is stored at bytes 10-13 in the BMP header 15 | _Offset = fxHexToDec(Text.Range(Source, 10*2+3*2, 2) & Text.Range(Source, 10*2+2*2, 2) & Text.Range(Source, 10*2+1*2, 2) & Text.Range(Source, 10*2+0*2, 2)), 16 | 17 | // Extract the pixel array as a hexadecimal string starting from the calculated offset 18 | // Each pixel is represented by 3 bytes (6 hex characters), and there are _Size * _Size pixels in total 19 | #"Extracted Text Range" = Text.Range(Source, _Offset*2, 3*2*_Size*_Size), 20 | 21 | // Convert the extracted pixel data into a table with a single column 22 | #"Converted to Table" = #table(1, {{#"Extracted Text Range"}}), 23 | 24 | // Split the hexadecimal string into individual pixels (6 hex characters per pixel) 25 | #"Split Column by Position" = Table.ExpandListColumn( 26 | Table.TransformColumns(#"Converted to Table", 27 | {{"Column1", Splitter.SplitTextByRepeatedLengths(6), let itemType = (type nullable text) meta [Serialized.Text = true] in type {itemType}}}), "Column1"), 28 | 29 | // Rename the column containing pixel data to "Pixel" 30 | #"Renamed Columns" = Table.RenameColumns(#"Split Column by Position", {{"Column1", "Pixel"}}), 31 | 32 | // Add an index column to keep track of the order of pixels 33 | #"Added Index" = Table.AddIndexColumn(#"Renamed Columns", "Index", 0, 1, Int64.Type), 34 | 35 | // Calculate the column index for each pixel (position within the row) 36 | #"Added Custom" = Table.AddColumn(#"Added Index", "Column", each Number.RoundDown([Index]/_Size, 0)), 37 | #"Changed Type" = Table.TransformColumnTypes(#"Added Custom", {{"Column", Int64.Type}}), 38 | 39 | // Calculate the row index for each pixel 40 | #"Added Custom1" = Table.AddColumn(#"Changed Type", "Row", each [Index] - [Column] * _Size), 41 | #"Changed Type1" = Table.TransformColumnTypes(#"Added Custom1", {{"Row", Int64.Type}}), 42 | 43 | // Convert pixel color from #BBGGRR format (BMP default) to #RRGGBB format (standard) 44 | #"Added Custom2" = Table.AddColumn(#"Changed Type1", "Color", each "#" & Text.Middle([Pixel], 4, 2) & Text.Middle([Pixel], 2, 2) & Text.Middle([Pixel], 0, 2)), 45 | 46 | // Remove the original "Pixel" column, retaining only the reformatted "Color" column 47 | #"Removed Columns" = Table.RemoveColumns(#"Added Custom2", {"Pixel"}), 48 | 49 | // Ensure the "Color" column is treated as text 50 | #"Changed Type2" = Table.TransformColumnTypes(#"Removed Columns", {{"Color", type text}}) 51 | in 52 | #"Changed Type2" 53 | -------------------------------------------------------------------------------- /fx/fxGetDataflowTable.m: -------------------------------------------------------------------------------- 1 | // ============================================= 2 | // Function: fxGetDataflowTable 3 | // Description: 4 | // Retrieves data from a specified entity (table) within a dataflow in a Power BI workspace. 5 | // Parameters: 6 | // - WorkspaceId (text): The unique identifier of the Power BI workspace. 7 | // - DataflowId (text): The unique identifier of the dataflow within the workspace. 8 | // - EntityName (text): The name of the entity (table) to retrieve data from. 9 | // Returns: 10 | // - A table containing the data from the specified entity. 11 | // ============================================= 12 | 13 | let 14 | GetDataflowTable = (WorkspaceId as text, DataflowId as text, EntityName as text) => 15 | let 16 | // Connect to the Power Platform Dataflows 17 | Source = PowerPlatform.Dataflows([]), 18 | 19 | // Access the list of Workspaces from the Dataflows source 20 | Workspaces = Source{[Id = "Workspaces"]}[Data], 21 | 22 | // Retrieve the specific Workspace using its Id 23 | Workspace = Workspaces{[workspaceId = WorkspaceId]}[Data], 24 | 25 | // Access the Dataflow within the specified Workspace using its Id 26 | Dataflow = Workspace{[dataflowId = DataflowId]}[Data], 27 | 28 | // Retrieve the specific table (entity) data from the Dataflow 29 | TableData = Dataflow{[entity = EntityName, version = ""]}[Data] 30 | in 31 | TableData 32 | in 33 | GetDataflowTable 34 | -------------------------------------------------------------------------------- /fx/fxGetListOfAllErrReplacements.m: -------------------------------------------------------------------------------- 1 | // Build a list of all table columns for Table.ReplaceErrorValues() 2 | // Output: {{"Column1", null}, {"Column2", null}} 3 | // Usage: Table.ReplaceErrorValues(table as table, errorReplacement as list) as table 4 | 5 | let 6 | // Function to generate the list of column names paired with null values for error replacement 7 | ErrorReplacement = (_table as table) => 8 | let 9 | // Get the list of all column names in the input table 10 | _AllColumns = Table.ColumnNames(_table), 11 | 12 | // Convert the list of column names into a single-column table 13 | #"Converted to Table" = Table.FromList(_AllColumns, Splitter.SplitByNothing(), {"ColumnName"}), 14 | 15 | // Add a new column with null values, corresponding to each column name 16 | #"Added Null Column" = Table.AddColumn(#"Converted to Table", "NullValue", each null), 17 | 18 | // Combine each column name and its corresponding null value into a list (e.g., {"Column1", null}) 19 | #"Combined Columns" = Table.AddColumn(#"Added Null Column", "Replacement", each {[ColumnName], [NullValue]}), 20 | 21 | // Remove the intermediate columns, leaving only the combined column-name-null-value pairs 22 | #"Removed Intermediate Columns" = Table.RemoveColumns(#"Combined Columns", {"ColumnName", "NullValue"}), 23 | 24 | // Extract the list of all column-name-null-value pairs 25 | _ListOfAllReplacements = #"Removed Intermediate Columns"[Replacement] 26 | in 27 | _ListOfAllReplacements 28 | in 29 | ErrorReplacement 30 | -------------------------------------------------------------------------------- /fx/fxHex2Dec.m: -------------------------------------------------------------------------------- 1 | // Convert a hexadecimal value (as text) to a decimal value 2 | let 3 | Hex2Dec = (input as text) => 4 | 5 | let 6 | // Function to convert a single hex digit (0-9, A-F) to its decimal equivalent 7 | convertHexDigit = (digit) => 8 | let 9 | // Mapping of hex digits to their corresponding decimal values 10 | values = { 11 | {"0", 0}, {"1", 1}, {"2", 2}, {"3", 3}, {"4", 4}, {"5", 5}, {"6", 6}, 12 | {"7", 7}, {"8", 8}, {"9", 9}, {"A", 10}, {"B", 11}, {"C", 12}, 13 | {"D", 13}, {"E", 14}, {"F", 15} 14 | }, 15 | 16 | // Select the decimal value that corresponds to the input hex digit 17 | Result = Value.ReplaceType( 18 | {List.First(List.Select(values, each _{0} = digit)){1}}, 19 | type {number} 20 | ) 21 | in 22 | Result, 23 | 24 | // Convert the input hex string to uppercase and reverse it for easier processing 25 | Reverse = List.Reverse(Text.ToList(Text.Upper(input))), 26 | 27 | // Generate a list of numbers representing the position of each hex digit (0, 1, 2, ...) 28 | noDigits = List.Numbers(0, List.Count(Reverse)), 29 | 30 | // Convert each hex digit to decimal and multiply by the appropriate power of 16 31 | DecimalValues = List.Transform(noDigits, each List.First(convertHexDigit(Reverse{_})) * Number.Power(16, _)), 32 | 33 | // Sum all the decimal values to get the final result 34 | Return = List.Sum(DecimalValues) 35 | in 36 | Return 37 | 38 | in 39 | Hex2Dec 40 | -------------------------------------------------------------------------------- /fx/fxOpenAI.m: -------------------------------------------------------------------------------- 1 | // Power Query M function to call the OpenAI API 2 | // Supports structured output (JSON format of the GPT response) 3 | // ================================================================================================ 4 | // GitHub: https://github.com/avatorl/M/blob/master/fx/fxOpenAI.m 5 | // Blog post about this function: https://www.powerofbi.org/2024/10/06/m-language-function-to-call-open-ai-api-from-power-query/ 6 | // 7 | // OpenAI API Documentation: 8 | // API Reference: https://platform.openai.com/docs/api-reference/ 9 | // Models: https://platform.openai.com/docs/models 10 | // Create Chat Completion: https://platform.openai.com/docs/api-reference/chat/create 11 | // Structured outputs: https://platform.openai.com/docs/guides/structured-outputs 12 | // API Errors: https://platform.openai.com/docs/guides/error-codes/api-errors 13 | // 14 | // Get your API Key at https://platform.openai.com/api-keys 15 | // ================================================================================================ 16 | // Function parameters: 17 | // - user (required): The user prompt to send to the OpenAI API. 18 | // - userData (optional): Optional data (text field) that will be concatenated with the user prompt. 19 | // Usage examples: 20 | // fxOpenAI("Translate this text into French, Italian, and German. Text to translate: " & [Text]) 21 | // fxOpenAI("Translate this text into French, Italian, and German. Text to translate:", [Text]) 22 | (user as text, optional userData as text) => 23 | let 24 | // CONFIGURATION ================================================================================== 25 | // Replace the API key below with your actual API key 26 | _api_key = "sk-proj-...SR8A", 27 | // Determine the model to use, for example: "gpt-4o-mini", "gpt-4o", "o1-mini" 28 | _model = "gpt-4o-mini", 29 | // Prepare user prompt: concatenate userData with user 30 | _user = user & " " & (userData ?? ""), 31 | // Determine the system message, for example: "You're a helpful assistant" 32 | _system = "You're a helpful assistant", 33 | // What sampling temperature to use, between 0 and 2. Higher values like 0.8 will make the output more random, while lower values like 0.2 will make it more focused and deterministic 34 | _temperature = 1, 35 | // An upper bound for the number of tokens that can be generated for a completion, including visible output tokens and reasoning tokens 36 | _max_completion_tokens = null, 37 | // Determine if structured output (JSON format of the GPT response) is enabled 38 | _structured_output = false, 39 | // Structured output example: 40 | // Function call: fxOpenAI("Translate this text into French, Italian, and German. Text to translate:",[Text]), where [Text] = "I have an apple and 2 oranges" 41 | // User prompt: "Translate this text into French, Italian, and German. Text to translate: I have an apple and 2 oranges" 42 | // GPT response JSON: {"TranslationFR": "J'ai une pomme et 2 oranges", "TranslationIT": "Ho una mela e 2 arance", "TranslationDE": "Ich habe einen Apfel und 2 Orangen"} 43 | // STRUCTURED OUTPUT JSON SCHEMA ================================================================== 44 | // Define the expected JSON schema for structured output 45 | _response_format = [ 46 | type = "json_schema", 47 | json_schema = [ 48 | name = "response_json_schema", 49 | description = "JSON format of the response", 50 | strict = true, 51 | schema = [ 52 | type = "object", 53 | properties = [ 54 | translationFR = [type = "string", description = "put French translation here"], 55 | translationIT = [type = "string", description = "put Italian translation here"], 56 | translationDE = [type = "string", description = "put German translation here"] 57 | ], 58 | required = {"translationFR", "translationIT", "translationDE"}, 59 | additionalProperties = false 60 | ] 61 | ] 62 | ], 63 | // ================================================================================================ 64 | // Define the base URL for the API endpoint 65 | _url_base = "https://api.openai.com", 66 | // Define the relative path for the API endpoint 67 | _url_rel = "v1/chat/completions", 68 | // 69 | // Create the JSON body for the API request, including the user message and system message 70 | requestDataBase = [ 71 | model = _model, 72 | // An upper bound for the number of tokens that can be generated for a completion, including visible output tokens and reasoning tokens 73 | max_completion_tokens = _max_completion_tokens, 74 | // What sampling temperature to use, between 0 and 2. Higher values like 0.8 will make the output more random, while lower values like 0.2 will make it more focused and deterministic 75 | temperature = _temperature, 76 | messages = {[ 77 | role = "system", 78 | content = _system 79 | ], [ 80 | role = "user", 81 | content = _user 82 | ]} 83 | ], 84 | // 85 | // Conditionally include the response_format field if structured output is enabled 86 | requestData = 87 | if _structured_output then 88 | Record.AddField(requestDataBase, "response_format", _response_format) 89 | else 90 | requestDataBase, 91 | // 92 | // Make the API call using Web.Contents and capture the response 93 | response = 94 | let 95 | httpRequest = Web.Contents( 96 | _url_base, 97 | [ 98 | RelativePath = _url_rel, 99 | Headers = [ 100 | #"Content-Type" = "application/json", 101 | #"Authorization" = "Bearer " & _api_key 102 | ], 103 | Content = Json.FromValue(requestData), 104 | ManualStatusHandling = {400, 401, 403, 404, 429, 500, 503} 105 | // List of status codes to handle 106 | ] 107 | ) 108 | in 109 | httpRequest, 110 | // 111 | // Extract metadata from the response 112 | responseMetadata = Value.Metadata(response), 113 | responseCode = responseMetadata[Response.Status], 114 | responseText = Text.FromBinary(response), 115 | // 116 | // Check the response code and handle errors 117 | responseJSON = 118 | if responseCode <> 200 then 119 | let 120 | // Parse the error response JSON 121 | errorResponse = Json.Document(responseText), 122 | // Extract the error message from the response 123 | errorMessage = 124 | if 125 | Record.HasFields(errorResponse, "error") 126 | and Record.HasFields(errorResponse[error], "message") 127 | then 128 | errorResponse[error][message] 129 | else 130 | "An unknown error occurred.", 131 | // Raise an error with the appropriate details 132 | errorRecord = Error.Record( 133 | "Open AI API Request Error " & Text.From(responseCode), errorMessage, errorResponse 134 | ) 135 | in 136 | // Raise an error with the appropriate details 137 | error errorRecord 138 | else 139 | // Parse the successful response JSON 140 | Json.Document(responseText), 141 | // 142 | // Extract the first choice from the API response 143 | choice = responseJSON[choices]{0}, 144 | // Retrieve the generated content and finish reason 145 | content = choice[message][content], 146 | reason = choice[finish_reason], 147 | // If structured output is enabled, parse the content as JSON 148 | finalContent = if _structured_output then Json.Document(content) else content, 149 | // Return both the content and the finish reason as the result 150 | Result = [ 151 | // Either text (structured output disabled) or record (structured output enabled) 152 | Content = finalContent, 153 | // "stop" - the API returned the full chat completion generated by the model without running into any limits 154 | // "length" - the conversation was too long for the context window 155 | // "content_filter" - the content was filtered due to policy violations 156 | FinishReason = reason, 157 | // Detailed API response with metadata (including number of tokens used) 158 | FullResponse = responseJSON 159 | ] 160 | in 161 | Result 162 | -------------------------------------------------------------------------------- /fx/fxSplitAndProperCaseColumnName.m: -------------------------------------------------------------------------------- 1 | // Function to convert a column name from 'thiIsColumnName' format to 'This Is Column Name' format 2 | = (_ColumnName as text) => 3 | 4 | let 5 | // Convert the column name string into a list of individual characters 6 | #"Added Custom" = Text.ToList(_ColumnName), 7 | 8 | // Convert the list of characters into a table format 9 | #"Converted to Table" = Table.FromList(#"Added Custom", Splitter.SplitByNothing(), null, null, ExtraValues.Error), 10 | 11 | // Rename the single column of the table to 'ListOfCharacters' for clarity 12 | #"Renamed Columns" = Table.RenameColumns(#"Converted to Table", {{"Column1", "ListOfCharacters"}}), 13 | 14 | // Add a new column 'Numbers' containing the ASCII number for each character 15 | #"Added Custom1" = Table.AddColumn(#"Renamed Columns", "Numbers", each Character.ToNumber([ListOfCharacters])), 16 | 17 | // Add a new column 'NewCharacter', prefixing uppercase letters with a '/' 18 | // This step helps in identifying word boundaries by detecting capital letters 19 | #"Added Custom2" = Table.AddColumn(#"Added Custom1", "NewCharacter", each (if [Numbers] > 64 and [Numbers] < 91 then "/" else "") & Character.FromNumber([Numbers])), 20 | 21 | // Remove unnecessary columns to keep only 'NewCharacter' 22 | #"Removed Columns" = Table.RemoveColumns(#"Added Custom2", {"ListOfCharacters", "Numbers"}), 23 | 24 | // Add a constant column 'One' with value 1 to use for grouping in the next step 25 | #"Added Custom3" = Table.AddColumn(#"Removed Columns", "One", each 1), 26 | 27 | // Group the rows to concatenate the 'NewCharacter' column into a single text string 28 | #"Grouped Rows" = Table.Group(#"Added Custom3", {"One"}, {{"NewName", each Text.Combine([NewCharacter]), type text}}), 29 | 30 | // Replace the '/' characters (used to mark word boundaries) with spaces 31 | #"Replaced Value" = Table.ReplaceValue(#"Grouped Rows", "/", " ", Replacer.ReplaceText, {"NewName"}), 32 | 33 | // Capitalize the first letter of each word in the newly formed name 34 | #"Capitalized Each Word" = Table.TransformColumns(#"Replaced Value", {{"NewName", Text.Proper, type text}}), 35 | 36 | // Extract the final column name from the table and return it 37 | NewName = Table.RemoveColumns(#"Capitalized Each Word", {"One"})[NewName]{0} 38 | in 39 | NewName 40 | --------------------------------------------------------------------------------