├── Calendars ├── DateTable │ ├── CustomPeriods12Month+ │ │ ├── fn_CustomPeriodCalendar.md │ │ └── fn_CustomPeriodCalendar.pq │ ├── SQL_Calendar │ │ ├── SQL_DimDates.sql │ │ ├── SQL_NativeQuery.pq │ │ ├── SQL_NativeQuery_v2.pq │ │ └── dim_calendar_v2.sql │ ├── StandardCalendarRange │ │ ├── fnDates.md │ │ ├── fnDates_Updated.md │ │ ├── fnDynamicMonthlyCalendar.pq │ │ ├── fnMonthlyCalendar.md │ │ ├── fnMonthlyCalendar.pq │ │ ├── fn_CalendarTable.pq │ │ ├── fn_DateKeyTable_Monthly.pq │ │ ├── fn_Dates.pq │ │ ├── fn_calendar_dates_table.pq │ │ ├── fn_calendar_dates_table_DEBUG.pq │ │ ├── fn_dates_updated.pq │ │ └── fn_tempDates.pq │ └── _archive │ │ ├── fnDates_v2.md │ │ ├── fn_CustomCalendar.md │ │ └── fn_Dates_v3.md ├── DynamicDatesListDEMO │ ├── ForGuerillaBI_DynamicListMonths.pbix │ └── readme.md ├── Fiscal_Calendar_Period_Functions │ ├── fnFiscalQuarterOffset.md │ ├── fn_GetFiscalPeriod.md │ ├── fn_GetMonthFromFiscalPeriod_v1.md │ └── fn_GetMonthFromFiscalPeriod_v2.md ├── TimeTable │ ├── fnTimeTable.md │ └── fn_TimeDimension.md └── _archive │ ├── DateTable.pq │ ├── YearGroupsMisc.pq │ ├── fnDateTable.pq │ ├── fnDatesTable_20220800 │ ├── fnDatesTable_EDNA_v2.md │ ├── fnDates_20221008 │ ├── fnDates_V2.md │ └── tx_DatesTable_20220800.md ├── Functions ├── (Un)Pivot │ ├── UnpivotMultipleColumns.md │ └── UnpivotMultipleColumns_v0.md ├── AdvancedETL │ └── ETLfunctions.md ├── BulkReplace │ └── fnBulkReplace.md ├── CheckForDups │ └── fnCheckForDups.md ├── CleanString │ └── fnCleanString.pq ├── CleanTextByCase │ └── fn_CleanTextByCase.md ├── ColumnNamesFix │ └── fnColumnNamesFix.md ├── ContainsText │ └── TextContains.md ├── CountMonths │ └── fnCountMonths.md ├── DataTypeErrors │ └── fnNoDataTypeErrors.md ├── Dataverse │ ├── fn_DataversePrep.md │ └── fn_GetCustomDataverseObjects ├── DateTime │ ├── bsl_end.pq │ ├── bst_start.pq │ ├── daylight_savings.pq │ ├── fnRemoveSecondsFromDateTime.pq │ ├── round_datetime_to_hours.pq │ └── round_time_to_hours.pq ├── DatesFromPeriod │ └── fnDateFromPeriod.md ├── DaylightSavings │ └── DaylightSavingAdjustment.pq ├── DecimalTimeToDuration │ └── fnDecimalTimeToDuration.pq ├── DynamicDatesList │ └── fnDynamicDatesList.pq ├── ErrorReplaceCols │ └── fnErrorReplaceColumns.md ├── ExtractDate │ └── fnExtractDate.md ├── ExtractDates │ └── ExtractDates.md ├── ExtractText │ └── extractTextOrNumbers.md ├── FilterMaxDate │ └── fnFilterMaxDate.md ├── FindWords&TextStrings │ └── fn_ExactStringMatchs.md ├── FindWordsExact │ ├── fnMatchTextStringExact.md │ └── fnMatchWordsExact.pq ├── FindWordsSubString │ ├── fnAllWordMatches..md │ └── fnMatchSubstring.md ├── GetDate │ └── fnGetDate.md ├── GetDetaflowMeta │ └── GetDataflowMeta.md ├── GetInitials │ └── fnInitialiseString.md ├── GetOneDriveFiles │ └── fnGetOneDriveFiles.md ├── GetSharePointFiles │ ├── _allfunctions.md │ ├── fnCombineFolder.md │ ├── fnGetSPFile.md │ └── fnGetSPFolder.md ├── GetText │ ├── fnGetDigits.md │ └── fnSelectText.md ├── GetUniques │ ├── fnGetUniques.md │ └── fn_GetUniqueDimension.pq ├── GetWeekNumber │ └── fnGetWeekNumber.md ├── GetWorkDay │ └── fnGetWorkDay.md ├── Grouping │ └── fnCustomGrouping.pq ├── Insert_Row │ ├── fn_insert_row_to_table.md │ └── fn_insert_row_to_table.pbix ├── IntervalDivision │ └── fnIntervalDivision.md ├── KeepUnpivotNulls │ └── fnKeepUnPivotNulls.pq ├── LastNMonths │ └── fnLastNMonths.md ├── LastRefresh │ ├── fnLastRefresh.md │ └── fnLastRefresh.pq ├── ListGenerate │ └── fnListGenerateExample.pq ├── ListZip │ └── ListZip.md ├── NavigateToTable │ └── NavigateToTable.md ├── OpenAi │ └── fxOpenAI.md ├── PascalCase │ └── fn_fix_pascal_case.pq ├── PowerTrim │ ├── fnPowerTrim.md │ └── fnTrimSpaces.md ├── QueryFolding │ └── fnQueryFolding.md ├── RemoveNullColumns │ └── RemoveNullColumns.md ├── RemoveRepeatingCharacters │ └── Text.RemoveRepeatingCharacters.pq ├── ReorderCols │ └── fnReorderCols.md ├── ReplaceNullsAndBlanks │ ├── fnReplaceNullsAndBlanks.md │ └── fnReplaceNullsBlanksSpaces.pq ├── ReplaceText │ └── fnConditionalReplace_v1.md ├── SharePointFunctions │ ├── fnSP_v1.md │ ├── fn_SP_x1.md │ └── fn_SP_x2.md ├── SnakeToCamel │ └── fnSnakeToCamelCase ├── StartsEndsWith │ └── TextStartsEndsWith.md ├── Templates │ ├── function-basic-template.md │ ├── functionTemplate_v1.md │ └── functionTemplate_v1a.md ├── TransformHeaders │ └── fnTransformHeaders.md ├── Year-Over-Year │ └── Year-Over-Year_dates.pq ├── __GetGithubFunction │ ├── _getGithubPQFunction.md │ └── fnGetGithubFunction.pq ├── filterMax │ ├── fnFilterMax.md │ └── fnFilterMax_v1.md ├── fnGetCalendarMonth │ ├── fnGetCalendarMonth.md │ └── fnGetMonthFromFiscalPeriod.md ├── fnGetFiscalPeriod.md ├── fnGetInitials │ ├── fnGetInitials.md │ ├── fnGetInitials_v2.pq │ └── fnGetInitials_v3.pqm ├── fnSuperCleanTextString │ └── fnSuperCleanTextString.pq └── zzzExcel │ └── flashFillAlphabet.md ├── GetDataFromSharePoint ├── fnCombineFolder.md ├── fnGetFile.md └── fnGetFolder.md ├── GoogleAnalytics └── fnGoogleConnector.md ├── JSON └── fnTableFromJSON.md ├── LICENSE ├── README.md ├── SharePointAPI └── SharePointAPI_fns.md ├── SyntaxHighlight.md ├── Templates ├── M-code Function Template.md ├── M-functionTemplate.md ├── M-template.md └── fn_custom_function_template.pq ├── UnzipContents └── fnUnzipContents.md ├── recordvalueListExample.md └── zInProgressDump └── Dump.md /Calendars/DateTable/SQL_Calendar/SQL_NativeQuery.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = Sql.Databases("localhost\mssqlserver01"), 3 | #"Contoso 100K" = Source{[Name="Contoso 100K"]}[Data], 4 | Custom1 = 5 | let 6 | vList = "[2019,2020]", 7 | vStartDate = "20160101", 8 | isEnabled = [EnableFolding = true ], 9 | vRunQuery = Value.NativeQuery( #"Contoso 100K" , 10 | "SELECT * FROM Data.Date WHERE [Date] > @StartDate 11 | and [Year] IN (select value from OPENJSON(@yearList))" , 12 | [StartDate= vStartDate, yearList = vList ] , isEnabled ) 13 | in 14 | vRunQuery 15 | in 16 | Custom1 17 | -------------------------------------------------------------------------------- /Calendars/DateTable/SQL_Calendar/SQL_NativeQuery_v2.pq: -------------------------------------------------------------------------------- 1 | let invokeCalendar = (Input_Calendar_Start_Year as text) => 2 | let 3 | _sqlServer = "sql-lcgdna-prd-uks-01.database.windows.net", 4 | _azureDatabase = "sqldb_lcgdna_dwh_01", 5 | vCalendarStartYear = Input_Calendar_Start_Year, 6 | _isFoldingEnabled = [EnableFolding = true ], 7 | _runSQLQueryALL = "SELECT * FROM [ENT].[Dim_Calendar_Join] WHERE [Year Num] >=" & vCalendarStartYear, 8 | _runSQLQuery = 9 | "SELECT [Key Date] as [Date] 10 | ,[Year Num] 11 | ,[Month Num] 12 | ,[Month Start] 13 | ,[Month End] 14 | ,[Month Name] 15 | ,[Month Short] 16 | ,[Month Initial] 17 | ,[Month Selection] 18 | ,[YearMonthID] 19 | ,[Fiscal Year] 20 | ,[Academic Year] 21 | ,[Fiscal Month Num] 22 | ,[Academic Month Num] 23 | ,[Year Month Int] 24 | ,[Fiscal Year Month Int] 25 | ,[Academic Year Month Int] 26 | ,[Fiscal Month Short] 27 | ,[Academic Month Short] 28 | ,[Month-Year] 29 | ,[Fiscal Month-Year] 30 | ,[Academic Month-Year] 31 | ,[Quarter Num] 32 | ,[Fiscal Quarter Num] 33 | ,[Academic Quarter Num] 34 | ,[Year Offset] 35 | ,[Fiscal Year Offset] 36 | ,[Academic Year Offset] 37 | ,[Month Offset] 38 | ,[Is in Year to Date] 39 | ,[Is Future] 40 | ,[Is Year Complete] 41 | ,[Is Financial Year Complete] 42 | ,[Is Academic Year Complete] 43 | FROM [ENT].[Dim_Calendar_Join] 44 | WHERE [Year Num] >=" & vCalendarStartYear // & _whereFilter_v2 45 | , 46 | _sourceDB = Sql.Database( _sqlServer, _azureDatabase ), 47 | _nativeQuery = Value.NativeQuery( _sourceDB , _runSQLQueryALL , null , _isFoldingEnabled), 48 | _renameDate = Table.RenameColumns(_nativeQuery,{{"Key Date", "Date"}}), 49 | _formatDates = Table.TransformColumnTypes(_renameDate,{{"Date", type date}, {"Month Start", type date}, {"Month End", type date}}), 50 | _colsOrder = {"Date", "YearMonthID", "Fiscal Year", "Academic Year", "Year Num", "Month Name", "Month Short", "Month Num", "Month Start", "Month End", "Month Initial", "Month Selection", "Fiscal Month Num", "Academic Month Num", "Year Month Int", "Fiscal Year Month Int", "Academic Year Month Int", "Fiscal Month Short", "Academic Month Short", "Month-Year", "Fiscal Month-Year", "Academic Month-Year", "Fiscal Quarter Num", "Academic Quarter Num", "Year Offset", "Fiscal Year Offset", "Academic Year Offset", "Month Offset"}, 51 | _inputTable = Table.ReorderColumns( _formatDates, _colsOrder ), 52 | _fiscalQuarterPrefix = Table.TransformColumns(_inputTable, {{"Fiscal Quarter Num", each "F" & _, type text}}), 53 | _academicQuarterPrefix = Table.TransformColumns(_fiscalQuarterPrefix, {{"Academic Quarter Num", each "A" & _, type text}}), 54 | _last15Months = Table.AddColumn(_academicQuarterPrefix, "Is Last 15 Months", each if [Month Offset] >= -15 then "Last 15 Months" else null, type text), 55 | _newStartsOnly = Table.AddColumn(_last15Months, "New Starts Only Filter", each if [Academic Year Offset] = 0 then "Show AY New Starts Only" else null, type text) 56 | in 57 | _newStartsOnly 58 | 59 | in invokeCalendar 60 | -------------------------------------------------------------------------------- /Calendars/DateTable/StandardCalendarRange/fnDynamicMonthlyCalendar.pq: -------------------------------------------------------------------------------- 1 | let 2 | fxDate = (Day as text, Start.Date as date, optional End.Date as date) as table => 3 | let 4 | Dayofmonth = if Day = "All" or Day = "all" then - 2 else if Day = "last" or Day = "Last" then - 1 else Number.FromText(Day), 5 | StartDate = if Dayofmonth = - 2 then Start.Date else #date(Date.Year(Start.Date), Date.Month(Start.Date), 1), 6 | EndDate1 = if End.Date = null then DateTime.Date(DateTime.LocalNow()) else End.Date, 7 | //End.Date = DateTime.Date(DateTime.LocalNow()), 8 | CYear = Date.Year(EndDate1), 9 | EndDate = if Dayofmonth = - 2 then EndDate1 else Date.AddDays(Date.EndOfMonth(EndDate1), 1), 10 | DayBetween = if Dayofmonth = - 2 then 1 else 31, 11 | NumberOfDays = Duration.Days(EndDate - StartDate) / DayBetween, 12 | NOM = if Dayofmonth = - 2 then 1 else 0, 13 | Dates = List.Dates(StartDate, NumberOfDays + NOM, #duration(DayBetween, 0, 0, 0)), 14 | CTTable = Table.FromList(Dates, Splitter.SplitByNothing(), null, null, ExtraValues.Error), 15 | RenameC = Table.RenameColumns(CTTable, {{"Column1", "Date"}}), 16 | ChangeT1 = Table.TransformColumnTypes(RenameC, {{"Date", type date}}), 17 | AddSDAM = Table.AddColumn( 18 | ChangeT1, 19 | "Selected Day Of Month", 20 | each if Dayofmonth = - 1 then Date.EndOfMonth([Date]) else if Dayofmonth = - 2 then [Date] else Date.AddDays([Date], - 1 * (Date.Day([Date]) - Dayofmonth)) 21 | ), 22 | AddMMYY = Table.AddColumn(AddSDAM, "Month-Year", each Text.Combine({Date.ToText([Date], "MMM"), "-", Date.ToText([Date], "yy")}), type text), 23 | RemoveDateC = Table.RemoveColumns(AddMMYY, {"Date"}), 24 | AddYear = Table.AddColumn(RemoveDateC, "Year", each Date.Year(Date.From([Selected Day Of Month])), Int64.Type), 25 | AddMonth = Table.AddColumn(AddYear, "Month Number", each Date.Month(Date.From([Selected Day Of Month])), Int64.Type), 26 | AddMonthN = Table.AddColumn(AddMonth, "Month Name", each Date.MonthName(Date.From([Selected Day Of Month])), type text), 27 | AddYMNo = Table.AddColumn( 28 | AddMonthN, 29 | "Year Month Number", 30 | each Text.Combine({Date.ToText(Date.From([Selected Day Of Month]), "yyyy"), Date.ToText(Date.From([Selected Day Of Month]), "MM")}), 31 | type text 32 | ), 33 | ChangeT2 = Table.TransformColumnTypes(AddYMNo, {{"Year Month Number", Int64.Type}}), 34 | SortByDay = Table.Sort(ChangeT2, {{"Selected Day Of Month", Order.Ascending}}), 35 | ChangeT3 = Table.TransformColumnTypes(SortByDay, {{"Selected Day Of Month", type date}}), 36 | QuarterNo = Table.AddColumn(ChangeT3, "Quarter", each Date.QuarterOfYear([Selected Day Of Month]), Int64.Type), 37 | YearQ = Table.AddColumn(QuarterNo, "Year & Quarter", each Text.Combine({Text.From(Date.Year([Selected Day Of Month]), "en-AU"), " Q", Text.From([Quarter], "en-AU")})), 38 | DayofWeek = Table.AddColumn(YearQ, "Day of Week", each Date.DayOfWeek([Selected Day Of Month]), Int64.Type), 39 | Dayname = Table.AddColumn(DayofWeek, "Day Of Week Name", each Text.Proper(Date.ToText([Selected Day Of Month], "dddd")), type text), 40 | StartMonth = Table.AddColumn(Dayname, "First day of month", each Date.StartOfMonth([Selected Day Of Month]), type date), 41 | LastDay = Table.AddColumn(StartMonth, "Last day of month", each Date.EndOfMonth([Selected Day Of Month]), type date), 42 | WeekofYear = Table.AddColumn(StartMonth, "Week Of Year", each Date.WeekOfYear([Selected Day Of Month], Day.Monday), Int64.Type), 43 | DateName = Table.RenameColumns(WeekofYear, {{"Selected Day Of Month", "Date"}}) 44 | in 45 | DateName, 46 | Documentation = [ 47 | Documentation.Name = "fxDate", 48 | Documentation.LongDescription = "Date table function to create a calendar table with a selected day of the month", 49 | Documentation.Author = "Vahid DM", 50 | Documentation.Category = "Table", 51 | Documentation.Version = "0.00", 52 | Documentation.Examples = { 53 | [ 54 | Description = "https://www.vahiddm.com/post/creating-calendat-table-with-3-steps ", 55 | Code 56 | = " Parameters: #(lf) 57 | Day: you can enter one of the below items in this field to create your table: #(lf) 58 | All: If you want to have a calendar table with all dates #(lf) 59 | Last: If you want to create a filtered data table with dates of the last day of #(lf) 60 | each month#(lf) 61 | number: you can enter a number from 1 to 31 in this field to have a filtered #(lf) 62 | data table with the list of the selected day for each month #(lf) 63 | Start.Date: The first date on the Calendar table #(lf) 64 | End.Date: This field is an Optional field and has 2 options: #(lf) 65 | select a date: the date chosen in this field will be the maximum date in your #(lf) 66 | calendar table#(lf) 67 | leave it blank: if you leave this field blank, you will have a Dynamic Calendar #(lf) 68 | Table that will use the current date as the End date. #(lf) 69 | If you Select:[Day.Of.Month]=15,[Start.Date]=20/03/2021,[End.Date]=14/06/2021 70 | " 71 | 72 | , 73 | Result = "{15/03/2021, 15/04/2021,15/05/2021,15/06/2021} " 74 | ] 75 | } 76 | ] 77 | in 78 | Value.ReplaceType(fxDate, Value.ReplaceMetadata(Value.Type(fxDate), Documentation)) 79 | -------------------------------------------------------------------------------- /Calendars/DateTable/StandardCalendarRange/fnMonthlyCalendar.md: -------------------------------------------------------------------------------- 1 | # fnMonthlyCalender 2 | ## Display monthly calendar between start and end year in 1-month imcrements 3 | 4 | 5 | ```ioke 6 | let 7 | fn = // fnMonthlyCalendar 8 | /* ------------------------------ 9 | Author: Imran Haq - PBI QUERYOUS 10 | GitHub: https://github.com/PBIQueryous/M-Code/ 11 | Description: Count number of months between two dates 12 | Credits: Rick de Goot (Guerilla BI) 13 | Link: https://gorilla.bi/power-query/date-table-with-monthly-increments/ 14 | Youtube: https://www.youtube.com/watch?v=eqWLcCBxA08 15 | Site: https://gorilla.bi/ 16 | ---------------------------------*/ 17 | 18 | // invoke function & define parameter inputs 19 | 20 | 21 | let 22 | invokeFn = 23 | ( 24 | Start_Year as number , // input start year as integer 25 | End_Year as number // input end year as integer 26 | )=> 27 | 28 | // ------------------------------------------------------------------ 29 | // function transformations 30 | let 31 | startYear = #date(Start_Year, 1, 1), 32 | endYear = #date(End_Year, 12, 31), 33 | monthList = 34 | List.Generate(() => 35 | startYear , // Starting value (start of year input) 36 | each _ <= endYear, // Create only when <= end of year output (31st Dec) 37 | each Date.AddMonths(_, 1)), // add months in between startYear and endYear in increments of 1 38 | 39 | build_Table = Table.FromList( 40 | monthList, 41 | Splitter.SplitByNothing(), // convert list to table 42 | type table // define table 43 | [ 44 | Date = Date.Type // column "Date" as type date 45 | ], 46 | null, 47 | ExtraValues.Error 48 | ), 49 | 50 | add_Records = Table.AddColumn( 51 | build_Table, 52 | "_Table", 53 | each [ 54 | Year = Date.Year([Date]), // add column for year number 55 | Month = Date.MonthName([Date]), // add column for month name 56 | MonthNUM = Date.Month([Date]), // add column Month Number 57 | MonthYEAR = Date.ToText([Date], "MMM-yy") // add column for short Month and Year, e.g. Jan 2023 58 | ], 59 | type [ 60 | Year = number, // year as number 61 | Month = text, // month as text 62 | MonthNUM = number, // monthNum as number 63 | MonthYEAR = text // monthYear as text 64 | ] 65 | ), 66 | 67 | expandColumns = Table.ExpandRecordColumn( 68 | add_Records, 69 | "_Table", 70 | {"Year", "Month", "MonthNUM", "MonthYEAR"}, // expand records to columns 71 | {"Year", "Month", "MonthNUM", "MonthYEAR"} // (re)name column headers 72 | ) 73 | in 74 | expandColumns 75 | , 76 | 77 | // ------------------------------------------------------------------ 78 | // change parameter metadata here 79 | fnType = type function ( 80 | Start_Year as ( 81 | type text 82 | meta 83 | [ 84 | Documentation.FieldCaption = " Input Start Year: #(lf) (Year Integer) ", 85 | Documentation.FieldDescription = " Input Start Year #(lf) eg: 2023 ", 86 | Documentation.SampleValues = {"2023"} 87 | // or Documentation.AllowedValues = {"Text1", "Text2", "Etc"} for multiple values in dropdown 88 | // Formatting.IsMultiLine = true, for text box with multiple-code lines (eg: for native queries) 89 | // Formatting.IsCode = true, formats text into coding style 90 | ] 91 | ) 92 | , 93 | End_Year as ( 94 | type text 95 | meta 96 | [ 97 | Documentation.FieldCaption = " Input End Year: #(lf) (Year Integer) ", 98 | Documentation.FieldDescription = " Input End Year #(lf) eg: 2025 ", 99 | Documentation.SampleValues = {"2025"} 100 | // or Documentation.AllowedValues = {"Text1", "Text2", "Etc"} for multiple values in dropdown 101 | // Formatting.IsMultiLine = true, for text box with multiple-code lines (eg: for native queries) 102 | // Formatting.IsCode = true, formats text into coding style 103 | ] 104 | ) 105 | ) as list, 106 | // ------------------------------------------------------------------ 107 | // edit function metadata here 108 | documentation = 109 | [ 110 | 111 | Documentation.Name = " fnMonthlyCalendar ", 112 | Documentation.Description = " Generate a calendar in monthly increments between Start & End Year input ", 113 | Documentation.LongDescription = " Generate a calendar in monthly increments between Start & End Year input ", 114 | Documentation.Category = " Dates ", 115 | Documentation.Source = " PBIQUERYOUS ", 116 | Documentation.Version = " 1.0 ", 117 | Documentation.Author = " Imran Haq ", 118 | Documentation.Examples = 119 | { 120 | [ 121 | Description = " Generate a calendar in monthly increments between Start & End Year input ", 122 | Code = " fnMonthlyCalendar( Start_Year , End_Year ) ", 123 | Result = " Table 124 | #(lf) ____________________________ 125 | #(lf) 126 | #(lf) 127 | " 128 | ] 129 | } 130 | 131 | ] 132 | , 133 | 134 | // ------------------------------------------------------------------ 135 | // Choose between Parameter Documentation or Function Documentation 136 | funtionDocumentation = // -- function metadata 137 | Value.ReplaceType(invokeFn, Value.ReplaceMetadata(Value.Type(invokeFn), documentation)), 138 | 139 | parameterDocumentation = // -- parameter metadata 140 | Value.ReplaceType(invokeFn, fnType) 141 | in 142 | // ------------------------------------------------------------------ 143 | // select one of the above steps and paste below 144 | funtionDocumentation /* <-- Choose final documentation type */ 145 | in 146 | fn 147 | ``` 148 | -------------------------------------------------------------------------------- /Calendars/DateTable/StandardCalendarRange/fnMonthlyCalendar.pq: -------------------------------------------------------------------------------- 1 | let 2 | fn = // fnMonthlyCalendar 3 | /* ------------------------------ 4 | Author: Imran Haq - PBI QUERYOUS 5 | GitHub: https://github.com/PBIQueryous/M-Code/ 6 | Description: Count number of months between two dates 7 | Credits: Rick de Goot (Guerilla BI) 8 | Link: https://gorilla.bi/power-query/date-table-with-monthly-increments/ 9 | Youtube: https://www.youtube.com/watch?v=eqWLcCBxA08 10 | Site: https://gorilla.bi/ 11 | ---------------------------------*/ 12 | 13 | // invoke function & define parameter inputs 14 | 15 | 16 | let 17 | invokeFn = 18 | ( 19 | Start_Year as number , // input start year as integer 20 | End_Year as number // input end year as integer 21 | )=> 22 | 23 | // ------------------------------------------------------------------ 24 | // function transformations 25 | let 26 | startYear = #date(Start_Year, 1, 1), 27 | endYear = #date(End_Year, 12, 31), 28 | monthList = 29 | List.Generate(() => 30 | startYear , // Starting value (start of year input) 31 | each _ <= endYear, // Create only when <= end of year output (31st Dec) 32 | each Date.AddMonths(_, 1)), // add months in between startYear and endYear in increments of 1 33 | 34 | build_Table = Table.FromList( 35 | monthList, 36 | Splitter.SplitByNothing(), // convert list to table 37 | type table // define table 38 | [ 39 | Date = Date.Type // column "Date" as type date 40 | ], 41 | null, 42 | ExtraValues.Error 43 | ), 44 | 45 | add_Records = Table.AddColumn( 46 | build_Table, 47 | "_Table", 48 | each [ 49 | EndOfMonth = Date.EndOfMonth([Date]), // add column for year number 50 | Year = Date.Year([Date]), // add column for year number 51 | Month = Date.MonthName([Date]), // add column for month name 52 | MonthNUM = Date.Month([Date]), // add column Month Number 53 | MonthYEAR = Date.ToText([Date], "MMM-yy") // add column for short Month and Year, e.g. Jan 2023 54 | ], 55 | type [ 56 | EndOfMonth = date, // EndOfMOnth as date 57 | Year = number, // year as number 58 | Month = text, // month as text 59 | MonthNUM = number, // monthNum as number 60 | MonthYEAR = text // monthYear as text 61 | ] 62 | ), 63 | 64 | list_FieldNames = Record.FieldNames ( Record.Combine ( add_Records[_Table] ) ), 65 | data_table = add_Records, 66 | expandColumns = Table.ExpandRecordColumn(data_table, "_Table", list_FieldNames, list_FieldNames) 67 | in 68 | expandColumns 69 | , 70 | 71 | // ------------------------------------------------------------------ 72 | // change parameter metadata here 73 | fnType = type function ( 74 | Start_Year as ( 75 | type number 76 | meta 77 | [ 78 | Documentation.FieldCaption = " Input Start Year: #(lf) (Year Integer) ", 79 | Documentation.FieldDescription = " Input Start Year #(lf) eg: 2023 ", 80 | Documentation.SampleValues = {"2023"} 81 | // or Documentation.AllowedValues = {"Text1", "Text2", "Etc"} for multiple values in dropdown 82 | // Formatting.IsMultiLine = true, for text box with multiple-code lines (eg: for native queries) 83 | // Formatting.IsCode = true, formats text into coding style 84 | ] 85 | ) 86 | , 87 | End_Year as ( 88 | type number 89 | meta 90 | [ 91 | Documentation.FieldCaption = " Input End Year: #(lf) (Year Integer) ", 92 | Documentation.FieldDescription = " Input End Year #(lf) eg: 2025 ", 93 | Documentation.SampleValues = {"2025"} 94 | // or Documentation.AllowedValues = {"Text1", "Text2", "Etc"} for multiple values in dropdown 95 | // Formatting.IsMultiLine = true, for text box with multiple-code lines (eg: for native queries) 96 | // Formatting.IsCode = true, formats text into coding style 97 | ] 98 | ) 99 | ) as list, 100 | // ------------------------------------------------------------------ 101 | // edit function metadata here 102 | documentation = 103 | [ 104 | 105 | Documentation.Name = " fnMonthlyCalendar ", 106 | Documentation.Description = " Generate a calendar in monthly increments between Start & End Year input ", 107 | Documentation.LongDescription = " Generate a calendar in monthly increments between Start & End Year input ", 108 | Documentation.Category = " Dates ", 109 | Documentation.Source = " PBIQUERYOUS ", 110 | Documentation.Version = " 1.0 ", 111 | Documentation.Author = " Imran Haq ", 112 | Documentation.Examples = 113 | { 114 | [ 115 | Description = " Generate a calendar in monthly increments between Start & End Year input ", 116 | Code = " fnMonthlyCalendar( Start_Year , End_Year ) ", 117 | Result = " Table 118 | #(lf) ____________________________ 119 | #(lf) 120 | #(lf) 121 | " 122 | ] 123 | } 124 | 125 | ] 126 | , 127 | 128 | // ------------------------------------------------------------------ 129 | // Choose between Parameter Documentation or Function Documentation 130 | funtionDocumentation = // -- function metadata 131 | Value.ReplaceType(invokeFn, Value.ReplaceMetadata(Value.Type(invokeFn), documentation)), 132 | 133 | parameterDocumentation = // -- parameter metadata 134 | Value.ReplaceType(invokeFn, fnType) 135 | in 136 | // ------------------------------------------------------------------ 137 | // select one of the above steps and paste below 138 | parameterDocumentation /* <-- Choose final documentation type */ 139 | in 140 | fn 141 | -------------------------------------------------------------------------------- /Calendars/DateTable/StandardCalendarRange/fn_DateKeyTable_Monthly.pq: -------------------------------------------------------------------------------- 1 | let 2 | output = 3 | (start_date as date, end_date as date, list_of_holidays as list) as table => 4 | let 5 | tb = 6 | #table( 7 | type table [ 8 | Date = date, 9 | Day = Int64.Type, 10 | Month = Int64.Type, 11 | MonthName = text, 12 | Year = Int64.Type, 13 | Quarter = Int64.Type, 14 | DayOfWeek = Int64.Type, 15 | IsWeekend = logical, 16 | Holidays = logical, 17 | HolidayOrWeekend = logical, 18 | EndDayOfMonth = Int64.Type 19 | ], 20 | List.Transform( 21 | List.Dates( 22 | start_date, 23 | ( 24 | Number.From(end_date) 25 | - Number.From(start_date) 26 | ), 27 | #duration(1, 0, 0, 0) 28 | ), 29 | each 30 | let 31 | dt = _, 32 | day = Date.Day(dt), 33 | month = Date.Month(dt), 34 | monthName = Date.ToText(dt, "MMMM", "en-us"), 35 | year = Date.Year(dt), 36 | quarter = Date.QuarterOfYear(dt), 37 | dayOfWeek = Date.DayOfWeek(dt, Day.Monday) + 1, 38 | isWeekend = 39 | if dayOfWeek > 5 then 40 | true 41 | else 42 | false, 43 | holidays = 44 | if 45 | List.Contains( 46 | list_of_holidays, 47 | Number.ToText(day) 48 | & "." 49 | & Number.ToText(month) 50 | ) 51 | then 52 | true 53 | else 54 | false, 55 | holidayorweekend = 56 | if isWeekend or holidays then 57 | true 58 | else 59 | false, 60 | enddayofmonth = Date.Day(Date.EndOfMonth(dt)), 61 | result = { 62 | dt, 63 | day, 64 | month, 65 | monthName, 66 | year, 67 | quarter, 68 | dayOfWeek, 69 | isWeekend, 70 | holidays, 71 | holidayorweekend, 72 | enddayofmonth 73 | } 74 | in 75 | result 76 | ) 77 | ) 78 | in 79 | tb, 80 | documentation = [ 81 | Documentation.Name = " Create-dateKey_newVersion.pq ", 82 | Documentation.Description = " Funcion is creating DateKey table. ", 83 | Documentation.Source = " https://www.jaknapowerbi.cz . ", 84 | Documentation.Version = " 2.0 ", 85 | Documentation.Author = " Štěpán Rešl " 86 | ] 87 | in 88 | Value.ReplaceType( 89 | output, 90 | Value.ReplaceMetadata( 91 | Value.Type(output), 92 | documentation 93 | ) 94 | ) 95 | -------------------------------------------------------------------------------- /Calendars/DateTable/StandardCalendarRange/fn_tempDates.pq: -------------------------------------------------------------------------------- 1 | v_Today = Date.From( DateTime.LocalNow() ), 2 | v_Year = Date.Year( DateTime.LocalNow() ), 3 | v_Month = Date.Month( DateTime.LocalNow() ), 4 | FYStartMonth = 4, 5 | AYStartMonth = 8, 6 | col_Year = Table.AddColumn( col_rename , "YearNUM", each Date.Year([Date]), type number), 7 | // calendar month num 8 | col_MonthNUM = Table.AddColumn( 9 | col_Year, 10 | "MonthNUM", 11 | each Date.Month([Date]), 12 | type number 13 | ), 14 | col_YearMonthID = Table.AddColumn(col_MonthNUM, "YearMonthID", each [YearNUM] * 12 + [MonthNUM], Int64.Type), 15 | col_FiscalYear = Table.AddColumn( col_YearMonthID , "Fiscal Year" , each 16 | if ([MonthNUM] >= FYStartMonth and FYStartMonth > 1) then Text.End(Text.From([YearNUM] + 0), 2) & "/" & Text.End(Text.From([YearNUM] + 1), 2) else Text.End(Text.From([YearNUM] - 1), 2) & "/" & Text.End(Text.From([YearNUM] + 0), 2), type text), 17 | col_AcademicYear = Table.AddColumn( col_FiscalYear , "Academic Year" , each 18 | if ([MonthNUM] >= AYStartMonth and AYStartMonth > 1) then Text.End(Text.From([YearNUM] + 0), 2) & "/" & Text.End(Text.From([YearNUM] + 1), 2) else Text.End(Text.From([YearNUM] - 1), 2) & "/" & Text.End(Text.From([YearNUM] + 0), 2), type text), 19 | col_FiscalMonthNUM = Table.AddColumn(col_AcademicYear, "FiscalMonthNUM", each if ( [MonthNUM] >= FYStartMonth and FYStartMonth > 1 ) then ( [MonthNUM] - (FYStartMonth - 1 )) else if ([MonthNUM] >= FYStartMonth and FYStartMonth = 1 ) then ([MonthNUM] + (12 - FYStartMonth + 1 ) ) else ([MonthNUM] + (12 - FYStartMonth + 1 )), Int64.Type), 20 | col_AcademicMonthNUM = Table.AddColumn(col_FiscalMonthNUM, "AcademicMonthNUM", each if ( [MonthNUM] >= AYStartMonth and AYStartMonth > 1 ) then ( [MonthNUM] - (AYStartMonth - 1 )) else if ([MonthNUM] >= AYStartMonth and AYStartMonth = 1 ) then ([MonthNUM] + (12 - AYStartMonth + 1 ) ) else ([MonthNUM] + (12 - AYStartMonth + 1 )), Int64.Type), 21 | // calendar month and year as integer key (20230001) 22 | col_MonthYearINT = Table.AddColumn( 23 | col_AcademicMonthNUM, 24 | "YearMonthINT", 25 | each [YearNUM] * 100 + [MonthNUM], 26 | type number 27 | ), 28 | col_FiscalYearMonthINT = Table.AddColumn( 29 | col_MonthYearINT, 30 | "FiscalYearMonthINT", 31 | each [YearNUM] * 100 + [FiscalMonthNUM], 32 | type number 33 | ), 34 | col_AcademicYearMonthINT = Table.AddColumn( 35 | col_FiscalYearMonthINT, 36 | "AcademicYearMonthINT", 37 | each [YearNUM] * 100 + [AcademicMonthNUM], 38 | type number 39 | ), 40 | col_FiscalMonthShort = Table.DuplicateColumn(col_AcademicYearMonthINT, "Month Short", "Fiscal Month Short"), 41 | col_AcademicMonthShort = Table.DuplicateColumn(col_FiscalMonthShort, "Fiscal Month Short", "Academic Month Short"), 42 | col_MonthYear = Table.AddColumn( col_AcademicMonthShort , "Month-Year" , each 43 | if ([MonthNUM] >= AYStartMonth and AYStartMonth > 1) then [Month Short] & "-" & Text.End(Text.From([YearNUM]), 2) else [Month Short] & "-" & Text.End(Text.From([YearNUM]), 2), type text), 44 | col_FiscalMonthYear = Table.DuplicateColumn(col_MonthYear, "Month-Year", "Fiscal Month-Year"), 45 | col_AcademicMonthYear = Table.DuplicateColumn(col_FiscalMonthYear, "Month-Year", "Academic Month-Year"), 46 | col_FiscalQuarterNUM = Table.AddColumn(col_AcademicMonthYear, "FiscalQuarterNUM", each "Q" & Text.From( Number.RoundUp(Date.Month(Date.AddMonths([Date], - (FYStartMonth - 1))) / 3)), Text.Type), 47 | col_AcademicQuarterNUM = Table.AddColumn(col_FiscalQuarterNUM, "AcademicQuarterNUM", each "Q" & Text.From( Number.RoundUp(Date.Month(Date.AddMonths([Date], - (AYStartMonth - 1))) / 3)), Text.Type), 48 | col_YearOFFSET = Table.AddColumn( 49 | col_AcademicQuarterNUM, 50 | "YearOFFSET", 51 | each Date.Year([Date]) - v_Year, 52 | type number 53 | ), 54 | col_FiscalYearOFFSET = Table.AddColumn( 55 | col_YearOFFSET, 56 | "FiscalYearOFFSET", 57 | each 58 | (if [MonthNUM] >= FYStartMonth then [YearNUM] + 1 else [YearNUM]) 59 | - (if v_Month >= FYStartMonth then v_Year + 1 else v_Year), 60 | type number 61 | ), 62 | col_AcademicYearOFFSET = Table.AddColumn( 63 | col_FiscalYearOFFSET, 64 | "AcademicYearOFFSET", 65 | each 66 | (if [MonthNUM] >= AYStartMonth then [YearNUM] + 1 else [YearNUM]) 67 | - (if v_Month >= AYStartMonth then v_Year + 1 else v_Year), 68 | type number 69 | ), 70 | // calendar month offset 71 | col_MonthOFFSET = Table.AddColumn( 72 | col_AcademicYearOFFSET, 73 | "MonthOFFSET", 74 | each ((12 * Date.Year([Date])) + Date.Month([Date])) 75 | - ( 76 | (12 * v_Year) 77 | + v_Month 78 | ), 79 | type number 80 | ), 81 | // is current calendar year complete as boolean 82 | col_isYTD = Table.AddColumn( 83 | col_MonthOFFSET, 84 | "IsInYearToDate", 85 | each Date.IsInYearToDate([Date]) , 86 | type logical 87 | ), 88 | col_isFuture = Table.AddColumn( 89 | col_isYTD, 90 | "isFuture", 91 | each not Date.IsInYearToDate([Date]) , 92 | type logical 93 | ), 94 | col_isYearComplete = Table.AddColumn(col_isFuture, "isYearComplete", each if [YearOFFSET] < 0 then true else false, type logical), 95 | col_isFYComplete = Table.AddColumn(col_isYearComplete, "isFYComplete", each if [FiscalYearOFFSET] < 0 then true else false, type logical), 96 | col_isAYComplete = Table.AddColumn(col_isFYComplete, "IsAYComplete", each if [AcademicYearOFFSET] < 0 then true else false, type logical), 97 | col_isCFY = Table.AddColumn(col_isAYComplete, "isCFY", each if [FiscalYearOFFSET] = 0 then true else false , type logical), 98 | col_isCAY = Table.AddColumn(col_isCFY, "isAFY", each if [AcademicYearOFFSET] = 0 then true else false, type logical) 99 | in 100 | col_isCAY 101 | -------------------------------------------------------------------------------- /Calendars/DynamicDatesListDEMO/ForGuerillaBI_DynamicListMonths.pbix: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/PBI-DataVizzle/M-Code/24af47fcc96261d43f3c56e7c8f2175d6b55e992/Calendars/DynamicDatesListDEMO/ForGuerillaBI_DynamicListMonths.pbix -------------------------------------------------------------------------------- /Calendars/DynamicDatesListDEMO/readme.md: -------------------------------------------------------------------------------- 1 | 2 | -------------------------------------------------------------------------------- /Calendars/Fiscal_Calendar_Period_Functions/fnFiscalQuarterOffset.md: -------------------------------------------------------------------------------- 1 | # fnFiscalQuarterOFFSET 2 | 3 | ``` ioke 4 | = let 5 | fxAddFiscalQuarterOffset = (Date as date, FiscalYearStartMonth as number) as number => 6 | let 7 | CurrentDate = Date.From(DateTime.LocalNow()), 8 | n = 9 | if List.Contains({1 .. 12}, FiscalYearStartMonth) and FiscalYearStartMonth > 1 then 10 | FiscalYearStartMonth - 1 11 | else 12 | 0, 13 | FiscalQuarterOffset = ( 14 | (4 * Date.Year(Date.AddMonths(Date.StartOfMonth(Date), - n))) 15 | + Date.QuarterOfYear(Date.AddMonths(Date.StartOfMonth(Date), - n)) 16 | ) 17 | - ( 18 | (4 * Date.Year(Date.AddMonths(Date.StartOfMonth(CurrentDate), - n))) 19 | + Date.QuarterOfYear(Date.AddMonths(Date.StartOfMonth(CurrentDate), - n)) 20 | ) 21 | in 22 | FiscalQuarterOffset, 23 | Documentation = [ 24 | Documentation.Name = " fxAddFiscalQuarterOffset", 25 | Documentation.Description = " Add a fiscal quarter offset", 26 | Documentation.LongDescription = " M function to add a fiscal quarter offset to your date table", 27 | Documentation.Category = " Table", 28 | Documentation.Version = " 0.01: Initial version", 29 | Documentation.Source = " local", 30 | Documentation.Author = " Melissa de Korte", 31 | Documentation.Examples = { 32 | [ 33 | Description = " ", 34 | Code 35 | = " Required paramters: #(lf) 36 | (Date) The field that contains the unique date value for each date in the date table #(lf) 37 | (FiscalYearStartMonth) Month number the fiscal year starts, January if omitted", 38 | Result = " " 39 | ] 40 | } 41 | ] 42 | in 43 | Value.ReplaceType( 44 | fxAddFiscalQuarterOffset, 45 | Value.ReplaceMetadata(Value.Type(fxAddFiscalQuarterOffset), Documentation) 46 | ) 47 | 48 | ``` 49 | -------------------------------------------------------------------------------- /Calendars/Fiscal_Calendar_Period_Functions/fn_GetFiscalPeriod.md: -------------------------------------------------------------------------------- 1 | # fn_GetFiscalPeriod 2 | ## Get Fiscal Period Number from Calendar Month Number 3 | 4 | ``` ioke 5 | 6 | let 7 | function1 = // fnGetFiscalPeriod 8 | /* ------------------------------ 9 | Author: Imran Haq - PBI QUERYOUS 10 | Description: Get Fiscal Period from Month Number column 11 | ---------------------------------*/ 12 | 13 | // invoke function & define parameter inputs 14 | let 15 | invokeFunction = (monthNum as any, fiscalMonthNum as nullable number) => 16 | 17 | // ------------------------------------------------------------------ 18 | // function transformations 19 | let 20 | arg1 = monthNum >= fiscalMonthNum and fiscalMonthNum > 1, // 1st argument 21 | res1 = monthNum - (fiscalMonthNum - 1), // 1st result 22 | arg2 = monthNum >= fiscalMonthNum and fiscalMonthNum = 1, // 2nd argument 23 | res2 = monthNum, // 2nd result 24 | res3 = monthNum + (12-fiscalMonthNum+1), // 3rd result 25 | result = if arg1 then res1 else if arg2 then res2 else res3 // final result 26 | in 27 | result 28 | 29 | , 30 | 31 | // ------------------------------------------------------------------ 32 | // change parameter metadata here 33 | fnType = type function ( 34 | monthNum as ( 35 | type any 36 | meta 37 | [ 38 | Documentation.FieldCaption = " Select column with Month Number ", 39 | Documentation.FieldDescription = " Select a column #(cr,lf) eg: [Month Number] ", 40 | Documentation.SampleValues = {"[MonthNumber]"} 41 | ] 42 | ), 43 | fiscalMonthNum as ( 44 | type number 45 | meta 46 | [ 47 | Documentation.FieldCaption = " Choose Fiscal Month Start ", 48 | Documentation.FieldDescription = " Fiscal Month Start #(cr,lf) (eg: Aug = 8) ", 49 | Documentation.AllowedValues = {1..12} 50 | ] 51 | ) 52 | ) as list, 53 | // ------------------------------------------------------------------ 54 | // edit function metadata here 55 | documentation = 56 | [ 57 | 58 | Documentation.Name = " fnGetCalendarMonth ", 59 | Documentation.Description = " Retrieves correct calendar month based on a fiscal period number ", 60 | Documentation.LongDescription = " Retrieves correct calendar month based on a fiscal period number ", 61 | Documentation.Category = " Fiscal Calendar Category ", 62 | Documentation.Source = " PBIQUERYOUS ", 63 | Documentation.Version = " 1.0 ", 64 | Documentation.Author = " Imran Haq ", 65 | Documentation.Examples = 66 | { 67 | [ 68 | Description = " ColumnName = [Column1]; Fiscal Month Start = 4 ", 69 | Code = " 70 | let #(cr,lf) 71 | fiscalMonth = if fiscalStart = null then 1 else fiscalStart, #(cr,lf) 72 | columnName = fiscalPeriod, #(cr,lf) 73 | calc = (12-fiscalMonth)+1, #(cr,lf) 74 | x = Number.Abs(columnName + fiscalMonth) - 1, #(cr,lf) 75 | y = Number.Abs(columnName + fiscalMonth) - 13, #(cr,lf) 76 | z = if columnName <= calc then x else y #(cr,lf) 77 | in #(cr,lf) 78 | z 79 | ", 80 | Result = " fnGetCalendarMonth([Column1], 4) " 81 | ] 82 | } 83 | 84 | ] 85 | , 86 | 87 | // ------------------------------------------------------------------ 88 | // Choose between Parameter Documentation or Function Documentation 89 | functionDocumentation = // -- function metadata 90 | Value.ReplaceType(invokeFunction, Value.ReplaceMetadata(Value.Type(invokeFunction), documentation)), 91 | 92 | parameterDocumentation = // -- parameter metadata 93 | Value.ReplaceType(invokeFunction, fnType) 94 | in 95 | // ------------------------------------------------------------------ 96 | // select one of the above steps and paste below 97 | parameterDocumentation /* <-- Choose final documentation type */ 98 | in 99 | function1 100 | 101 | ``` 102 | -------------------------------------------------------------------------------- /Calendars/Fiscal_Calendar_Period_Functions/fn_GetMonthFromFiscalPeriod_v1.md: -------------------------------------------------------------------------------- 1 | # fn_GetMonthFromFiscalPeriod_v1 2 | ## Get month number from Fiscal Period 3 | 4 | ``` ioke 5 | 6 | let 7 | fn = // fnGetMonthFromFP 8 | /* ------------------------------ 9 | Author: Imran Haq - PBI QUERYOUS 10 | GitHub: https://github.com/PBIQueryous/M-Code/ 11 | Description: Takes Fiscal Period and Converts to Month Number 12 | Credits: Gilbert Quevauvilliers 13 | Link: https://gqbi.wordpress.com/2016/09/13/power-bi-how-to-easily-create-dynamic-date-tabledimension-with-fiscal-attributes-using-power-query/comment-page-1/ 14 | Site: https://gqbi.wordpress.com/ 15 | ---------------------------------*/ 16 | 17 | // invoke function & define parameter inputs 18 | let 19 | invokeFn = (dateColumn as any, fiscalMonthNumber as number) => 20 | 21 | // ------------------------------------------------------------------ 22 | // function transformations 23 | let 24 | fiscalMonthStart = List.Select({1 .. 12}, each _ = fiscalMonthNumber){0}? ?? 1, // ensure valid number 25 | fiscalMonthCalc = 10 + fiscalMonthStart, // calculation 1 26 | calculation = Number.Mod(dateColumn + fiscalMonthCalc , 12) + 1, // calculation 2 27 | Result = calculation // result 28 | in 29 | Result 30 | , 31 | 32 | // ------------------------------------------------------------------ 33 | // change parameter metadata here 34 | fnType = type function ( 35 | dateColumn as ( 36 | type any 37 | meta 38 | [ 39 | Documentation.FieldCaption = " Select Fiscal Period Column ", 40 | Documentation.FieldDescription = " Select Fiscal Period Column (eg: [Fiscal Period]) ", 41 | Documentation.SampleValues = {"[Fiscal Period Column]"} 42 | ] 43 | ), 44 | fiscalMonthNumber as ( 45 | type number 46 | meta 47 | [ 48 | Documentation.FieldCaption = " Select Fiscal Month Start ", 49 | Documentation.FieldDescription = " Fiscal Month { 1..12 } ", 50 | Documentation.AllowedValues = {1..12} 51 | ] 52 | ) 53 | ) as list, 54 | // ------------------------------------------------------------------ 55 | // edit function metadata here 56 | documentation = 57 | [ 58 | 59 | Documentation.Name = " fnGetMonthFromFP ", 60 | Documentation.Description = " Takes Fiscal Period and Converts to Month Number ", 61 | Documentation.LongDescription = " Takes Fiscal Period and Converts to Month Number ", 62 | Documentation.Category = " Fiscal Date ", 63 | Documentation.Source = " PBIQUERYOUS ", 64 | Documentation.Version = " 1.0 ", 65 | Documentation.Author = " Imran Haq ", 66 | Documentation.Examples = 67 | { 68 | [ 69 | Description = " ExampleDescription ", 70 | Code = " = Number.Mod(dateColumn + fiscalMonthCalc , 12)+1 ", 71 | Result = " ExampleOutput 72 | #(lf) 73 | #(lf) 74 | " 75 | ] 76 | } 77 | 78 | ] 79 | , 80 | 81 | // ------------------------------------------------------------------ 82 | // Choose between Parameter Documentation or Function Documentation 83 | funtionDocumentation = // -- function metadata 84 | Value.ReplaceType(invokeFn, Value.ReplaceMetadata(Value.Type(invokeFn), documentation)), 85 | 86 | parameterDocumentation = // -- parameter metadata 87 | Value.ReplaceType(invokeFn, fnType) 88 | in 89 | // ------------------------------------------------------------------ 90 | // select one of the above steps and paste below 91 | parameterDocumentation /* <-- Choose final documentation type */ 92 | in 93 | fn 94 | 95 | ``` 96 | -------------------------------------------------------------------------------- /Calendars/Fiscal_Calendar_Period_Functions/fn_GetMonthFromFiscalPeriod_v2.md: -------------------------------------------------------------------------------- 1 | # fn_GetMonthFromFiscalPeriod 2 | ## Get calendar month number from fiscal period number 3 | 4 | ``` ioke 5 | 6 | let 7 | function1 = // fnGetCalendarMonth 8 | /* ------------------------------ 9 | Author: Imran Haq - PBI QUERYOUS 10 | Description: Get Calendar Month Number from Fiscal Period Number 11 | ---------------------------------*/ 12 | 13 | // invoke function & define parameter inputs 14 | let 15 | invokeFunction = (fiscalPeriod as any, fiscalStart as number) => 16 | 17 | // ------------------------------------------------------------------ 18 | // function transformations 19 | let 20 | fiscalMonth = if fiscalStart = null then 1 else fiscalStart, // if null then 1 else fiscal month number 21 | columnName = fiscalPeriod, // fiscal month column 22 | calc = (12-fiscalMonth)+1, // calculation 23 | x = Number.Abs(columnName + fiscalMonth) - 1, 24 | y = Number.Abs(columnName + fiscalMonth) - 13, 25 | z = if columnName <= calc then x else y // if FiscalPeriod <= Calculation then x else y 26 | in 27 | z 28 | , 29 | 30 | // ------------------------------------------------------------------ 31 | // change parameter metadata here 32 | fnType = type function ( 33 | fiscalPeriod as ( 34 | type any 35 | meta 36 | [ 37 | Documentation.FieldCaption = " Choose column with Fiscal Month number ", 38 | Documentation.FieldDescription = " Select a column #(cr,lf) eg: [Fiscal Month] ", 39 | Documentation.SampleValues = {"[FiscalMonth]"} 40 | ] 41 | ), 42 | fiscalStart as ( 43 | type number 44 | meta 45 | [ 46 | Documentation.FieldCaption = " Choose Fiscal Month Start ", 47 | Documentation.FieldDescription = " Fiscal Month Start #(cr,lf) Choose a month number ", 48 | Documentation.AllowedValues = {1..12} 49 | ] 50 | ) 51 | ) as list, 52 | // ------------------------------------------------------------------ 53 | // edit function metadata here 54 | documentation = 55 | [ 56 | 57 | Documentation.Name = " fnGetCalendarMonth ", 58 | Documentation.Description = " Retrieves correct calendar month based on a fiscal period number ", 59 | Documentation.LongDescription = " Retrieves correct calendar month based on a fiscal period number ", 60 | Documentation.Category = " Fiscal Calendar Category ", 61 | Documentation.Source = " PBIQUERYOUS ", 62 | Documentation.Version = " 1.0 ", 63 | Documentation.Author = " Imran Haq ", 64 | Documentation.Examples = 65 | { 66 | [ 67 | Description = " ColumnName = [Column1]; Fiscal Month Start = 4 ", 68 | Code = " 69 | let #(cr,lf) 70 | fiscalMonth = if fiscalStart = null then 1 else fiscalStart, #(cr,lf) 71 | columnName = fiscalPeriod, #(cr,lf) 72 | calc = (12-fiscalMonth)+1, #(cr,lf) 73 | x = Number.Abs(columnName + fiscalMonth) - 1, #(cr,lf) 74 | y = Number.Abs(columnName + fiscalMonth) - 13, #(cr,lf) 75 | z = if columnName <= calc then x else y #(cr,lf) 76 | in #(cr,lf) 77 | z 78 | ", 79 | Result = " fnGetCalendarMonth([Column1], 4) " 80 | ] 81 | } 82 | 83 | ] 84 | , 85 | 86 | // ------------------------------------------------------------------ 87 | // Choose between Parameter Documentation or Function Documentation 88 | functionDocumentation = // -- function metadata 89 | Value.ReplaceType(invokeFunction, Value.ReplaceMetadata(Value.Type(invokeFunction), documentation)), 90 | 91 | parameterDocumentation = // -- parameter metadata 92 | Value.ReplaceType(invokeFunction, fnType) 93 | in 94 | // ------------------------------------------------------------------ 95 | // select one of the above steps and paste below 96 | parameterDocumentation /* <-- Choose final documentation type */ 97 | in 98 | function1 99 | 100 | ``` 101 | -------------------------------------------------------------------------------- /Calendars/TimeTable/fnTimeTable.md: -------------------------------------------------------------------------------- 1 | # fnTimeTable 2 | 3 | ```ioke 4 | let 5 | fn = () => 6 | let 7 | Source = List.Times( 8 | #time(0, 0, 0), 9 | Duration.TotalSeconds(#duration(1, 0, 0, 0)), 10 | #duration(0, 0, 0, 1) 11 | ), 12 | list_ToTable = Table.TransformColumnTypes( 13 | Table.FromList(Source, Splitter.SplitByNothing(), {"Second"}), 14 | {{"Second", type time}} 15 | ), 16 | col_Hour = Table.AddColumn(list_ToTable, "Hour", each Time.Hour([Second]), Int64.Type), 17 | col_Minute = Table.AddColumn(col_Hour, "Minute", each Time.Minute([Second]), Int64.Type), 18 | col_5mins = Table.AddColumn( 19 | col_Minute, 20 | "5 min", 21 | each #time(0, Number.IntegerDivide(Time.Minute([Second]), 5) * 5, 0), 22 | Time.Type 23 | ), 24 | col_15mins = Table.AddColumn( 25 | col_5mins, 26 | "15 min", 27 | each #time(0, Number.IntegerDivide(Time.Minute([Second]), 15) * 15, 0), 28 | Time.Type 29 | ), 30 | col_30mins = Table.AddColumn( 31 | col_15mins, 32 | "30 min", 33 | each #time(0, Number.IntegerDivide(Time.Minute([Second]), 30) * 30, 0), 34 | Time.Type 35 | ), 36 | col_12hr = Table.AddColumn( 37 | col_30mins, 38 | "12hr", 39 | each 40 | let 41 | x1 = Number.Mod([Hour], 12), 42 | x2 = if x1 = 0 then 12 else x1 43 | in 44 | x2, 45 | Int64.Type 46 | ), 47 | col_AMPM = Table.AddColumn( 48 | col_12hr, 49 | "AM/PM", 50 | each if [Hour] < 12 then "AM" else "PM", 51 | type text 52 | ), 53 | col_24hrLabel = Table.AddColumn( 54 | col_AMPM, 55 | "24hr Label", 56 | each Text.PadStart(Text.From([Hour]), 2, "0"), 57 | type text 58 | ), 59 | col_12hrLabel = Table.AddColumn( 60 | col_24hrLabel, 61 | "12hr Label", 62 | each Text.Combine({Text.From([12hr], "en-GB"), [#"AM/PM"]}, " "), 63 | type text 64 | ), 65 | cols_Reorder = Table.ReorderColumns( 66 | col_12hrLabel, 67 | { 68 | "24hr Label", 69 | "12hr", 70 | "AM/PM", 71 | "12hr Label", 72 | "Second", 73 | "Hour", 74 | "Minute", 75 | "5 min", 76 | "15 min", 77 | "30 min" 78 | } 79 | ), 80 | HrMin_Label = Table.TransformColumnTypes( 81 | Table.DuplicateColumn(cols_Reorder, "Second", "HourMinute"), 82 | {{"HourMinute", type text}} 83 | ) 84 | in 85 | HrMin_Label 86 | in 87 | fn 88 | 89 | ``` 90 | -------------------------------------------------------------------------------- /Calendars/_archive/YearGroupsMisc.pq: -------------------------------------------------------------------------------- 1 | = Table.AddColumn( 2 | col_Last15Months, 3 | "AcademicYear Group", 4 | each 5 | let 6 | cond1 = [Academic CurrYearOffset] <= - 2, 7 | prev = List.Max( 8 | Table.SelectRows(col_Last15Months, each ([Academic CurrYearOffset] <= - 2))[Academic Year] 9 | ) 10 | & "-", 11 | cond2 = [Academic CurrYearOffset] >= 2, 12 | future = List.Max( 13 | Table.SelectRows(col_Last15Months, each ([Academic CurrYearOffset] >= 2))[Academic Year] 14 | ) 15 | & "+", 16 | result = if cond1 then prev else if cond2 then future else [Academic Year] 17 | in 18 | result, 19 | type text 20 | ) 21 | -------------------------------------------------------------------------------- /Functions/(Un)Pivot/UnpivotMultipleColumns.md: -------------------------------------------------------------------------------- 1 | # Unpivot Groups of Columns 2 | 3 | ```js 4 | let 5 | Source = DataTable, 6 | // select columns and generate list of code 7 | selectColumns = Table.SelectColumns( 8 | Source, 9 | { 10 | "School", 11 | "FileName", 12 | "ID", 13 | "Term", 14 | "Student", 15 | "Primary Sector Job", 16 | "Primary Career Aspiration", 17 | "Secondary Sector Job", 18 | "Secondary Career Aspiration", 19 | "Terciary Sector Job", 20 | "Terciary Career Aspiration" 21 | } 22 | ), 23 | // use previous list of columns to select columns for List.Zip function 24 | listZipColumns = 25 | { 26 | "Primary Sector Job", 27 | "Primary Career Aspiration", 28 | "Secondary Sector Job", 29 | "Secondary Career Aspiration", 30 | "Terciary Sector Job", 31 | "Terciary Career Aspiration" 32 | }, 33 | addListZip = Table.AddColumn( 34 | selectColumns, 35 | "Custom", 36 | each List.Zip( 37 | // Group 1 - Attributes 38 | { 39 | {"Primary", 40 | "Secondary", 41 | "Terciary" 42 | }, 43 | // Group 2 - Values 1 44 | { 45 | [Primary Career Job], 46 | [Secondary Career Job], 47 | [Terciary Career Job] 48 | }, 49 | // Group 3 - Values 2 50 | { 51 | [Primary Career Aspiration], 52 | [Secondary Career Aspiration], 53 | [Terciary Career Aspiration] 54 | } 55 | // add additional column groups as list (as required) 56 | /* , 57 | * { 58 | * [ColumnGroupC1] 59 | * [ColumnGroupC2] 60 | * [ColumnGroupC3] 61 | * } 62 | */ 63 | } 64 | ) 65 | ), 66 | removeGroupColumns = Table.RemoveColumns( 67 | // use previous var listZipColumns as list argument to remove those columns as no longer needed 68 | addListZip, listZipColumns 69 | ), 70 | expandLists = Table.ExpandListColumn(removeGroupColumns, "Custom"), 71 | expandValues = Table.TransformColumns( 72 | expandLists, 73 | {"Custom", each Text.Combine(List.Transform(_, Text.From), ";"), type text} 74 | ), 75 | // Split lists by delimiter - remember to rename columns within code here 76 | splitColumns = Table.SplitColumn( 77 | expandValues, 78 | "Custom", 79 | Splitter.SplitTextByDelimiter(";", QuoteStyle.Csv), 80 | { // rename columns 81 | "Primary/Secondary/Terciary", 82 | "Sector", 83 | "Aspiration" 84 | } 85 | ), 86 | formatColumns = Table.TransformColumnTypes( 87 | splitColumns, 88 | { 89 | {"Primary/Secondary/Terciary", type text}, 90 | {"Sector", type text}, 91 | {"Aspiration", type text} 92 | } 93 | ) 94 | in 95 | formatColumns 96 | 97 | ``` 98 | -------------------------------------------------------------------------------- /Functions/(Un)Pivot/UnpivotMultipleColumns_v0.md: -------------------------------------------------------------------------------- 1 | # Unpivot Multiple Columns 2 | ## List.Zip() 3 | 4 | ```C# 5 | addListZip = Table.AddColumn( 6 | selectColumns, 7 | "Custom", 8 | each List.Zip( 9 | // Group 1 - Attributes 10 | { { 11 | "Attribute1", 12 | "Attribute2", 13 | "Attribute3" 14 | }, 15 | // Group 2 - Values 1 16 | { 17 | [ColumnGroupA1], 18 | [ColumnGroupA2], 19 | [ColumnGroupA3] 20 | }, 21 | // Group 3 - Values 2 22 | { 23 | [ColumnGroupB1], 24 | [ColumnGroupB2], 25 | [ColumnGroupB3] 26 | } 27 | // add additional column groups as list (as required) 28 | /* , 29 | * { 30 | * [ColumnGroupC1] 31 | * [ColumnGroupC2] 32 | * [ColumnGroupC3] 33 | * } 34 | */ 35 | })) 36 | ``` 37 | -------------------------------------------------------------------------------- /Functions/AdvancedETL/ETLfunctions.md: -------------------------------------------------------------------------------- 1 | ```c# 2 | // Function Code 3 | = (QueryStart as table) => 4 | 5 | // Remove Top Rows upt Specified Rows 6 | = Table.Skip(PrevSTEP, each[Column1] <> "TEXT") 7 | 8 | // Remove Bottom Rows upto Specified Rows 9 | = Table.RemoveLastN(Custom1, each[Column1] <> "TEXT") 10 | 11 | // Remove First Rows upto Specified Rows 12 | = Table.RemoveFirstN(Prep,each [Column1] <> "TEXT") 13 | 14 | // Replace Values where the Text Starts with Specific Characters 15 | = Table.ReplaceValue(PrevSTEP,each [Column1],each if Text.StartsWith([Column1], ";0") then "" else null,Replacer.ReplaceText,{"Column1"}) 16 | 17 | // Remove rows until first null 18 | = Table.FirstN(PrevSTEP,each [Column1] <> null) 19 | 20 | // Remove nulls until first value 21 | = Table.RemoveFirstN(PrevSTEP,each [Column1] = null) 22 | 23 | // Keep Rows until Desired Text Found in Column 24 | = Table.FirstN(PrevSTEP,each [Column1] <> "TEXT") 25 | 26 | // Table Schema 27 | Table.Schema 28 | 29 | // Count Splits 30 | = Table.AddColumn(#"Removed Columns2", "Count Item", each List.Count(Text.Split([Custom],";"))) 31 | = Table.AddColumn(LISTcount, "Custom.1", each List.NonNullCount(Text.Split([Custom], ";" ))) 32 | 33 | 34 | // Get Previous Rows 35 | = Table.AddColumn(IDnext, "IDprevPos", each 36 | try 37 | // PrevStep[columnName]{0} 38 | prevStep[columnName]{[indexColumn]-1} 39 | otherwise null) 40 | 41 | // Get Next Rows 42 | = Table.AddColumn(IDpos, "IDnextPos", each 43 | try 44 | prevStep[columnName]{[indexColumn]+1} 45 | otherwise null) 46 | 47 | // Days Laps Examples 48 | Table.AddColumn(ADDindex1, "Stage Days Lapsed", each try 49 | if [Stage] = "Date S/L Complete" then [Days Lapsed] else [Days Lapsed] - ADDindex1[Days Lapsed]{[Index0]-1} 50 | otherwise null, Int64.Type) 51 | ``` 52 | -------------------------------------------------------------------------------- /Functions/BulkReplace/fnBulkReplace.md: -------------------------------------------------------------------------------- 1 | # fnBulkReplace 2 | ## Bulk Replace Characters 3 | 4 | ```C# 5 | let BulkReplace = (DataTable as table, FindReplaceTable as table, DataTableColumn as list) => 6 | let 7 | //Convert the FindReplaceTable to a list using the Table.ToRows function 8 | //so we can reference the list with an index number 9 | FindReplaceList = Table.ToRows(FindReplaceTable), 10 | //Count number of rows in the FindReplaceTable to determine 11 | //how many iterations are needed 12 | Counter = Table.RowCount(FindReplaceTable), 13 | //Define a function to iterate over our list 14 | //with the Table.ReplaceValue function 15 | BulkReplaceValues = (DataTableTemp, n) => 16 | let 17 | //Replace values using nth item in FindReplaceList 18 | ReplaceTable = Table.ReplaceValue( 19 | DataTableTemp, 20 | //replace null with empty string in nth item 21 | if FindReplaceList{n}{0} = null then "" else FindReplaceList{n}{0}, 22 | if FindReplaceList{n}{1} = null then "" else FindReplaceList{n}{1}, 23 | Replacer.ReplaceText, 24 | DataTableColumn 25 | ) 26 | in 27 | //if we are not at the end of the FindReplaceList 28 | //then iterate through Table.ReplaceValue again 29 | if n = Counter - 1 30 | then ReplaceTable 31 | else @BulkReplaceValues(ReplaceTable, n + 1), 32 | //Evaluate the sub-function at the first row 33 | Output = BulkReplaceValues(DataTable, 0) 34 | in 35 | Output 36 | // custom function step: = fnBulkReplace(PreviousStep, ReplacementTable, {"Period"} ) 37 | // explained: = FUNCTION_NAME(PREVIOUS_STEP, TABLE_WITH_OLD_AND_NEW_VALUES, {"COLUMN_NAME_FROM_PREVIOUS_STEP"} ) 38 | in 39 | BulkReplace 40 | ``` 41 | -------------------------------------------------------------------------------- /Functions/CheckForDups/fnCheckForDups.md: -------------------------------------------------------------------------------- 1 | ``` ioke 2 | //Chech if there are duplicate rows in the table. Return Error if any 3 | _CountRows1 = Table.RowCount(<#"Previous Step">), 4 | #"Removed Duplicates" = Table.Distinct(#"Previous Step", {<"Column Name">}), 5 | _CountRows2 = Table.RowCount(#"Removed Duplicates"), 6 | _Error = 7 | error [ 8 | Reason = "DuplicateRecords", 9 | Message = "Duplicate records", 10 | Detail = "Duplicate records found in <[Column Name]> column" 11 | ], 12 | Result = if _CountRows2 = _CountRows1 then #"Removed Duplicates" else _Error 13 | 14 | 15 | ``` 16 | -------------------------------------------------------------------------------- /Functions/CleanString/fnCleanString.pq: -------------------------------------------------------------------------------- 1 | (OriginalString as text) => 2 | let 3 | DirtyString = OriginalString, 4 | CharactersToKeep = 5 | let 6 | CapitalAlphabets = { "A" .. "Z" }, 7 | CursiveAlphabets = { "a" .. "z" }, 8 | Numbers = { 0 .. 9 }, 9 | NumbersAsText = List.Transform ( Numbers, each Number.ToText (_) ), 10 | RemainingCharacters = { " ", ".", "," } 11 | in 12 | CapitalAlphabets & CursiveAlphabets & CursiveAlphabets & RemainingCharacters, 13 | Result = Text.Select ( DirtyString, CharactersToKeep ) 14 | in 15 | Result 16 | -------------------------------------------------------------------------------- /Functions/CleanTextByCase/fn_CleanTextByCase.md: -------------------------------------------------------------------------------- 1 | # fn_CleanTextByCase 2 | ## clean text string by character transition, including underscores 3 | 4 | ```ioke 5 | 6 | splitText = Table.AddColumn( 7 | prevStep, "Custom", each 8 | Text.Combine( 9 | Splitter.SplitTextByCharacterTransition({"a".."z"},{"A".."Z"}) 10 | (Text.Replace([Column1], "_", "")) 11 | , " " 12 | ) 13 | ) 14 | 15 | ``` 16 | 17 | 18 | ## Using Transform Columns instead of Add Column 19 | 20 | 21 | ```ioke 22 | 23 | = Table.TransformColumns( 24 | col_ProgrammeDataSource, 25 | {{"Aptem Program Status", each Text.Combine( 26 | Splitter.SplitTextByCharacterTransition({"a".."z"},{"A".."Z"}) 27 | (Text.Replace(_, "_", "")) 28 | , " " 29 | ), 30 | type text}}) 31 | 32 | ``` 33 | -------------------------------------------------------------------------------- /Functions/ColumnNamesFix/fnColumnNamesFix.md: -------------------------------------------------------------------------------- 1 | ``` ioke 2 | //Function to change column name from 'thiIsColumnName' format to 'This Is Column Name' format 3 | = (_ColumnName as text) => 4 | let 5 | #"Added Custom" = Text.ToList (_ColumnName), 6 | #"Converted to Table" = Table.FromList(#"Added Custom", Splitter.SplitByNothing(), null, null, ExtraValues.Error), 7 | #"Renamed Columns" = Table.RenameColumns(#"Converted to Table",{{"Column1", "ListOfCharacters"}}), 8 | #"Added Custom1" = Table.AddColumn(#"Renamed Columns", "Numbers", each Character.ToNumber([ListOfCharacters])), 9 | #"Added Custom2" = Table.AddColumn(#"Added Custom1", "NewCharacter", each (if [Numbers] > 64 and [Numbers] < 91 then "/" else "") & Character.FromNumber([Numbers])), 10 | #"Removed Columns" = Table.RemoveColumns(#"Added Custom2",{"ListOfCharacters", "Numbers"}), 11 | #"Added Custom3" = Table.AddColumn(#"Removed Columns", "One", each 1), 12 | #"Grouped Rows" = Table.Group(#"Added Custom3", {"One"}, {{"NewName", each Text.Combine([NewCharacter]), type text}}), 13 | #"Replaced Value" = Table.ReplaceValue(#"Grouped Rows","/"," ",Replacer.ReplaceText,{"NewName"}), 14 | #"Capitalized Each Word" = Table.TransformColumns(#"Replaced Value",{{"NewName", Text.Proper, type text}}), 15 | NewName = Table.RemoveColumns(#"Capitalized Each Word",{"One"})[NewName]{0} 16 | in 17 | NewName 18 | ``` 19 | -------------------------------------------------------------------------------- /Functions/ContainsText/TextContains.md: -------------------------------------------------------------------------------- 1 | ```c# 2 | = Text.Contains( "Red roses", "Red" ) // Returns true 3 | = Text.Contains( "Red roses", "red" ) // Returns false 4 | = Text.Contains( "Red roses", "red", 5 | Comparer.Ordinal ) // Returns false 6 | = Text.Contains( "Red roses", "red", 7 | Comparer.OrdinalIgnoreCase ) // Returns true 8 | ``` 9 | -------------------------------------------------------------------------------- /Functions/CountMonths/fnCountMonths.md: -------------------------------------------------------------------------------- 1 | # fnCountMonths 2 | ## Count number of motnhs between two dates 3 | 4 | ```ioke 5 | 6 | let 7 | fn = // fnCountMonths 8 | /* ------------------------------ 9 | Author: Imran Haq - PBI QUERYOUS 10 | GitHub: https://github.com/PBIQueryous/M-Code/ 11 | Description: Count number of months between two dates 12 | Credits: 13 | Link: 14 | Site: 15 | ---------------------------------*/ 16 | 17 | // invoke function & define parameter inputs 18 | 19 | 20 | let 21 | invokeFn = (StartDate as date , EndDate as date)=> 22 | 23 | // ------------------------------------------------------------------ 24 | // function transformations 25 | let 26 | MonthsList = 27 | List.Generate( 28 | () => [ DateValue = Date.From( StartDate ) ], 29 | each [DateValue] <= Date.From( EndDate ), 30 | each [ DateValue = Date.AddMonths( [DateValue] , 1 ) ], 31 | each [DateValue] 32 | ), 33 | MonthsCount = Int64.From( List.Count( MonthsList )) 34 | in 35 | MonthsCount 36 | , 37 | 38 | // ------------------------------------------------------------------ 39 | // change parameter metadata here 40 | fnType = type function ( 41 | StartDate as ( 42 | type text 43 | meta 44 | [ 45 | Documentation.FieldCaption = " Select Column: #(lf) Date Column ", 46 | Documentation.FieldDescription = " Select Date Column #(lf) eg: Start Date ", 47 | Documentation.SampleValues = {"23/01/2023"} 48 | // or Documentation.AllowedValues = {"Text1", "Text2", "Etc"} for multiple values in dropdown 49 | // Formatting.IsMultiLine = true, for text box with multiple-code lines (eg: for native queries) 50 | // Formatting.IsCode = true, formats text into coding style 51 | ] 52 | ) 53 | , 54 | EndDate as ( 55 | type text 56 | meta 57 | [ 58 | Documentation.FieldCaption = " Select Column: #(lf) Date Column ", 59 | Documentation.FieldDescription = " Select Date Column #(lf) eg: End Date ", 60 | Documentation.SampleValues = {"31/12/2023"} 61 | // or Documentation.AllowedValues = {"Text1", "Text2", "Etc"} for multiple values in dropdown 62 | // Formatting.IsMultiLine = true, for text box with multiple-code lines (eg: for native queries) 63 | // Formatting.IsCode = true, formats text into coding style 64 | ] 65 | ) 66 | ) as list, 67 | // ------------------------------------------------------------------ 68 | // edit function metadata here 69 | documentation = 70 | [ 71 | 72 | Documentation.Name = " fnCountMonths ", 73 | Documentation.Description = " Count number of months between two dates ", 74 | Documentation.LongDescription = " Count number of months between two dates ", 75 | Documentation.Category = " Dates ", 76 | Documentation.Source = " PBIQUERYOUS ", 77 | Documentation.Version = " 1.0 ", 78 | Documentation.Author = " Imran Haq ", 79 | Documentation.Examples = 80 | { 81 | [ 82 | Description = " Count number of months between two dates ", 83 | Code = " fnCountMonths( StartDate , EndDate ) ", 84 | Result = " Table 85 | #(lf) ____________________________ 86 | #(lf) 01/01/2023 | 01/03/2023 | 3 87 | #(lf) 88 | " 89 | ] 90 | } 91 | 92 | ] 93 | , 94 | 95 | // ------------------------------------------------------------------ 96 | // Choose between Parameter Documentation or Function Documentation 97 | funtionDocumentation = // -- function metadata 98 | Value.ReplaceType(invokeFn, Value.ReplaceMetadata(Value.Type(invokeFn), documentation)), 99 | 100 | parameterDocumentation = // -- parameter metadata 101 | Value.ReplaceType(invokeFn, fnType) 102 | in 103 | // ------------------------------------------------------------------ 104 | // select one of the above steps and paste below 105 | funtionDocumentation /* <-- Choose final documentation type */ 106 | in 107 | fn 108 | 109 | ``` 110 | -------------------------------------------------------------------------------- /Functions/DataTypeErrors/fnNoDataTypeErrors.md: -------------------------------------------------------------------------------- 1 | ```ioke 2 | 3 | let 4 | Source = let 5 | ChangeTypefx = (Table as table, DataTypes as list) as table => 6 | let 7 | SourceCols = Table.ColumnNames(Table), 8 | DataTypesColumnList = List.Transform(DataTypes, each _{0}), 9 | MatchingCols = List.Intersect({SourceCols, DataTypesColumnList}), 10 | MatchingTypesRestoredasList = 11 | List.Transform( 12 | List.Transform( 13 | MatchingCols, 14 | each List.PositionOf(DataTypesColumnList, _) 15 | ), 16 | each DataTypes{_} 17 | ), 18 | Custom2 = Table.TransformColumnTypes(Table, MatchingTypesRestoredasList) 19 | in 20 | Custom2, 21 | Docs = [ 22 | Documentation.Name = "ChangeTypeFxNoErrors", 23 | Documentation.Description = "Returns no error if the data types applied are not found.", 24 | Documentation.Author = "Chandeep Chhabra @ goodly.co.in", 25 | Documentation.Examples = 26 | { 27 | [ 28 | Description = "There are 2 arguments to this function. Table, DataTypes as List of List", 29 | Code = 30 | "ChangeTypeNoErrors ( 31 | Source, -- Table Name 32 | { {Date, type date}, 33 | {Region, type text}, 34 | {Units, Int64.Type} } -- Data types applied to columns 35 | ) 36 | ", 37 | Result = "Table with no errors" 38 | ] 39 | } 40 | ] 41 | in 42 | Value.ReplaceType(ChangeTypefx, Value.ReplaceMetadata(Value.Type(ChangeTypefx), Docs)) 43 | in 44 | Source 45 | 46 | ``` 47 | -------------------------------------------------------------------------------- /Functions/Dataverse/fn_DataversePrep.md: -------------------------------------------------------------------------------- 1 | # fn_GetCustomDataverseObjects 2 | 3 | ``` ioke 4 | 5 | let 6 | invokeFunction = (dataverseRootURL as text, dataversePrefix as text, optional dataverseTableName as text) => 7 | let 8 | Source = CommonDataService.Database(dataverseRootURL, [CreateNavigationProperties = false]), 9 | fn_getCols = 10 | let 11 | fn = (tableName as any, prefix as text) => 12 | let 13 | list_AllHeaders = Table.ColumnNames(tableName), 14 | //-- get column names 15 | list_ColumnsToRemove = List.Select(list_AllHeaders, each not Text.StartsWith(_, prefix)), 16 | //-- remove columns that don't have the prefix 17 | list_ColumnsToKeep = List.Select(list_AllHeaders, each Text.StartsWith(_, prefix) and not Text.Contains(_, "_base")), 18 | //-- keep columns with the prefix and remove any (base) columns 19 | SELECT_COLS = Table.SelectColumns(tableName, list_ColumnsToKeep) 20 | //-- select columns 21 | in 22 | SELECT_COLS 23 | in 24 | fn, 25 | vPrefix = dataversePrefix, 26 | vTableName = dataverseTableName, 27 | table_DataverseTables = Table.SelectRows(Source, each Text.StartsWith([Name], vPrefix)), 28 | invoke_FunctionToCleanColumns = Table.SelectColumns(Table.AddColumn(table_DataverseTables, "CustomData", each fn_getCols([Data], vPrefix)), {"Schema", "Item", "Data", "CustomData"}), 29 | import_CleanTable = invoke_FunctionToCleanColumns{[Schema = "dbo", Item = vTableName]}[CustomData], 30 | finalStep = if dataverseTableName = null then invoke_FunctionToCleanColumns else import_CleanTable 31 | in 32 | finalStep 33 | in 34 | invokeFunction 35 | 36 | ``` 37 | -------------------------------------------------------------------------------- /Functions/Dataverse/fn_GetCustomDataverseObjects: -------------------------------------------------------------------------------- 1 | let 2 | invokeFunction = (dataverseRootURL as text, dataversePrefix as text, optional dataverseTableName as text) => 3 | let 4 | Source = CommonDataService.Database(dataverseRootURL, [CreateNavigationProperties = false]), 5 | fn_getCols = 6 | let 7 | fn = (tableName as any, prefix as text) => 8 | let 9 | list_AllHeaders = Table.ColumnNames(tableName), 10 | //-- get column names 11 | list_ColumnsToRemove = List.Select(list_AllHeaders, each not Text.StartsWith(_, prefix)), 12 | //-- remove columns that don't have the prefix 13 | list_ColumnsToKeep = List.Select(list_AllHeaders, each Text.StartsWith(_, prefix) and not Text.Contains(_, "_base")), 14 | //-- keep columns with the prefix and remove any (base) columns 15 | SELECT_COLS = Table.SelectColumns(tableName, list_ColumnsToKeep) 16 | //-- select columns 17 | in 18 | SELECT_COLS 19 | in 20 | fn, 21 | vPrefix = dataversePrefix, 22 | vTableName = dataverseTableName, 23 | table_DataverseTables = Table.SelectRows(Source, each Text.StartsWith([Name], vPrefix)), 24 | invoke_FunctionToCleanColumns = Table.SelectColumns(Table.AddColumn(table_DataverseTables, "CustomData", each fn_getCols([Data], vPrefix)), {"Schema", "Item", "Data", "CustomData"}), 25 | import_CleanTable = invoke_FunctionToCleanColumns{[Schema = "dbo", Item = vTableName]}[CustomData], 26 | finalStep = if dataverseTableName = null then invoke_FunctionToCleanColumns else import_CleanTable 27 | in 28 | finalStep 29 | in 30 | invokeFunction 31 | -------------------------------------------------------------------------------- /Functions/DateTime/bsl_end.pq: -------------------------------------------------------------------------------- 1 | = DateTime.From(Date.StartOfWeek(#date(Date.Year(DateTime.LocalNow()), 10, 31), Day.Sunday)) + #duration( 0, 2, 0, 0 ) 2 | -------------------------------------------------------------------------------- /Functions/DateTime/bst_start.pq: -------------------------------------------------------------------------------- 1 | = DateTime.From(Date.StartOfWeek(#date(Date.Year(DateTime.LocalNow()), 3, 31), Day.Sunday)) + #duration( 0, 1, 0, 0 ) 2 | -------------------------------------------------------------------------------- /Functions/DateTime/daylight_savings.pq: -------------------------------------------------------------------------------- 1 | = Table.AddColumn(div_pricing_discount, "website_order_time_adj", each if [website_order_time] > DateTime.From(p_firstSundayBST) and [website_order_time] < DateTime.From(p_lastSundayBST) then #duration( 0, 1, 0, 0 ) + [website_order_time] else [website_order_time], type datetime) 2 | 3 | = Table.AddColumn(format_pricing, "order_created_date_time_adj", each if [order_created_date_time] > DateTime.From(p_firstSundayBST) and [order_created_date_time] < DateTime.From(p_lastSundayBST) then #duration( 0, 1, 0, 0 ) + [order_created_date_time] else [order_created_date_time], type datetime) 4 | -------------------------------------------------------------------------------- /Functions/DateTime/fnRemoveSecondsFromDateTime.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = Table.TransformColumnTypes(Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("rZhBjiUhCIavMun1vEQBS62rdPr+1xiwCkExk1lM0quvfYgIP1jf31/1kz+QAH6ldie4c/76+f39VT70UIA75bvQS8u7Ng1aXgoPzeXG64YS15Y7XyeKPdJ207MWPzm9hvONWV0L+PENPn16UXrwOF93Rt4y0nKnFCn/tUinb55CujOcKEQLkG/QM2cNG90lczx3zI71m2DH1y1RuuJqYiMtYkQ+o0buxewGb0l14MsCyp4U9nzg+qlzR1mMLy0zXWiaQE0BppwCb5BmamWJhaWLpRZ2Szi7vgxqAT742u030E3ltUuTcg6Uazud/B5uqBqLNC1L+OvqBfuGvOVzKW2eo0sSWfAtPpX/sfrG22VenlYLYhc1idqnvWdGSQws21qUtIdweXSj7HjAnBt0xicj5ZBdA8/go7nHGdPeA5Z5QL6+t0o2+lb7RulgoWvmr/lGN1wv1nzrEk/Al2oGVLaqx2tetHg5rlHmOi2oNwLupoFTuW23N4r9VH10mWr5Wp2+LavZZUpbxrF3nJ9pEyjJLQ7ygV5WZbNSk5jYS1JUmatHA9es+KrGfpaklC84l9OMUUL1DWfsm9xI0WO36QRUldQZezbMClD0nlzlkIbC11O6tH6nIIIICBvZ7p/jTlojdrgqaoH72iJ231N4CwimkaY3lDSUbWbFWLsHTfJqVnpRu28ro0i7pYpRTrh8rbfM8eWyK6C3bJchfjyLSRdzNcqRYXVY6KViWt1l8BW9rm0UVbA0PKKCKm4mQiSXAbQnoLSmm9REmyb8mS3CfBLYm3oXRcccKeqRF1o59IFCshpdaEmRUhw3uhw5Rc9MwjzFdPKB9XyWkaNFFcxTEvmPlCsOAhWtmtI4O4IIStvii7J2H3geCzmdc6pHQRFHuvZMyxQWpbedmzg+qf0sziZ3TRoTaoRUoZ/c7pFeGov6ueb5pP3r9DANs2dsIm9YfAZN+UXlyUa6y0tjwUir1t1Cu05HnnItAEU6O42nkCzbHM2mdo5ytkUfONuyni0bLXq2ZQoCzWK7Ug5xadY6TAS5YVJMrIImmI6ShmfK6NNPpsOablWGIMwnOhtHnxZEB/e1o/XAYS1pk7EMLKOdbJchHZuTKp3oHnahLVynNJl0pKxsGCnYjO8o6qy00MteFI5Wezs42qxgjA4djZRsIHW0mNA42izqjnbNEk9lTK2RlpMPMtwf1nZrikZ5ONgLQyiaDDt6hUIWWk+3KWPgwULX0d6mzjyyhDaaZB5CHfhtOJThAFcqvZa0AsLDUydJnVCkV+vihaL1LvfqqFbf03Aao88uJ5KSqsILLdaQHK1R0galFqgE40DdK9VRspHK0WKtcqEHz+RloHPLS/mCCtp3AIs7ny08GMczqdRIu+WJUa5O2gcUHNIed5NxHyN1jzJHexwtcRlQHM1WL46CZuVCydTE0WrK42g/+cvpF0YylPQr0YK8LONu8v0mesb1neIpmEKMOtc3RQuEpnOOUqhveShAUCmhZLs5Wo70Cjn5tM6cTrREC4BB0R5KesfaZZ/OuX0GkXYxvzatQ9Yc860EpDPYdwn7DiIDg765VLyqe+/aq2JcXIaNjkf3nI9tRpcj70U/Ci4U8lOGOdIaJyEZQe0J7GgO7fspw8Nuo/edaJilpGfZCOGoEwijnOz71b/JfqSH3bCGhBDaTnHAFuUTZbCFGEkZd6Nd+fSgL3P3ECO0QVGH4DTGx3SiuH8WGXS+HPUBcknnS+k/0eKbGb8cp9D9G77+x+q/YvcUgtH/0hEjHHC2Ips1XUWa5jeeFc/nv8doXzdXvKu/jBnXmPl+/gA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Date created" = _t]), {{"Date created", type datetime}}), 3 | InsertTimeOnly = Table.AddColumn(Source, "Time UI", each DateTime.Time([Date created]), type time), 4 | ChangeToText = Table.TransformColumnTypes(InsertTimeOnly,{{"Time UI", type text}}), 5 | ChangeToTime = Table.TransformColumnTypes(ChangeToText,{{"Time UI", type time}}), 6 | DateTimeToText = Table.AddColumn(ChangeToTime, "DateTime.ToText", each Time.From( DateTime.ToText( [Date created], "HH:mm" )), type time), 7 | DateTimeToRecord = Table.AddColumn(DateTimeToText, "DateTime.ToRecord", each let t = DateTime.ToRecord( [Date created] ) in #time( t[Hour], t[Minute], 0), type time) 8 | in 9 | DateTimeToRecord 10 | -------------------------------------------------------------------------------- /Functions/DateTime/round_datetime_to_hours.pq: -------------------------------------------------------------------------------- 1 | = Table.AddColumn(col_addBST_DaylightSaving, "website_order_time_hour", each DateTime.From(Number.From([website_order_time_adj]) - ( Time.Minute([website_order_time_adj]) / (60*24)) - ( Time.Second([website_order_time_adj]) / (3600*24))), type datetime) 2 | -------------------------------------------------------------------------------- /Functions/DateTime/round_time_to_hours.pq: -------------------------------------------------------------------------------- 1 | = Table.AddColumn(col_created_date_time_adj, "order_created_date_time_hour", each if [order_created_date_time] = null then null else DateTime.From(Number.From([order_created_date_time_adj]) - ( Time.Minute([order_created_date_time_adj]) / (60*24)) - ( Time.Second([order_created_date_time_adj]) / (3600*24))), type datetime) 2 | -------------------------------------------------------------------------------- /Functions/DatesFromPeriod/fnDateFromPeriod.md: -------------------------------------------------------------------------------- 1 | ```c# 2 | let 3 | function1 = // fnDateFromPeriod 4 | /* ------------------------------ 5 | Author: Imran Haq - PBI QUERYOUS 6 | Description: 7 | ---------------------------------*/ 8 | 9 | // invoke function & define parameter inputs 10 | let 11 | invokeFunction = (dataInput as any) => 12 | 13 | // ------------------------------------------------------------------ 14 | // function transformations 15 | let 16 | step1 = dataInput, 17 | step2 = Number.From(Text.BeforeDelimiter(step1, "/")), 18 | step3 = Number.From(Text.AfterDelimiter(step1, "Q")), 19 | step4 = if _quarter = 1 then 4 20 | else if _quarter = 2 then 7 21 | else if _quarter = 3 then 10 22 | else if _quarter = 4 then 1 23 | else null, 24 | step5 = if _quarter = 4 then Date.From("1-" & Text.From(_fix) & "-" & Text.From(_year + 1)) 25 | else Date.From("1-" & Text.From(_fix) & "-" & Text.From(_year)) 26 | , 27 | // consolidate last transformation step 28 | functionOutput = step5 29 | in 30 | functionOutput, 31 | 32 | // ------------------------------------------------------------------ 33 | // change parameter metadata here 34 | fnType = type function ( 35 | dataInput as ( 36 | type text 37 | meta 38 | [ 39 | Documentation.FieldCaption = " type text: #(lf) see example in field ", 40 | Documentation.FieldDescription = " type a dummy integer date #(lf) eg: 31122022 ", 41 | Documentation.SampleValues = {31122022} 42 | ] 43 | ), 44 | optional separator as ( 45 | type text 46 | meta 47 | [ 48 | Documentation.FieldCaption = " Choose Separator Type ", 49 | Documentation.FieldDescription = " Recommended to use #(lf) forward slash / ", 50 | Documentation.AllowedValues = {"","-", "/"} 51 | ] 52 | ) 53 | ) as list, 54 | // ------------------------------------------------------------------ 55 | // edit function metadata here 56 | documentation = 57 | [ 58 | 59 | Documentation.Name = " fnDateFromPeriod ", 60 | Documentation.Description = " Converts Period YYYY/YYYY QQ to date format DD/MM/YYYY ", 61 | Documentation.LongDescription = " Converts Period YYYY/YYYY QQ to date format DD/MM/YYYY ", 62 | Documentation.Category = " Dates ", 63 | Documentation.Source = " PBIQUERYOUS ", 64 | Documentation.Version = " 1.0 ", 65 | Documentation.Author = " Imran Haq ", 66 | Documentation.Examples = 67 | { 68 | [ 69 | Description = " description ", 70 | Code = " 2021/2022 Q4 ", 71 | Result = " result #(lf) 1/1/2022 72 | #(lf) new line #(lf) 2 " 73 | ] 74 | } 75 | 76 | ] 77 | , 78 | 79 | // ------------------------------------------------------------------ 80 | // Choose between Parameter Documentation or Function Documentation 81 | funtionDocumentation = // -- function metadata 82 | Value.ReplaceType(invokeFunction, Value.ReplaceMetadata(Value.Type(invokeFunction), documentation)), 83 | 84 | parameterDocumentation = // -- parameter metadata 85 | Value.ReplaceType(invokeFunction, fnType) 86 | in 87 | // ------------------------------------------------------------------ 88 | // select one of the above steps and paste below 89 | funtionDocumentation /* <-- Choose final documentation type */ 90 | in 91 | function1 92 | ``` 93 | -------------------------------------------------------------------------------- /Functions/DaylightSavings/DaylightSavingAdjustment.pq: -------------------------------------------------------------------------------- 1 | Table.AddColumn( 2 | div_pricing_discount, 3 | "website_order_time_adj", 4 | each 5 | if [website_order_time] 6 | > DateTime.From(p_firstSundayBST) and [website_order_time] 7 | < DateTime.From(p_lastSundayBST) 8 | then 9 | #duration(0, 1, 0, 0) + [website_order_time] 10 | else 11 | [website_order_time], 12 | type datetime 13 | ) 14 | -------------------------------------------------------------------------------- /Functions/DecimalTimeToDuration/fnDecimalTimeToDuration.pq: -------------------------------------------------------------------------------- 1 | let 2 | fxDecimalTimeInMinToDuration = 3 | ( DecimalTimeInMin ) as duration => 4 | let 5 | t = Splitter.SplitTextByAnyDelimiter({",", "."})(Text.From( DecimalTimeInMin )), 6 | x = Number.From( t{0}? ?? "0" ), 7 | d = if x >1440 then x /1440 else 0, 8 | h = if x >1440 then (Number.Mod( d, 1) *1440) /60 else if x >60 then x /60 else 0, 9 | m = if x >60 then Number.Round(Number.Mod(h, 1) *60 ) else x, 10 | r = #duration( Number.RoundDown(d, 0), Number.RoundDown(h, 0), m, Number.From( Text.PadEnd( t{1}? ?? "0", 2, "0")) ) 11 | in 12 | r, 13 | Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMlWK1YlWMtQxhtB6ENpIxwQiYaQHZRhASB1DcwhDD8ow1DExhGqFMsxhWo0hegxNYAKWFiY6RkALYgE=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [InMinutes = _t]), 14 | InvokeCustom = Table.AddColumn(Source, "fxDecimalTimeInMinToDuration", each fxDecimalTimeInMinToDuration([InMinutes]), type duration) 15 | in 16 | InvokeCustom 17 | -------------------------------------------------------------------------------- /Functions/DynamicDatesList/fnDynamicDatesList.pq: -------------------------------------------------------------------------------- 1 | //-- generate list of dates dynamically in relation to number of payments 2 | col_ListOfDates = Table.AddColumn( 3 | cols_Select, 4 | "ListOfDates", 5 | each 6 | let 7 | zeroPay = [Payments] - 0, // number of payments 8 | startDate = Date.StartOfMonth([Start Date]), // start date 9 | // if number of payments is 0 then return zeroPay variable, otherwise number of payments -1 (less one to compensate for list.generate function 10 | endDate = Date.EndOfMonth( // end date 11 | Date.AddMonths(startDate, (if [Payments] = 0 then zeroPay else [Payments] - 1)) 12 | ), 13 | // generate list of dates between start and end date, incrementally by 1 month 14 | x3 = List.Generate(() => startDate, each _ <= endDate, each Date.AddMonths(_, 1)), 15 | x4 = Table.FromList( 16 | x3, 17 | Splitter.SplitByNothing(), 18 | type table [PaymentMonth = Date.Type], 19 | null, 20 | ExtraValues.Error 21 | ), 22 | 23 | // insert achievement value against achievement date within the nested table 24 | x5 = Table.AddColumn( 25 | x4, 26 | "Achievement Value", 27 | // NT is the INNER NESTED TABLE 28 | // if Achievement Payment Month = the PaymentMonth in the Nested Table then inject the Ach Value against it 29 | (NT) => if [Achievement Payment Month] = NT[PaymentMonth] then [Ach Value] else 0 30 | ) 31 | in 32 | x5 33 | ), 34 | expand_ListOfDates = Table.ExpandTableColumn( 35 | col_ListOfDates, 36 | "ListOfDates", 37 | {"PaymentMonth", "Achievement Value"}, 38 | {"PaymentMonth", "Achievement Value"} 39 | ), 40 | cols_Format = Table.TransformColumnTypes( 41 | expand_ListOfDates, 42 | {{"PaymentMonth", type date}, {"Achievement Value", type number}} 43 | ), 44 | -------------------------------------------------------------------------------- /Functions/ErrorReplaceCols/fnErrorReplaceColumns.md: -------------------------------------------------------------------------------- 1 | ``` ioke 2 | 3 | //Build a list of all table columns for Table.ReplaceErrorValues() 4 | //Output: {{"Column1",null}, {"Column2",null}} 5 | let 6 | GetListOfAllErrReplacements = (_table as table) => 7 | let 8 | _AllColumns = Table.ColumnNames(_table), 9 | #"Converted to Table" = Table.FromList(_AllColumns, Splitter.SplitByNothing(), null, null, ExtraValues.Error), 10 | #"Added Custom1" = Table.AddColumn(#"Converted to Table", "Custom1", each null), 11 | #"Added Custom2" = Table.AddColumn(#"Added Custom1", "Custom2", each {[Column1],[Custom1]}), 12 | #"Removed Columns" = Table.RemoveColumns(#"Added Custom2",{"Column1", "Custom1"}), 13 | _ListOfAllReplacements = #"Removed Columns"[Custom2] 14 | in 15 | _ListOfAllReplacements 16 | in 17 | GetListOfAllErrReplacements 18 | 19 | ``` 20 | -------------------------------------------------------------------------------- /Functions/ExtractDate/fnExtractDate.md: -------------------------------------------------------------------------------- 1 | # Extract Date Integers and format as Data 2 | ## transform yyyymmdd to dd/mm/yyyy 3 | 4 | ```c# 5 | let 6 | // Imran Haq - PBI QUERYOUS 7 | // transform digits yyyymmdd to Date format dd/mm/yyyy 8 | output = 9 | let 10 | fn 11 | = // fnExtractDate 12 | let 13 | invokeFunction = (input as text, optional separator as text) => 14 | let 15 | extractDate = Text.Start(Text.Select(input, {"0".."9"}),2) 16 | & separator & Text.Middle(Text.Select(input, {"0".."9"}), 2, 2) 17 | & separator & Text.End(Text.Middle(Text.Select(input, {"0".."9"}), 4, 4), 2) 18 | in 19 | extractDate 20 | in 21 | invokeFunction, 22 | documentation = [ 23 | Documentation.Name = " fnExtractDate ", 24 | Documentation.Description = " Extracts numbers and converts to date ", 25 | Documentation.LongDescription 26 | = " Extracts date in number format yyyymmdd and coverts to short date format ", 27 | Documentation.Category = " Function Dates Category ", 28 | Documentation.Source = " PBI QUERYOUS ", 29 | Documentation.Version = " 1.0 ", 30 | Documentation.Author = " Imran Haq ", 31 | Documentation.Examples = { 32 | [ 33 | Description = " Date.FromText(Text.Select(Source, {''0'' .. ''9''})) ", 34 | Code = " 23032022_Final ", 35 | Result = " 02 - 09 - 2021 " 36 | ] 37 | } 38 | ] 39 | in 40 | Value.ReplaceType(fn, Value.ReplaceMetadata(Value.Type(fn), documentation)) 41 | in 42 | output 43 | ``` 44 | -------------------------------------------------------------------------------- /Functions/ExtractDates/ExtractDates.md: -------------------------------------------------------------------------------- 1 | ```c# 2 | = Date.FromText( "31122022", [Format="ddMMyyyy"] ) 3 | // Returns #date(2022, 12, 31) 4 | = Date.FromText( "12312022", [Format="MMddyyyy"] ) 5 | // Returns #date(2022, 12, 31) 6 | = Date.FromText( "20223112", [Format="yyyyddMM"] ) 7 | // Returns #date(2022, 12, 31) 8 | = Date.FromText( "12-31-2022", [Format="MM-dd-yyyy"] ) 9 | // Returns #date(2022, 12, 31) 10 | = Date.FromText( "2022-31-12", [Format="yyyy-dd-MM"] ) 11 | // Returns #date(2022, 12, 31) 12 | = Date.FromText( "31*12*2022", [Format="dd*MM*yyyy"] ) 13 | // Returns #date(2022, 12, 31) 14 | = Date.FromText( "31.*12.*22", [Format="dd.*MM.*yy"] ) 15 | // Returns #date(2022, 12, 31) 16 | ``` 17 | 18 | ```c# 19 | = Date.FromText("30 Mrt 2022", [Format="dd MMM yyyy"]) 20 | // Returns an error, PQ does not recognize Mrt as March 21 | 22 | = Date.FromText("30 Mrt 2022", [Format="dd MMM yyyy", Culture="nl-NL"]) 23 | // Returns #date( 2022, 3, 30). Mrt = March in Dutch 24 | 25 | = Date.FromText("30 Maart 22", [Format="dd MMMM yy", Culture="nl-NL"]) 26 | // Returns #date( 2022, 3, 30). Maart = March in Dutch 27 | 28 | = Date.FromText("30 juin 2022", [Format="dd MMM yyyy"]) 29 | // Returns an error, PQ does not recognize juin as June 30 | 31 | = Date.FromText("30 juin 2022", [Format="dd MMM yyyy", Culture="fr-FR"]) 32 | // Returns #date( 2022, 6, 30 ), juin = June in French 33 | ``` 34 | -------------------------------------------------------------------------------- /Functions/ExtractText/extractTextOrNumbers.md: -------------------------------------------------------------------------------- 1 | Extract numeric characters from a text string 2 | 3 | example code 4 | ```js 5 | Table.TransformColumnTypes(Table.AddColumn(Source, "TimeStamp", each Text.Select( [Name], {"0".."9"})), {{"TimeStamp", Int64.Type}}) 6 | ``` 7 | 8 | ## Extract Numbers: template 9 | ```c# 10 | Table.TransformColumnTypes( 11 | Table.AddColumn( 12 | Source, 13 | "NewColumn", 14 | each Text.Select( [SourceColumn], {"0".."9"})), 15 | {{"SourceColumn", Int64.Type}}) 16 | ``` 17 | 18 | ## Extract Text: template 19 | ```c# 20 | Table.TransformColumnTypes( 21 | Table.AddColumn( 22 | Source, 23 | "NewColumn", 24 | each Text.Select( [SourceColumn], {"a".."z", "A".."Z"})), 25 | {{"SourceColumn", type text}}) 26 | ``` 27 | -------------------------------------------------------------------------------- /Functions/FilterMaxDate/fnFilterMaxDate.md: -------------------------------------------------------------------------------- 1 | # fnFilterMaxDate 2 | ## filter table by max date available (for latest records) 3 | 4 | ```C# 5 | let 6 | input = Source 7 | fnFilterMax = Table.SelectRows(input, each ([Field] = List.Max(input[Field]))) ) 8 | in 9 | fnFilterMax 10 | ``` 11 | -------------------------------------------------------------------------------- /Functions/FindWordsExact/fnMatchTextStringExact.md: -------------------------------------------------------------------------------- 1 | ```ioke 2 | 3 | let 4 | customFunction = // fnMatchExactWords 5 | /* ------------------------------ 6 | Author: Imran Haq - PBI QUERYOUS 7 | Description: fnMatchExactWords 8 | ---------------------------------*/ 9 | 10 | // 1.0: invoke function & define parameter inputs 11 | let 12 | invokeFunction = (Column as any, WordList as any, optional InsertList as any) => 13 | 14 | // ------------------------------------------------------------------ 15 | // 2.0: function transformations 16 | let 17 | // checks if WordList is null, then returns a pre-defined list of your choice 18 | ListWords = if InsertList <> null then InsertList else if WordList = null then InsertList else Text.Split(WordList, ","), 19 | 20 | ColumnValues = Text.Split(Column, " "), // check againt each cell in the select column 21 | 22 | Result = List.ContainsAny(ColumnValues, ListWords) // return result 23 | in 24 | Result 25 | , 26 | 27 | // ------------------------------------------------------------------ 28 | // 3.0: change parameter metadata here 29 | fnType = type function ( 30 | // 3.0.1: first parameter 31 | Column as ( 32 | type any 33 | meta 34 | [ 35 | Documentation.FieldCaption = " Select Column: #(lf) Column from Table ", 36 | Documentation.FieldDescription = " Select Table Column: #(cr,lf) Column from Table ", 37 | Documentation.SampleValues = {"[ColumnName]"} 38 | ] 39 | ) 40 | 41 | // 3.0.2: second parameter 42 | , 43 | WordList as ( 44 | type list 45 | meta 46 | [ 47 | Documentation.FieldCaption = " Type manual list of words ", 48 | Documentation.FieldDescription = " Words #(lf) Separated by comma, no spaces, no speech marks ", 49 | Documentation.SampleValues = {"Word1, Word2, Word3"} 50 | ] 51 | ) 52 | 53 | 54 | // 3.0.3: third parameter 55 | , 56 | optional InsertList as ( 57 | type list 58 | meta 59 | [ 60 | Documentation.FieldCaption = " pre-defined list object ", 61 | Documentation.FieldDescription = " List object #(lf) { 'Word1', 'Word2'} ", 62 | Documentation.SampleValues = {"{ Word1, Word2, Word3 }"} 63 | ] 64 | ) 65 | 66 | 67 | // 3.1: parameter return type 68 | ) as list, 69 | // ------------------------------------------------------------------ 70 | // 4.0: edit function metadata here 71 | documentation = 72 | [ 73 | 74 | Documentation.Name = " fnMatchExactWords ", 75 | Documentation.Description = " Finds exact matches of list of words in each cell ", 76 | Documentation.LongDescription = " Finds exact matches of list of words in each cell ", 77 | Documentation.Category = " ETL Category ", 78 | Documentation.Source = " PBIQUERYOUS ", 79 | Documentation.Version = " 1.0 ", 80 | Documentation.Author = " Imran Haq ", 81 | Documentation.Examples = 82 | { 83 | [ 84 | Description = " Finds exact matches of list of words in each cell ", 85 | Code = " fnMatchExactWords( [ColumName], WordList, null ) ", 86 | Result = 87 | " 88 | 1. Create New Function Step 89 | 2. Type function and complete parameters 90 | 2a. fnMatchExactWords( [ColumName], {Canada,Germany}, null ) 91 | 2b. fnMatchExactWords( [ColumName], {Canada,Germany}, ListOfWords ) 92 | 2c. fnMatchExactWords( [ColumName], null, ListOfWords ) 93 | 94 | 95 | " 96 | 97 | ] 98 | /* , 99 | [ 100 | Description = " description ", 101 | Code = " code ", 102 | Result = " result #(cr,lf) new line 103 | #(cr,lf) new line #(cr,lf) 2 " 104 | ] */ 105 | } 106 | 107 | ] 108 | , 109 | 110 | // ------------------------------------------------------------------ 111 | // 5.0: Choose between Parameter Documentation or Function Documentation 112 | functionDocumentation = // -- function metadata 113 | Value.ReplaceType(invokeFunction, Value.ReplaceMetadata( Value.Type(invokeFunction), documentation)), 114 | 115 | parameterDocumentation = // -- parameter metadata 116 | Value.ReplaceType(invokeFunction, fnType), 117 | 118 | replaceMeta = // -- both metas 119 | Value.ReplaceType( 120 | Value.ReplaceType( invokeFunction, fnType ), 121 | Value.ReplaceMetadata( Value.Type(invokeFunction), documentation) 122 | ) 123 | in 124 | // ------------------------------------------------------------------ 125 | // select one of the above steps and paste below 126 | replaceMeta /* <-- Choose final documentation type */ 127 | 128 | in 129 | customFunction 130 | 131 | ``` 132 | -------------------------------------------------------------------------------- /Functions/FindWordsExact/fnMatchWordsExact.pq: -------------------------------------------------------------------------------- 1 | 2 | let 3 | customFunction = // fnMatchExactWords 4 | /* ------------------------------ 5 | Author: Imran Haq - PBI QUERYOUS 6 | Description: fnMatchExactWords 7 | ---------------------------------*/ 8 | 9 | // 1.0: invoke function & define parameter inputs 10 | let 11 | invokeFunction = (Column as any, WordList as any, optional InsertList as any) => 12 | 13 | // ------------------------------------------------------------------ 14 | // 2.0: function transformations 15 | let 16 | // checks if WordList is null, then returns a pre-defined list of your choice 17 | ListWords = if InsertList <> null then InsertList else if WordList = null then InsertList else Text.Split(WordList, ","), 18 | 19 | ColumnValues = Text.Split(Column, " "), // check againt each cell in the select column 20 | 21 | Result = List.ContainsAny(ColumnValues, ListWords) // return result 22 | in 23 | Result 24 | , 25 | 26 | // ------------------------------------------------------------------ 27 | // 3.0: change parameter metadata here 28 | fnType = type function ( 29 | // 3.0.1: first parameter 30 | Column as ( 31 | type any 32 | meta 33 | [ 34 | Documentation.FieldCaption = " Select Column: #(lf) Column from Table ", 35 | Documentation.FieldDescription = " Select Table Column: #(cr,lf) Column from Table ", 36 | Documentation.SampleValues = {"[ColumnName]"} 37 | ] 38 | ) 39 | 40 | // 3.0.2: second parameter 41 | , 42 | WordList as ( 43 | type list 44 | meta 45 | [ 46 | Documentation.FieldCaption = " Type manual list of words ", 47 | Documentation.FieldDescription = " Words #(lf) Separated by comma, no spaces, no speech marks ", 48 | Documentation.SampleValues = {"Word1, Word2, Word3"} 49 | ] 50 | ) 51 | 52 | 53 | // 3.0.3: third parameter 54 | , 55 | optional InsertList as ( 56 | type list 57 | meta 58 | [ 59 | Documentation.FieldCaption = " pre-defined list object ", 60 | Documentation.FieldDescription = " List object #(lf) { 'Word1', 'Word2'} ", 61 | Documentation.SampleValues = {"{ Word1, Word2, Word3 }"} 62 | ] 63 | ) 64 | 65 | 66 | // 3.1: parameter return type 67 | ) as list, 68 | // ------------------------------------------------------------------ 69 | // 4.0: edit function metadata here 70 | documentation = 71 | [ 72 | 73 | Documentation.Name = " fnMatchExactWords ", 74 | Documentation.Description = " Finds exact matches of list of words in each cell ", 75 | Documentation.LongDescription = " Finds exact matches of list of words in each cell ", 76 | Documentation.Category = " ETL Category ", 77 | Documentation.Source = " PBIQUERYOUS ", 78 | Documentation.Version = " 1.0 ", 79 | Documentation.Author = " Imran Haq ", 80 | Documentation.Examples = 81 | { 82 | [ 83 | Description = " Finds exact matches of list of words in each cell ", 84 | Code = " fnMatchExactWords( [ColumName], WordList, null ) ", 85 | Result = 86 | " 87 | 1. Create New Function Step 88 | 2. Type function and complete parameters 89 | 2a. fnMatchExactWords( [ColumName], {Canada,Germany}, null ) 90 | 2b. fnMatchExactWords( [ColumName], {Canada,Germany}, ListOfWords ) 91 | 2c. fnMatchExactWords( [ColumName], null, ListOfWords ) 92 | 93 | 94 | " 95 | 96 | ] 97 | /* , 98 | [ 99 | Description = " description ", 100 | Code = " code ", 101 | Result = " result #(cr,lf) new line 102 | #(cr,lf) new line #(cr,lf) 2 " 103 | ] */ 104 | } 105 | 106 | ] 107 | , 108 | 109 | // ------------------------------------------------------------------ 110 | // 5.0: Choose between Parameter Documentation or Function Documentation 111 | functionDocumentation = // -- function metadata 112 | Value.ReplaceType(invokeFunction, Value.ReplaceMetadata( Value.Type(invokeFunction), documentation)), 113 | 114 | parameterDocumentation = // -- parameter metadata 115 | Value.ReplaceType(invokeFunction, fnType), 116 | 117 | replaceMeta = // -- both metas 118 | Value.ReplaceType( 119 | Value.ReplaceType( invokeFunction, fnType ), 120 | Value.ReplaceMetadata( Value.Type(invokeFunction), documentation) 121 | ) 122 | in 123 | // ------------------------------------------------------------------ 124 | // select one of the above steps and paste below 125 | replaceMeta /* <-- Choose final documentation type */ 126 | 127 | in 128 | customFunction 129 | 130 | -------------------------------------------------------------------------------- /Functions/FindWordsSubString/fnAllWordMatches..md: -------------------------------------------------------------------------------- 1 | ```ioke 2 | = Table.AddColumn(result, "Custom.1", each 3 | let arg1 = List.ContainsAny( Text.Split( [Country] , " "), {"Russia", "Mexico"} ), // exact match 4 | arg2 = List.ContainsAny( Text.Split( [Country] , " "), {"Canada", "Germany"} ), // exact match 5 | arg3 = List.AnyTrue( { [Country] = "United Kingdom" , [Country] = "United States of America" }), // exact match 6 | arg4 = List.ContainsAny( {[Country]}, {"France", "Country of the World"}), 7 | arg5 = List.AnyTrue( List.Transform( {"United States of America", " World", "anc"}, (substring)=> Text.Contains([Country], substring, Comparer.OrdinalIgnoreCase)) ), 8 | arg7 = List.AnyTrue( List.Transform( {" World", "anc"}, (substring)=> Text.Contains(([Country]), substring, Comparer.OrdinalIgnoreCase))), 9 | 10 | calc1 = if arg7 then 1 else if arg2 then 2 else if arg3 then 3 else /* if arg4 then 4 else */if arg5 then 5 else "9" 11 | in calc1 12 | 13 | ) 14 | ``` 15 | -------------------------------------------------------------------------------- /Functions/GetDate/fnGetDate.md: -------------------------------------------------------------------------------- 1 | # fnGetDate 2 | ## Get date from text string 3 | 4 | ```C# 5 | let 6 | Source = let 7 | func 8 | = // fnPowerDate 9 | 10 | let 11 | Source = (Source as text) => 12 | let 13 | ExtractDate = Date.FromText(Text.Select(Source, {"0" .. "9"})) 14 | in 15 | ExtractDate 16 | in 17 | Source, 18 | documentation = [ 19 | Documentation.Name = " Function.PowerDate ", 20 | Documentation.Description = " Extracts numbers and converts to date ", 21 | Documentation.LongDescription = " Extracts date in number format yyyymmdd and coverts to short date format ", 22 | Documentation.Category = " Function Dates Category ", 23 | Documentation.Source = " TVCA BI Team ", 24 | Documentation.Version = " Date / Number (02/09/2021 or 20210902) ", 25 | Documentation.Author = " Imran Haq ", 26 | Documentation.Examples = { 27 | [ 28 | Description = " Date.FromText(Text.Select(Source, {''0'' .. ''9''})) ", 29 | Code = " ABC_2021_09_02_Final ", 30 | Result = " 02 / 09 / 2021 " 31 | ] 32 | } 33 | ] 34 | in 35 | Value.ReplaceType(func, Value.ReplaceMetadata(Value.Type(func), documentation)) 36 | in 37 | Source 38 | ``` 39 | -------------------------------------------------------------------------------- /Functions/GetDetaflowMeta/GetDataflowMeta.md: -------------------------------------------------------------------------------- 1 | # Step 1 2 | ```ioke 3 | //Returns all workspaces/dataflows/tables as a table for easy reference 4 | //Useful in conjunction with the fGetPowerPlatformDataflowData function 5 | let 6 | Source = 7 | PowerPlatform.Dataflows(), 8 | Workspaces = 9 | Source{[Id = "Workspaces"]}[Data], 10 | GR1 = 11 | Table.Group( 12 | Workspaces, 13 | {"workspaceName"}, 14 | { 15 | { 16 | "all", 17 | each _, 18 | type table [ 19 | workspaceId = text, 20 | workspaceName = text, 21 | baseUrl = text, 22 | Data = any, 23 | ItemKind = text, 24 | ItemName = text, 25 | IsLeaf = logical, 26 | Tags = text 27 | ] 28 | } 29 | } 30 | ), 31 | ExpandWorkspaces = 32 | Table.ExpandTableColumn( 33 | GR1, 34 | "all", 35 | {"Data"}, 36 | {"Data"} 37 | ), 38 | ExpandWorkspace = 39 | Table.ExpandTableColumn( 40 | ExpandWorkspaces, 41 | "Data", 42 | {"dataflowName", "Data"}, 43 | {"dataflowName", "Data"} 44 | ), 45 | ExpandDataflow = 46 | Table.ExpandTableColumn( 47 | ExpandWorkspace, 48 | "Data", 49 | {"entityName"}, 50 | {"entityName"} 51 | ), 52 | CT1 = 53 | Table.TransformColumnTypes( 54 | ExpandDataflow, 55 | List.Transform( 56 | Table.ColumnNames(ExpandDataflow), 57 | each {_, type text} 58 | ) 59 | ) 60 | in 61 | CT1 62 | 63 | ``` 64 | 65 | # Step 2 66 | ```ioke 67 | 68 | // Relies on the pDataflowWorkspace parameter existing 69 | // pDataflowWorkspace defines the name (in text) of the workspace 70 | // This avoids the need for GUIDS and makes integration with deployment pipelines simple 71 | 72 | (DataflowName as text, TableName as text) => 73 | let 74 | WorkspaceID = 75 | let 76 | Source = PowerPlatform.Dataflows(null), 77 | Workspaces = Source{[Id = "Workspaces"]}[Data], 78 | WSName = Table.SelectRows(Workspaces, each ([workspaceName] = pDataflowWorkspace)), 79 | WSID = WSName{0}[workspaceId] 80 | in 81 | WSID, 82 | Source = PowerPlatform.Dataflows(null), 83 | Workspaces = Source{[Id = "Workspaces"]}[Data], 84 | Workspace = Workspaces{[workspaceId = WorkspaceID]}[Data], 85 | Dataflow = Table.SelectRows(Workspace, each ([dataflowName] = DataflowName)), 86 | DataflowID = Dataflow{0}[dataflowId], 87 | Data = Workspace{[dataflowId = DataflowID]}[Data], 88 | Result = Data{[ 89 | entity = TableName, 90 | version = "" 91 | ]}[Data] 92 | in 93 | Result 94 | ``` 95 | 96 | # Step 3 97 | ```ioke 98 | // Use this pattern to allow direct query against the Dataflow 99 | // Direct query can only be set at the 'Source' step 100 | // The Dataflow functions in this repo don't allow for that option 101 | 102 | let 103 | DFName = "DataflowName", 104 | TableName = "TableName", 105 | Source = PowerPlatform.Dataflows(null), 106 | Workspaces = Source{[Id = "Workspaces"]}[Data], 107 | FilterWorkspace = Table.SelectRows(Workspaces, each [workspaceName] = pDataflowWorkspace), 108 | DrillDownDataflows = FilterWorkspace{0}[Data], 109 | FilterDataflowName = DrillDownDataflows{[dataflowName = DFName]}[Data], 110 | DrillDownEntity = FilterDataflowName{[entity = TableName, version = ""]}[Data] 111 | in 112 | DrillDownEntity 113 | 114 | ``` 115 | -------------------------------------------------------------------------------- /Functions/GetInitials/fnInitialiseString.md: -------------------------------------------------------------------------------- 1 | ```C# 2 | let fn = 3 | (columnInput) => 4 | 5 | let 6 | initials = Text.Combine(List.Transform( Splitter.SplitTextByDelimiter(" ", QuoteStyle.None)(columnInput) , each Text.Start(_, 1))), 7 | lastword = List.Reverse( Splitter.SplitTextByDelimiter(" ", QuoteStyle.None)(columnInput)){0}, 8 | combine = Text.Combine( { Text.From(initials), Text.From(lastword) } , "-") 9 | 10 | in 11 | combine 12 | 13 | in 14 | fn 15 | ``` 16 | -------------------------------------------------------------------------------- /Functions/GetOneDriveFiles/fnGetOneDriveFiles.md: -------------------------------------------------------------------------------- 1 | # fnGetOneDriveFiles 2 | ## get file from personal OneDrive 3 | 4 | ```C# 5 | = (URLpath) => 6 | let 7 | // get embed code from OneDrive details 8 | fixURL = Text.Replace( 9 | Text.BetweenDelimiters(Text.BetweenDelimiters(URLpath, " ", " ", 0, 0), """", """", 0, 0), 10 | "embed?", // replace old text 11 | "download?" // with new text 12 | ) 13 | & "&app=Excel" // add suffix 14 | in 15 | Web.Contents(fixURL) 16 | ``` 17 | -------------------------------------------------------------------------------- /Functions/GetText/fnGetDigits.md: -------------------------------------------------------------------------------- 1 | # fnGetDigits 2 | ## Get digits from string 3 | 4 | ```C# 5 | let 6 | Source = let 7 | func = // fnPowerDigits 8 | 9 | let 10 | Source = (Source as text) => 11 | let 12 | ExtractNums = Text.Select(Source, {"0" .. "9"}) 13 | in 14 | ExtractNums 15 | in 16 | Source, 17 | documentation = [ 18 | Documentation.Name = " Function.PowerDigits ", 19 | Documentation.Description = " Extracts numbers from string ", 20 | Documentation.LongDescription 21 | = " Add Column, Invoke Custom Function, Choose Column to Extract numbers. ", 22 | Documentation.Category = " Trim Function ", 23 | Documentation.Source = " TVCA PowerBI Team ", 24 | Documentation.Version = " 02 / 09 / 2022 ", 25 | Documentation.Author = " Imran Haq ", 26 | Documentation.Examples = { 27 | [ 28 | Description = " Text.Select(Source, {''0''..''9''}) ", 29 | Code = " AB12C3DEF4GH5 ", 30 | Result = " 12345 " 31 | ] 32 | } 33 | ] 34 | in 35 | Value.ReplaceType(func, Value.ReplaceMetadata(Value.Type(func), documentation)) 36 | in 37 | Source 38 | ``` 39 | -------------------------------------------------------------------------------- /Functions/GetText/fnSelectText.md: -------------------------------------------------------------------------------- 1 | # fnSelectText 2 | ## Get text characters from string 3 | 4 | ```C# 5 | let 6 | Source = let 7 | func = // fnPowerDigits 8 | 9 | let 10 | Source = (Source as text) => 11 | let 12 | ExtractText = Text.Select(Source, {"a" .. "z"}) 13 | in 14 | ExtractText 15 | in 16 | Source, 17 | documentation = [ 18 | Documentation.Name = " Function.PowerText ", 19 | Documentation.Description = " Extracts text from string ", 20 | Documentation.LongDescription 21 | = " Add Column, Invoke Custom Function, Choose Column to Extract text. ", 22 | Documentation.Category = " Trim Function ", 23 | Documentation.Source = " TVCA PowerBI Team ", 24 | Documentation.Version = " 02 / 09 / 2022 ", 25 | Documentation.Author = " Imran Haq ", 26 | Documentation.Examples = { 27 | [ 28 | Description = " Text.Select(Source, {''a''..''z''}) ", 29 | Code = " AB12C3DEF4GH5 ", 30 | Result = " ABCDEFGH " 31 | ] 32 | } 33 | ] 34 | in 35 | Value.ReplaceType(func, Value.ReplaceMetadata(Value.Type(func), documentation)) 36 | in 37 | Source 38 | ``` 39 | -------------------------------------------------------------------------------- /Functions/GetUniques/fnGetUniques.md: -------------------------------------------------------------------------------- 1 | # fnGetUniques 2 | ## get unique values 3 | 4 | ```C# 5 | let 6 | // Author: Imran Haq - PBI QUERYOUS 7 | // --- Function segment --- 8 | output = (input as list) as table => 9 | let 10 | step1 = Table.TransformColumnTypes(Table.Sort(Table.Distinct(Table.FromList(input)), {{"Column1", Order.Ascending}}), {{"Column1", type text}}) 11 | in 12 | step1, 13 | // Output from inner steps 14 | // --- Documentation segment --- 15 | documentation = [ 16 | Documentation.Name = " fnGetUniques ", 17 | Documentation.Description = " Extract column of unique values ", 18 | Documentation.LongDescription 19 | = " Select Table, Select Column and Invoke. Extracts a column of unique values ", 20 | Documentation.Category = " Data Extraction ", 21 | Documentation.Source = " https://github.com/PBIQueryous - PBI Queryous - Stay Queryous ", 22 | Documentation.Version = " 1.0 (21/04/2022) ", 23 | Documentation.Author = " Imran Haq (Newcastle upon Tyne) ", 24 | Documentation.Examples = {[Description = " Stay Queryous ", Code = " Stay Queryous ", Result = " Stay Queryous "]} 25 | ], 26 | functionDocs = Value.ReplaceType( // Replace type of the value 27 | output, // Function caller 28 | Value.ReplaceMetadata( // Replace metadata of the function 29 | Value.Type(output), // Return output type of function 30 | documentation // Documentation assigment 31 | ) 32 | ) 33 | in 34 | functionDocs 35 | ``` 36 | -------------------------------------------------------------------------------- /Functions/GetUniques/fn_GetUniqueDimension.pq: -------------------------------------------------------------------------------- 1 | let 2 | fn = (tableInput as table) as table => 3 | let 4 | sourceInput = tableInput, 5 | headerName = Table.ColumnNames(sourceInput){0}, 6 | dataPrep = Table.Sort( 7 | Table.SelectRows(Table.Distinct(sourceInput), each not List.IsEmpty(List.RemoveMatchingItems(Record.FieldValues(_), {"", null}))), 8 | {{headerName, Order.Ascending}} 9 | ) 10 | in 11 | dataPrep 12 | in 13 | fn 14 | -------------------------------------------------------------------------------- /Functions/GetWeekNumber/fnGetWeekNumber.md: -------------------------------------------------------------------------------- 1 | ```C# 2 | let 3 | func = (Date as date, optional Return_type as number) => 4 | let 5 | // For a detailled description about the options of the Return_types see the official documentation: 6 | // https://support.microsoft.com/en-us/office/weeknum-function-e5c43a03-b4ab-426c-b411-b18c13c75340 7 | 8 | // PQ native Date.WeekFromYear starts to count from 0(Sunday) to 6(Saturday) as opposed to Excel from 1(Sunday) to 7(Saturday) 9 | ConvertedNumber = 10 | if Return_type = null then 11 | 0 12 | else 13 | Record.Field( 14 | [1 = 0, 2 = 1, 11 = 1, 12 = 2, 13 = 3, 14 = 4, 15 = 5, 16 = 6, 17 = 0, 21 = 21], 15 | Text.From(Return_type) 16 | ), 17 | IsoWeek = // this function comes from r-k-b on Github: https://gist.github.com/r-k-b/18d898e5eed786c9240e3804b167a5ca 18 | let 19 | getDayOfWeek = (d as date) => 20 | let 21 | result = 1 + Date.DayOfWeek(d, Day.Monday) 22 | in 23 | result, 24 | getNaiveWeek = (inDate as date) => 25 | let 26 | 27 | // monday = 1, sunday = 7 28 | weekday = getDayOfWeek(inDate), 29 | weekdayOfJan4th = getDayOfWeek(#date(Date.Year(inDate), 1, 4)), 30 | ordinal = Date.DayOfYear(inDate), 31 | naiveWeek = Number.RoundDown((ordinal - weekday + 10) / 7) 32 | in 33 | naiveWeek, 34 | thisYear = Date.Year(Date), 35 | priorYear = thisYear - 1, 36 | nwn = getNaiveWeek(Date), 37 | lastWeekOfPriorYear = getNaiveWeek(#date(priorYear, 12, 28)), 38 | // http://stackoverflow.com/a/34092382/2014893 39 | lastWeekOfThisYear = getNaiveWeek(#date(thisYear, 12, 28)), 40 | weekYear = 41 | if nwn < 1 then 42 | priorYear 43 | else if nwn > lastWeekOfThisYear then 44 | thisYear + 1 45 | else 46 | thisYear, 47 | weekNumber = 48 | if nwn < 1 then 49 | lastWeekOfPriorYear 50 | else if nwn > lastWeekOfThisYear then 51 | 1 52 | else 53 | nwn 54 | in 55 | Number.RoundDown(weekNumber), 56 | Default = Date.WeekOfYear(Date, ConvertedNumber), 57 | Result = if Return_type = 21 then IsoWeek else Default 58 | in 59 | Result, 60 | documentation = [ 61 | Documentation.Name = " Xls.WEEKNUM.pq ", 62 | Documentation.Description = " Returns the week number of a specific date. For example, the week containing January 1 is the first week of the year, and is numbered week 1. Equivalent of the YEARFRAC-Function in Excel. ", 63 | Documentation.LongDescription = " Returns the week number of a specific date. For example, the week containing January 1 is the first week of the year, and is numbered week 1. There are two systems used for this function: 64 | System 1 The week containing January 1 is the first week of the year, and is numbered week 1. 65 | System 2 The week containing the first Thursday of the year is the first week of the year, and is numbered as week 1. This system is the methodology specified in ISO 8601, which is commonly known as the European week numbering system. 66 | Equivalent of the YEARFRAC-Function in Excel. ", 67 | Documentation.Category = " Xls.Date ", 68 | Documentation.Source = " www.TheBIcountant.com - https://wp.me/p6lgsG-2ta . ", 69 | Documentation.Version = " 1.0 ", 70 | Documentation.Author = " Imke Feldmann ", 71 | Documentation.Examples = {[Description = " ", 72 | Code = " let 73 | Serial_number = #date(2012, 3, 9) , 74 | Return_type = 2, 75 | FunctionCall = Xls_WEEKNUM(Serial_number, Return_type) 76 | in 77 | FunctionCall ", 78 | Result = " 11 79 | "]}], 80 | Custom = Value.ReplaceType(func, Value.ReplaceMetadata(Value.Type(func), documentation)) 81 | in 82 | Custom 83 | ``` 84 | -------------------------------------------------------------------------------- /Functions/GetWorkDay/fnGetWorkDay.md: -------------------------------------------------------------------------------- 1 | ```C# 2 | let 3 | func = (StartDate as date, Days as number, optional Holidays as list) => 4 | let 5 | /* Debug parameters 6 | StartDate = #date(2008, 10, 1), 7 | Days = 151, 8 | //Holidays = {#date(2008,11,26), #date(2008,12,4), #date(2009,1,21)}, 9 | */ 10 | Holidays_ = if Holidays = null then 0 else List.Count(Holidays), 11 | // Create a list of days that span the max possible period 12 | ListOfDates = 13 | if Days >= 0 then 14 | List.Dates( 15 | StartDate, 16 | Number.RoundUp((Days + Holidays_) * (7 / 5) + 2, 0), 17 | #duration(1, 0, 0, 0) 18 | ) 19 | else 20 | let 21 | EarliestStartDate = Date.From( 22 | Number.From( 23 | Date.AddDays(StartDate, Number.RoundUp((Days - Holidays_) * (7 / 5) - 2, 0)) 24 | ) 25 | ), 26 | Result = List.Dates( 27 | EarliestStartDate, 28 | Number.From(StartDate - EarliestStartDate), 29 | #duration(1, 0, 0, 0) 30 | ) 31 | in 32 | Result, 33 | // if the optional Holidays parameter is used: Keep only those dates in the list that don't occur in the list of Holidays; 34 | // otherwise continue with previous table 35 | DeleteHolidays = if Holidays = null then ListOfDates else List.Difference(ListOfDates, Holidays), 36 | // Select only the first 5 days of the week 37 | // The 1 in the 2nd parameter of Date.DayOfWeek makes sure that Monday will be taken as first day of the week 38 | DeleteWeekends = List.Select(DeleteHolidays, each Date.DayOfWeek(_, 1) < 5), 39 | // Count the number of days (items in the list) 40 | CountDays = 41 | if Days >= 0 then 42 | DeleteWeekends{Days} 43 | else 44 | DeleteWeekends{List.Count(DeleteWeekends) + Days}, 45 | // CountDays = if Days >= 0 then List.Last(DeleteHolidays) else List.First(DeleteHolidays), 46 | Result = if CountDays = null then StartDate else CountDays 47 | in 48 | Result, 49 | documentation = [ 50 | Documentation.Name = " Xls_WORKDAY ", 51 | Documentation.Description = " Returns a number that represents a date that is the indicated number of working days before or after a date (the starting date). ", 52 | Documentation.LongDescription = " Returns a number that represents a date that is the indicated number of working days before or after a date (the starting date). Working days exclude weekends and any dates identified as holidays. ", 53 | Documentation.Category = " Xls.Date ", 54 | Documentation.Source = " www.TheBIcountant.com - https://wp.me/p6lgsG-2sW ", 55 | Documentation.Version = " 1.0 ", 56 | Documentation.Author = " Imke Feldmann ", 57 | Documentation.Examples = {[Description = " ", 58 | Code = " let 59 | StartDate = #date(2008, 10, 1), 60 | Days = 151, 61 | Holidays = {#date(2008,11,26), #date(2008,12,4), #date(2009,1,21)}, 62 | Result = Xls_WORKDAY(StartDate, Days, Holidays) 63 | 64 | in 65 | Result ", 66 | Result = " #date(2009,5,5) 67 | "]}], 68 | Custom = Value.ReplaceType(func, Value.ReplaceMetadata(Value.Type(func), documentation)) 69 | in 70 | Custom 71 | ``` 72 | -------------------------------------------------------------------------------- /Functions/Grouping/fnCustomGrouping.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("bZQ5ckQhDETv8uMJQBIgHcGBE6dTc/9reP4ULbtVBCQP0NJans/r++untdZd5Hpc95l2vR7/uG2uOvhi4UKY++bdG11o2xcF99vG/Z7tqG4+Gd/x3F/6Mo5U59G+nd3a2OYLXhuLMvftVhvLYLE/KH8YZ7dDYJ+DH3oMZ4xtJfj5bBCt8AV1GoezUMZglRccGDte0IHtO4o12IxnsditQ+XozFErKbI5/HLVPZvqnSFdxE7YOKDo+wM/D3Q5Zxt2ViEgZ8G+g/TiFL1Az6O1M0YrjGBu5+eolJTnkLKr00VHB/LgRodfKxxZrcn8nJUc5zPkOFch84xR7s5J5RLhsoacY/mslk/bK3PsKB6T0ABn87krePrD0E2ssAmWwmKebjtLPNBnrNmAZlI4RFNWZ8A+qzAgmhjHmdsi+MNEJ2hnrjltzDOvwQlPlGWx44Vx61oKvJByUWj95cAfPLu58Iy1cxKOeSkxeYrKYuTmKRHlJqHdIC3n0d4ivX4B", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [Records = _t, Priority = _t, Minutes = _t]), 3 | ChType = Table.TransformColumnTypes(Source,{{"Priority", Int64.Type}, {"Minutes", Int64.Type}}), 4 | Partitions = Table.Partition(ChType, "Priority", 2, each if _ < 3 then 0 else 1), 5 | nRows = Number.Round(Table.RowCount(Partitions{0}) * 0.05, 0), 6 | t1 = Table.RemoveColumns( 7 | Table.AddColumn( 8 | Table.AddRankColumn( 9 | Partitions{0}, 10 | "i", 11 | {"Minutes", Order.Descending}, 12 | [RankKind = RankKind.Ordinal] 13 | ), "Exclude", each [i] <= nRows, type logical 14 | ), {"i"} 15 | ), 16 | t2 = Table.AddColumn(Partitions{1}, "Exclude", each true, type logical), 17 | t = t1 & t2 18 | in 19 | t 20 | -------------------------------------------------------------------------------- /Functions/Insert_Row/fn_insert_row_to_table.pbix: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/PBI-DataVizzle/M-Code/24af47fcc96261d43f3c56e7c8f2175d6b55e992/Functions/Insert_Row/fn_insert_row_to_table.pbix -------------------------------------------------------------------------------- /Functions/IntervalDivision/fnIntervalDivision.md: -------------------------------------------------------------------------------- 1 | # fnIntervalDivision 2 | 3 | ```ioke 4 | let 5 | customFunction = ( input as any, interval as number, divisor as number) => 6 | let 7 | formula = Number.RoundAwayFromZero( input / interval, 0 ) * interval, // calculation 8 | result = (formula / divisor) // final result 9 | in 10 | result 11 | in 12 | customFunction 13 | ``` 14 | -------------------------------------------------------------------------------- /Functions/KeepUnpivotNulls/fnKeepUnPivotNulls.pq: -------------------------------------------------------------------------------- 1 | let 2 | Source = Table, 3 | ToRec = Table.CombineColumnsToRecord( Source, "Value", List.Skip( Table.ColumnNames(Source), 1) ), 4 | ToTable = Table.TransformColumns( ToRec, {"Value", each Record.ToTable( _ )}), 5 | Expand = Table.ExpandTableColumn(ToTable, "Value", {"Name", "Value"}, {"Name", "Value"}) 6 | in 7 | Expand 8 | -------------------------------------------------------------------------------- /Functions/LastNMonths/fnLastNMonths.md: -------------------------------------------------------------------------------- 1 | # fnLastNMonths 2 | ## Is date value within the last N Months 3 | 4 | ### version 1 5 | ```ioke 6 | let 7 | fn = (inputDate as date, months as number, optional entireMonth as logical) => 8 | 9 | let 10 | dateColumn = inputDate, 11 | vToday = Date.From(DateTime.LocalNow()), 12 | monthTest = if (entireMonth = true) and (months > 0) then true else false, 13 | test = if monthTest then vToday > Date.AddMonths(Date.StartOfMonth( dateColumn ), months ) else vToday >= Date.AddMonths( dateColumn , months ), 14 | result = if test then 1 else 0 15 | in 16 | result 17 | 18 | in 19 | fn 20 | ``` 21 | 22 | ### version 2 23 | 24 | ```ioke 25 | let 26 | fn = (inputDate as date, months as number, optional entireMonth as logical) => 27 | 28 | let 29 | numberOfMonths = months *-1, 30 | dateColumn = inputDate, 31 | vToday = Date.From(DateTime.LocalNow()), 32 | monthTest = if (entireMonth = true) and (months > 0) then true else false, 33 | test = if monthTest then Date.AddMonths(Date.EndOfMonth(vToday), numberOfMonths) > dateColumn else Date.AddMonths(vToday, numberOfMonths) >= dateColumn, 34 | result = if test then 1 else 0 35 | in 36 | result 37 | 38 | in 39 | fn 40 | ``` 41 | -------------------------------------------------------------------------------- /Functions/LastRefresh/fnLastRefresh.md: -------------------------------------------------------------------------------- 1 | # fnLastRefresh 2 | ## Date.Now() function for LastRefresh value 3 | 4 | ```C# 5 | let 6 | invokeFn = () => let 7 | inputData = DateTimeZone.FixedUtcNow(), 8 | extractTable = #table(1, {{inputData}}), 9 | formatData = Table.TransformColumnTypes(extractTable,{{"Column1", type datetime}}), 10 | extractDate = Table.AddColumn(formatData, "Date", each DateTime.Date([Column1]), type date), 11 | extractTime = Table.AddColumn(extractDate, "Time", each DateTime.Time([Column1]), type time), 12 | renameHeader = Table.RenameColumns(extractTime,{{"Column1", "Date/Time"}}) 13 | in 14 | renameHeader 15 | in 16 | invokeFn 17 | ``` 18 | -------------------------------------------------------------------------------- /Functions/LastRefresh/fnLastRefresh.pq: -------------------------------------------------------------------------------- 1 | let 2 | invokeFn = () => let 3 | inputData = DateTimeZone.FixedUtcNow(), 4 | extractTable = #table(1, {{inputData}}), 5 | formatData = Table.TransformColumnTypes(extractTable,{{"Column1", type datetime}}), 6 | extractDate = Table.AddColumn(formatData, "Date", each DateTime.Date([Column1]), type date), 7 | extractTime = Table.AddColumn(extractDate, "Time", each DateTime.Time([Column1]), type time), 8 | renameHeader = Table.RenameColumns(extractTime,{{"Column1", "Date/Time"}}) 9 | in 10 | renameHeader 11 | in 12 | invokeFn 13 | -------------------------------------------------------------------------------- /Functions/ListGenerate/fnListGenerateExample.pq: -------------------------------------------------------------------------------- 1 | //Generalized form of List.Generate 2 | = List.Generate( 3 | () => [x = 0, y = 1], // assigns a value to x and y 4 | each [x] + [y] < 100, // apply function as long as < 100 5 | each [y = [x] + [y], // y equals x + y of previous step 6 | x = [y] ], // x changes to previous y 7 | each [x] // returns x 8 | ) 9 | 10 | //Specific Example 11 | 12 | PyramidGenerate = 13 | Table.AddColumn(MarkerIndex, "Triangle", each 14 | List.Generate( 15 | () => [x=0, y= {[Data]}{0}], 16 | each [x] <= MaxCount, 17 | each [ x = [x] + 1, y = Text.Combine( {MarkerIndex[Data]{x}, [y] , MarkerIndex[Data]{x}},"")], 18 | each [y] 19 | ) 20 | ) 21 | -------------------------------------------------------------------------------- /Functions/ListZip/ListZip.md: -------------------------------------------------------------------------------- 1 | # List.Zip 2 | ## unpivot groups of columns 3 | 4 | ```C# 5 | 6 | // list columns to zip; this list will be used in a later step to remove these columns 7 | listZipColumns = { 8 | "Primary Sector Job/Profession", 9 | "Primary Career Aspiration", 10 | "Second Sector Job/Profession", 11 | "Career Aspiration2", 12 | "Third Sector Job/Profession", 13 | "Career Aspiration3" 14 | }, 15 | addListZip = Table.AddColumn( 16 | selectColumns, 17 | "Custom", 18 | each List.Zip( 19 | 20 | // Group 1 - Attributes (list of lists) // list1 (list of attributes) 21 | { 22 | { 23 | "Primary", 24 | "Second", 25 | "Third" 26 | }, 27 | 28 | // Group 2 - Values 1 // list2 (list columns in order) 29 | { 30 | [#"Primary Sector Job/Profession"], 31 | [#"Second Sector Job/Profession"], 32 | [#"Third Sector Job/Profession"] 33 | }, 34 | 35 | // Group 3 - Values 2 // list3 (list columns in order) 36 | { 37 | [Primary Career Aspiration], 38 | [Career Aspiration2], 39 | [Career Aspiration3] 40 | } 41 | 42 | // add additional column groups as list (as required) 43 | /* , 44 | * { 45 | * [ColumnGroupC1] 46 | * [ColumnGroupC2] 47 | * [ColumnGroupC3] 48 | * } 49 | */ 50 | } 51 | ) 52 | ), 53 | // use previous var listZipColumns as list argument to remove those columns as no longer needed 54 | removeGroupColumns = Table.RemoveColumns( 55 | addListZip, 56 | listZipColumns 57 | ) 58 | ``` 59 | -------------------------------------------------------------------------------- /Functions/NavigateToTable/NavigateToTable.md: -------------------------------------------------------------------------------- 1 | # Navigate to Table 2 | ## Navigate to a Table using multiple criteria 3 | 4 | ```c# 5 | 6 | = Source{ [ Column1 = "Value1", Column2 = "Value2" ] } [Data] 7 | 8 | ``` 9 | -------------------------------------------------------------------------------- /Functions/OpenAi/fxOpenAI.md: -------------------------------------------------------------------------------- 1 | #OpenAi 2 | 3 | ``` ioke 4 | 5 | //Do not trust any math and factual data provided by AI. But it is amazing in understanding human language! 6 | 7 | (prompt as text, optional model as text, optional max_tokens as number, optional temperature as number) => 8 | 9 | let 10 | _model = if model = null then "text-davinci-003" else model, 11 | _max_tokens = if max_tokens = null then 500 else max_tokens, 12 | _temperature = if temperature = null then 0.7 else temperature, 13 | 14 | //https://beta.openai.com/account/api-keys 15 | _api_key = "", 16 | _url_base = "https://api.openai.com/", 17 | _url_rel = "v1/completions", 18 | 19 | ContentJSON ="{ 20 | ""prompt"": """ & prompt & """, 21 | ""model"": """ & _model & """, 22 | ""max_tokens"": " & Text.From(_max_tokens) & ", 23 | ""temperature"": " & Text.From(_temperature) & 24 | "}", 25 | 26 | ContentBinary = Text.ToBinary(ContentJSON), 27 | 28 | Source = Json.Document( 29 | Web.Contents( 30 | _url_base, 31 | [ 32 | RelativePath=_url_rel, 33 | Headers=[ 34 | #"Content-Type"="application/json", 35 | #"Authorization"="Bearer " & _api_key 36 | ], 37 | Content=ContentBinary 38 | ] 39 | ) 40 | ), 41 | 42 | choices = Source[choices]{0}, 43 | #"Converted to Table" = Record.ToTable(choices), 44 | #"Filtered Rows" = Table.SelectRows(#"Converted to Table", each ([Name] = "text")), 45 | Result = Table.RemoveColumns(#"Filtered Rows",{"Name"})[Value]{0} 46 | in 47 | Result 48 | 49 | ``` 50 | -------------------------------------------------------------------------------- /Functions/PascalCase/fn_fix_pascal_case.pq: -------------------------------------------------------------------------------- 1 | // Shared by Sergey Lossev 2 | (Source) => 3 | let 4 | to_list = Text.ToList(Source), 5 | accum_chars = List.Accumulate(to_list, "", (sum, x) => sum & (if x = Text.Upper(x) then " " & x else x)), 6 | split = Text.Split(Text.Trim(accum_chars), " "), 7 | accum_words = List.Accumulate(split, "", (sum, x) => sum & (if Text.Length(x) = 1 then x else " " & x & " ")), 8 | replace = Text.Trim(Text.Replace(accum_words, " ", " ")) 9 | in 10 | replace 11 | -------------------------------------------------------------------------------- /Functions/PowerTrim/fnPowerTrim.md: -------------------------------------------------------------------------------- 1 | # fnPowerTrim 2 | ### function to trim spaces and/or special characters 3 | #### Credit to: [Ivan Bondarenko | fnPowerTrim](https://gist.github.com/IvanBond/de5d947421fbfaaf0e8e45c628b01836) 4 | 5 | ```c# 6 | let 7 | fn = // fnPowerTrim 8 | /* ------------------------------ 9 | Author: Imran Haq - PBI QUERYOUS 10 | GitHub: https://github.com/PBIQueryous/M-Code/tree/main/Functions 11 | Description: Trims spaces and special Characters 12 | Credits: Ivan Bondarenko 13 | Link: https://gist.github.com/IvanBond/de5d947421fbfaaf0e8e45c628b01836 14 | Site: 15 | ---------------------------------*/ 16 | 17 | // invoke function & define parameter inputs 18 | let 19 | invokeFn = (inputText as text, optional specialChar as text) => 20 | 21 | // ------------------------------------------------------------------ 22 | // function transformations 23 | 24 | let 25 | char = if specialChar = null then " " else specialChar, 26 | split = Text.Split(inputText, char), 27 | removeblanks = List.Select(split, each _ <> ""), 28 | result = Text.Combine(removeblanks, char) 29 | in 30 | result 31 | , 32 | 33 | // ------------------------------------------------------------------ 34 | // change parameter metadata here 35 | fnType = type function ( 36 | inputText as (type text meta 37 | [ 38 | Documentation.FieldCaption = " Trim Text in Column ", 39 | Documentation.FieldDescription = " Text to Trim: #(lf) Selected Column " 40 | ] 41 | ), 42 | optional specialChar as ( 43 | type text 44 | meta 45 | [ 46 | Documentation.FieldCaption = " Select Special Character: #(lf) Choose from Dropdown ", 47 | Documentation.FieldDescription = " Special Character #(lf) eg: space, colon, semi-colon, hyphen ", 48 | Documentation.AllowedValues = {" ", ":", ";" ,"-", "_", ","} 49 | ] 50 | ) 51 | ) as list, 52 | // ------------------------------------------------------------------ 53 | // edit function metadata here 54 | documentation = 55 | [ 56 | 57 | Documentation.Name = " fnPowerTrim ", 58 | Documentation.Description = " Cleans leading/trailing and double spaces and optional special character ", 59 | Documentation.LongDescription = " Cleans leading/trailing and double spaces and optional special character ", 60 | Documentation.Category = " Trim (columns) ", 61 | Documentation.Source = " PBIQUERYOUS ", 62 | Documentation.Version = " 2.4 ", 63 | Documentation.Author = " Imran Haq ", 64 | Documentation.Examples = 65 | { 66 | [ 67 | Description = " Cleans leading/trailing and double spaces and optional special character ", 68 | Code = " leading and trailing spaces ", 69 | Result = " leading and trailing spaces 70 | #(lf) 71 | #(lf) 72 | " 73 | ] 74 | } 75 | 76 | ] 77 | , 78 | 79 | // ------------------------------------------------------------------ 80 | // Choose between Parameter Documentation or Function Documentation 81 | funtionDocumentation = // -- function metadata 82 | Value.ReplaceType(invokeFn, Value.ReplaceMetadata(Value.Type(invokeFn), documentation)), 83 | 84 | parameterDocumentation = // -- parameter metadata 85 | Value.ReplaceType(invokeFn, fnType) 86 | in 87 | // ------------------------------------------------------------------ 88 | // select one of the above steps and paste below 89 | parameterDocumentation /* <-- Choose final documentation type */ 90 | in 91 | fn 92 | ``` 93 | -------------------------------------------------------------------------------- /Functions/PowerTrim/fnTrimSpaces.md: -------------------------------------------------------------------------------- 1 | # fnTrimSpaces 2 | ### PowerQuery function 3 | ##### Function to trim leading spaces, trailing spaces and/or double (or more) spaces 4 | 5 | ```C# 6 | let 7 | fn = // fnTrimSpaces 8 | /* ------------------------------ 9 | Author: Imran Haq - PBI QUERYOUS 10 | GitHub: https://github.com/PBIQueryous/M-Code/tree/main/Functions 11 | Description: Cleans leading/trailing and double spaces 12 | Credits: John Macdougall MVP 13 | Link: https://www.howtoexcel.org/replicate-trim/ 14 | Site: https://www.howtoexcel.org/blog/ 15 | ---------------------------------*/ 16 | 17 | // invoke function & define parameter inputs 18 | let 19 | invokeFn = (TextToTrim) => 20 | 21 | // ------------------------------------------------------------------ 22 | // function transformations 23 | let 24 | ReplacedText = Text.Replace(TextToTrim, " ", " "), 25 | Result = 26 | if not (Text.Contains(ReplacedText, " ")) then 27 | ReplacedText 28 | else 29 | @invokeFn(ReplacedText) 30 | in 31 | Text.Trim(Result), 32 | 33 | // ------------------------------------------------------------------ 34 | // change parameter metadata here 35 | fnType = type function ( 36 | TextToTrim as ( 37 | type text 38 | meta 39 | [ 40 | Documentation.FieldCaption = " Select Column: #(lf) Trim Text in Column ", 41 | Documentation.FieldDescription = " Select Column to Trim #(lf) eg: Column1 ", 42 | Documentation.SampleValues = {"Column1"} 43 | ] 44 | ) 45 | ) as list, 46 | // ------------------------------------------------------------------ 47 | // edit function metadata here 48 | documentation = 49 | [ 50 | 51 | Documentation.Name = " fnTrimSpaces ", 52 | Documentation.Description = " Cleans leading/trailing and double spaces ", 53 | Documentation.LongDescription = " Cleans leading/trailing and double spaces ", 54 | Documentation.Category = " Trim (columns) ", 55 | Documentation.Source = " PBIQUERYOUS ", 56 | Documentation.Version = " 1.0 ", 57 | Documentation.Author = " Imran Haq ", 58 | Documentation.Examples = 59 | { 60 | [ 61 | Description = " Cleans leading/trailing and double spaces ", 62 | Code = " leading and trailing spaces ", 63 | Result = " leading and trailing spaces 64 | #(lf) 65 | #(lf) 66 | " 67 | ] 68 | } 69 | 70 | ] 71 | , 72 | 73 | // ------------------------------------------------------------------ 74 | // Choose between Parameter Documentation or Function Documentation 75 | funtionDocumentation = // -- function metadata 76 | Value.ReplaceType(invokeFn, Value.ReplaceMetadata(Value.Type(invokeFn), documentation)), 77 | 78 | parameterDocumentation = // -- parameter metadata 79 | Value.ReplaceType(invokeFn, fnType) 80 | in 81 | // ------------------------------------------------------------------ 82 | // select one of the above steps and paste below 83 | funtionDocumentation /* <-- Choose final documentation type */ 84 | in 85 | fn 86 | ``` 87 | -------------------------------------------------------------------------------- /Functions/QueryFolding/fnQueryFolding.md: -------------------------------------------------------------------------------- 1 | ## _QFIndicator 2 | 3 | ```C# 4 | // Save as __QFIndicator 5 | (tableName as table) => 6 | let 7 | fn = 8 | if (Value.Metadata(tableName)[QueryFolding][IsFolded] = true) then 9 | "Query Folded Successfully" 10 | else 11 | error Error.Record( 12 | "Query Folding Warning", 13 | "Query not folding", 14 | "Either the query does not use native query (i.e SQL) or the transformations are not foldable. If you are using SQL, check the query logs" 15 | ) 16 | in 17 | fn 18 | ``` 19 | 20 | 21 | ## _QFAudit 22 | 23 | ```C# 24 | // Save as __QFAudit 25 | (optional RunFn as text) => 26 | let 27 | Source = #sections[Section1], 28 | convertToTable = Record.ToTable(Source), 29 | removeErrors = Table.RemoveRowsWithErrors(convertToTable), 30 | addErrorCol = Table.AddColumn( 31 | removeErrors, 32 | "IsTable", 33 | each [Value] is table, 34 | type logical 35 | ), 36 | filterRows = Table.SelectRows(addErrorCol, each ([IsTable] = true)), 37 | QFCheck = Table.AddColumn( 38 | filterRows, 39 | "QF Check", 40 | each try __QFIndicator([Value]) otherwise Character.FromNumber(10060) & " Check the query", 41 | type text 42 | ), 43 | Result = Table.Sort(QFCheck, QFCheck) 44 | in 45 | Result 46 | ``` 47 | -------------------------------------------------------------------------------- /Functions/RemoveNullColumns/RemoveNullColumns.md: -------------------------------------------------------------------------------- 1 | # Remove all Null Columns 2 | ### Scans previous step (as table) and dynamically removes all completely null columns 3 | 4 | ```c# 5 | = Table.SelectColumns(Source, 6 | List.Select(Table.ColumnNames(Source), 7 | each List.NonNullCount(Table.Column(Source,_)) <> 0)) 8 | ``` 9 | -------------------------------------------------------------------------------- /Functions/RemoveRepeatingCharacters/Text.RemoveRepeatingCharacters.pq: -------------------------------------------------------------------------------- 1 | let func = 2 | (Text as text, Delimiter as text) as text => 3 | let 4 | TextToList = List.Buffer(Text.Split(Text, Delimiter)), 5 | FilterList = List.Select(TextToList, each _ <> ""), 6 | Result = Text.Combine(FilterList, Delimiter) 7 | in 8 | Result 9 | , documentation = [ 10 | Documentation.Name = " Text.RemoveRepeatingCharacters 11 | ", Documentation.Description = " Removes repeating characters of the delimiter from a string 12 | " , Documentation.LongDescription = " Removes repeating characters of the delimiter from a string 13 | ", Documentation.Category = " Text Modification 14 | ", Documentation.Source = " http://wp.me/p6lgsG-M9 . 15 | ", Documentation.Author = " Imke Feldmann: www.TheBIccountant.com . 16 | ", Documentation.Examples = {[Description = " Removes repeating characters of the delimiter from a string 17 | " , Code = " RemoveRepeatingCharacters(""Imke Feldmann"", "" "") 18 | ", Result = " ""Imke Feldmann"" 19 | "]}] 20 | in 21 | Value.ReplaceType(func, Value.ReplaceMetadata(Value.Type(func), documentation)) 22 | -------------------------------------------------------------------------------- /Functions/ReorderCols/fnReorderCols.md: -------------------------------------------------------------------------------- 1 | ```c# 2 | (tbl as table, reorderedColumns as list, offset as number) as table => 3 | Table.ReorderColumns 4 | ( 5 | tbl, 6 | List.InsertRange 7 | ( 8 | List.Difference 9 | ( 10 | Table.ColumnNames(tbl), 11 | reorderedColumns 12 | ), 13 | offset, 14 | reorderedColumns 15 | ) 16 | ) 17 | ``` 18 | -------------------------------------------------------------------------------- /Functions/ReplaceNullsAndBlanks/fnReplaceNullsAndBlanks.md: -------------------------------------------------------------------------------- 1 | # fnReplaceNullsAndBlanks 2 | ## Replaces blanks with nulls, then removes null Rows and Columns 3 | 4 | ```C# 5 | let 6 | fn = (inputTable as table) => 7 | let 8 | source = inputTable, 9 | headers = Table.ColumnNames(source), 10 | replacer = Table.ReplaceValue(source, "", null, Replacer.ReplaceValue, headers), 11 | cleanser = Table.SelectColumns( 12 | Table.SelectRows( 13 | replacer, 14 | each not List.IsEmpty(List.RemoveMatchingItems(Record.FieldValues(_), {"", null})) 15 | ), 16 | List.Select( 17 | Table.ColumnNames(replacer), 18 | each List.NonNullCount(Table.Column(replacer, _)) <> 0 19 | ) 20 | ) 21 | in 22 | cleanser 23 | in 24 | fn 25 | ``` 26 | -------------------------------------------------------------------------------- /Functions/ReplaceNullsAndBlanks/fnReplaceNullsBlanksSpaces.pq: -------------------------------------------------------------------------------- 1 | (t as table) as table => 2 | let 3 | RemoveEmptyCols = Table.RemoveColumns( t, 4 | Table.SelectRows( 5 | Table.Profile( t, 6 | { 7 | {"NonEmpty", each true, each List.NonNullCount( List.Select( List.Transform( _, each try Text.Trim(Text.Clean(_)) otherwise _), each _ <> ""))} 8 | } 9 | )[[Column], [NonEmpty]], each [NonEmpty] = 0 10 | )[Column] 11 | ), 12 | RemoveEmptyRows = Table.SelectRows( RemoveEmptyCols, 13 | each List.NonNullCount( List.Select( List.Transform( Record.FieldValues(_), each try Text.Trim(Text.Clean(_)) otherwise _), each _ <> "")) >0 14 | ) 15 | in 16 | RemoveEmptyRows 17 | -------------------------------------------------------------------------------- /Functions/ReplaceText/fnConditionalReplace_v1.md: -------------------------------------------------------------------------------- 1 | # Replace Text 2 | ### several templates for replacing text, conditional and multiple 3 | 4 | ###### nb: 5 | `Replacer.ReplaceText` = replaces strings and substrings 6 | `Replacer.ReplaceValue` = replaces entire cell contents only 7 | 8 | 9 | 10 | ```c# 11 | = Table.TransformColumns(#”Changed Type”, {“FieldBeingChanged”, each if _ null then “New Value” else “Old Value”}) 12 | ``` 13 | ## Single Step 14 | ```c# 15 | = Table.ReplaceValue( 16 | #"Removed Other Columns", 17 | each [Income] > 50000, 18 | each 2, 19 | (x,y,z)=> if y then z else x, 20 | {"Kidhome", "Teenhome"} 21 | ) 22 | ``` 23 | 24 | ```c# 25 | = List.Accumulate( 26 | Table.ToRecords(ReplacementTable), 27 | [Consumer_ID], 28 | (valueToReplace, replaceOldNewRecord) => 29 | Text.Replace(valueToReplace, replaceOldNewRecord[Old], replaceOldNewRecord[New]) 30 | ) 31 | ``` 32 | 33 | ## Bulk Replace 34 | ```c# 35 | = Table.ReplaceValue( 36 | #"Changed Type", 37 | each [Consumer_ID], 38 | each List.Accumulate( 39 | List.Buffer( Table.ToRecords( ReplacementTable ) ), 40 | [Consumer_ID], 41 | ( valueToReplace, replaceOldNewRecord ) => 42 | Text.Replace( valueToReplace, 43 | replaceOldNewRecord[Old], 44 | replaceOldNewRecord[New] ) ), 45 | Replacer.ReplaceText, 46 | {"Consumer_ID"} 47 | ) 48 | ``` 49 | 50 | 51 | ```c# 52 | = Text.Combine( 53 | List.ReplaceMatchingItems( 54 | { [Consumer_ID] }, 55 | List.Buffer( 56 | List.Zip( { ReplacementTable[Old], 57 | ReplacementTable[New] } ), 58 | Comparer.OrdinalIgnoreCase 59 | ) 60 | ) 61 | ``` 62 | 63 | ## contains word 64 | 65 | ```c# 66 | = Table.ReplaceValue( 67 | #"Changed Type", 68 | each [Consumer_ID], 69 | each if Text.Contains([Consumer_ID] ), "rick", 70 | Comparer.OrdinalIgnoreCase ) then "Rick" else 71 | [Consumer_ID], 72 | Replacer.ReplaceValue, 73 | {"Consumer_ID"} 74 | ) 75 | ``` 76 | 77 | ```c# 78 | = Text.Combine( 79 | List.ReplaceMatchingItems( 80 | { [Consumer_ID] }, 81 | { { "Rick", "RICk" } }, 82 | Comparer.OrdinalIgnoreCase 83 | ) 84 | ) 85 | ``` 86 | 87 | ```c# 88 | Text.Combine( 89 | List.ReplaceMatchingItems( 90 | {[Consumer_ID]}, 91 | { 92 | {"Rick", "RICk"}, 93 | {"GorillaBI", "GORILLABi"}, 94 | {"RickdeGroot", "RICKDEGROOt"} 95 | }, 96 | Comparer.OrdinalIgnoreCase 97 | ) 98 | ) 99 | ``` 100 | -------------------------------------------------------------------------------- /Functions/SharePointFunctions/fnSP_v1.md: -------------------------------------------------------------------------------- 1 | 2 | # OscarMartinez 3 | ## paginated results 4 | 5 | ```ioke 6 | 7 | //This query will return paginated results 8 | 9 | //This approach permits refresh from Power BI service. 10 | //Big thanks to Rob Reily and googlogmobi for their entries that made this possible. 11 | 12 | //https://www.linkedin.com/pulse/loading-data-paged-related-from-ms-graph-api-power-bi-rob-reilly/ 13 | //https://community.powerbi.com/t5/Power-Query/Dynamic-data-sources-aren-t-refreshed-in-the-Power-BI-service/td-p/1563630 14 | 15 | let 16 | baseURL = "https://", 17 | listName = "", 18 | GetPages = (Path)=> 19 | let 20 | Source = Json.Document( 21 | Web.Contents( 22 | baseURL, 23 | [ 24 | RelativePath = Path, 25 | Headers=[ 26 | Accept="application/json;odata=nometadata" 27 | ] 28 | ] 29 | ) 30 | ), 31 | ll= Source[value], 32 | Next = Text.Replace(Source[odata.nextLink], baseURL, ""), 33 | result = try @ll & Function.InvokeAfter(()=> @GetPages(Next) , #duration(0,0,0,0.1)) otherwise @ll 34 | in 35 | result, 36 | 37 | Fullset = GetPages("/_api/web/lists/getbytitle('"&listName&"')/items?" 38 | &"&$select=Id,FileDirRef,FSObjType,ItemEdit/Title" //These are the columns we are requesting, expanded columns must include the parent column name. 39 | &"&$expand=ItemEdit" // Include here the columns that require to be expanded 40 | &"&$filter=startswith(FileDirRef,'/teams/SharePointSite/Shared Documents/Folder Route 1/Folder route 2') and FSObjType eq 0" //This will filter the query to a specific folder to get files only excluding folder items. 41 | ), 42 | #"Converted to Table" = Table.FromList(Fullset, Splitter.SplitByNothing(), null, null, ExtraValues.Error) 43 | in 44 | #"Converted to Table" 45 | 46 | 47 | ``` 48 | 49 | ## binary files 50 | 51 | ```ioke 52 | //This query will retrieve the binaries of the SharePoint document list. 53 | let 54 | //baseURL = "https://", 55 | //listName = "", 56 | Source = Json.Document(Web.Contents(baseURL & "/_api/web/lists/getbytitle('" & listName & "')/items", [Query=[ 57 | #"$top"="1000", //This is the size of the batch 58 | #"$expand" = "File", //This is the column that requires to be expanded 59 | #"$select" = "Id,File/ServerRelativeUrl" //This are the columns we are requesting, expanded columns must include the parent column name. 60 | 61 | ], Headers=[Accept="application/json;odata=nometadata"]]))[value], 62 | #"Converted to Table" = Table.FromList(Source, Splitter.SplitByNothing(), null, null, ExtraValues.Error), 63 | #"Expanded Column1" = Table.ExpandRecordColumn(#"Converted to Table", "Column1", {"Id", "File"}, {"Id", "File"}), 64 | #"Expanded File" = Table.ExpandRecordColumn(#"Expanded Column1", "File", {"ServerRelativeUrl"}, {"ServerRelativeUrl"}), 65 | #"Get Binary fx" = (serverRelativeUrl as text) => let 66 | binaryFx = 67 | Web.Contents(baseURL & "_api/web/GetFileByServerRelativeUrl('"& serverRelativeUrl &"')/$value") 68 | in 69 | binaryFx, 70 | #"Invoked Custom Function" = Table.AddColumn(#"Expanded File", "Query1", each #"Get Binary fx"([ServerRelativeUrl])) 71 | in 72 | #"Invoked Custom Function" 73 | 74 | ``` 75 | -------------------------------------------------------------------------------- /Functions/SharePointFunctions/fn_SP_x1.md: -------------------------------------------------------------------------------- 1 | # retrieve columns internal name 2 | 3 | ```ioke 4 | 5 | //This query will retrieve the columns internalname, display name and type. 6 | let 7 | baseURL = "https://", 8 | listName = "", 9 | Source = Json.Document(Web.Contents( 10 | baseURL&"/_api/web/", 11 | [ 12 | RelativePath = "lists/GetByTitle('"&listName&"')/Fields?$select=Title,InternalName,TypeAsString" , 13 | Headers = [ 14 | Accept = "application/json;odata=nometadata" 15 | ] 16 | ] 17 | )), 18 | value = Source[value], 19 | #"Converted to Table" = Table.FromList(value, Splitter.SplitByNothing(), null, null, ExtraValues.Error), 20 | #"Expanded Column1" = Table.ExpandRecordColumn(#"Converted to Table", "Column1", {"InternalName", "Title", "TypeAsString"}, {"Internal Name","Title", "Type"}), 21 | #"Sorted Rows" = Table.Sort(#"Expanded Column1",{{"Title", Order.Ascending}}) 22 | in 23 | #"Sorted Rows" 24 | 25 | ``` 26 | -------------------------------------------------------------------------------- /Functions/SharePointFunctions/fn_SP_x2.md: -------------------------------------------------------------------------------- 1 | # basic API request 2 | 3 | ```ioke 4 | //This is the basic API request that returns a XML document 5 | let 6 | baseURL = "https://", 7 | listName = "", 8 | Source = Web.Contents( 9 | baseURL & "/_api/web/lists/getbytitle('" & listName & "')/items" 10 | ) 11 | in 12 | Source 13 | 14 | ``` 15 | 16 | ``` ioke 17 | //This is the basic API request that returns a JSON Document 18 | let 19 | baseURL = "https://", 20 | listName = "", 21 | Source = Web.Contents( 22 | baseURL & "/_api/web/lists/getbytitle('" & listName & "')/items", 23 | [ 24 | Headers= 25 | [ 26 | Accept="application/json;odata=nometadata" //changing headers return a JSON Document 27 | ] 28 | ] 29 | ) 30 | in 31 | Source 32 | ``` 33 | 34 | ## 35 | 36 | ```ioke 37 | 38 | let 39 | baseURL = "https://", 40 | listName = "", 41 | Source = Web.Contents( 42 | baseURL & "/_api/web/lists/getbytitle('" & listName & "')/items", 43 | [ 44 | Query = 45 | [ 46 | #"$top"="50", //This is the size of the batch 47 | #"$expand" = "ItemEdit", //These is the column that requires to be expanded 48 | #"$select" = "Id, ItemEdit/Title" //These are the columns we are requesting, expanded columns must include the parent column name. 49 | 50 | ], 51 | Headers= 52 | [ 53 | Accept="application/json;odata=nometadata" //changing headers return a JSON Document 54 | ] 55 | ] 56 | ) 57 | in 58 | Source 59 | 60 | ``` 61 | -------------------------------------------------------------------------------- /Functions/SnakeToCamel/fnSnakeToCamelCase: -------------------------------------------------------------------------------- 1 | = (MyTable as table) => 2 | let 3 | UnderScoreReplaced = Table.TransformColumnNames(MyTable, each Text.Replace(_, "_", " ") ), 4 | CapitalizeFirstLetters = Table.TransformColumnNames(UnderScoreReplaced, each Text.Proper(_)) 5 | in 6 | CapitalizeFirstLetters 7 | -------------------------------------------------------------------------------- /Functions/StartsEndsWith/TextStartsEndsWith.md: -------------------------------------------------------------------------------- 1 | ```c# 2 | = Text.StartsWith( "I got the Power", "I got") // Returns true 3 | = Text.StartsWith( "I got the Power", "i got") // Returns false 4 | = Text.StartsWith( "I got the Power", "i got", 5 | Comparer.Ordinal) // Returns false 6 | = Text.StartsWith( "I got the Power", "i got", 7 | Comparer.OrdinalIgnoreCase) // Returns true 8 | 9 | = Text.EndsWith( "Biking to home", "home") // Returns true 10 | = Text.EndsWith( "Biking to home", "HOME") // Returns false 11 | = Text.EndsWith( "Biking to home", "HOME", 12 | Comparer.Ordinal) // Returns false 13 | = Text.EndsWith( "Biking to home", "HOME", 14 | Comparer.OrdinalIgnoreCase) // Returns false 15 | ``` 16 | -------------------------------------------------------------------------------- /Functions/Templates/function-basic-template.md: -------------------------------------------------------------------------------- 1 | ```ruby 2 | // --------------------------- Function ------------------------------ 3 | let 4 | // --------------------------- Fucntion segment ----------------------------------- 5 | output = 6 | (/* parameter as text, optional opt_parameter as text */) /* as text */ => // Input definition + Function output type definition 7 | let // Inner function steps declaration 8 | initStep = "", 9 | lastStep = "" 10 | in 11 | lastStep, // Output from inner steps 12 | // --------------------------- Documentation segment ------------------------------ 13 | documentation = [ 14 | Documentation.Name = " NAME OF FUNCTION ", // Name of the function 15 | Documentation.Description = " DESCRIPTION ", // Decription of the function 16 | Documentation.Source = " URL / SOURCE DESCRIPTION ", // Source of the function 17 | Documentation.Version = " VERSION ", // Version of the function 18 | Documentation.Author = " AUTHOR ", // Author of the function 19 | Documentation.Examples = // Examples of the functions 20 | { 21 | [ 22 | Description = " EXAMPLE DESCRIPTION ", // Description of the example 23 | Code = " EXAMPLE CODE ", // Code of the example 24 | Result = " EXAMPLE RESULT " // Result of the example 25 | ] 26 | } 27 | ] 28 | // --------------------------- Output -------------------------------------------- 29 | in 30 | Value.ReplaceType( // Replace type of the value 31 | output, // Function caller 32 | Value.ReplaceMetadata( // Replace metadata of the function 33 | Value.Type(output), // Return output type of function 34 | documentation // Documentation assigment 35 | ) 36 | ) 37 | // ------------------------------------------------------------------------------------ 38 | ``` 39 | -------------------------------------------------------------------------------- /Functions/Templates/functionTemplate_v1a.md: -------------------------------------------------------------------------------- 1 | # Function Template 2 | ### function template with steps to edit parameter and function metadata 3 | 4 | ```ioke 5 | let 6 | customFunction = // fnReplaceBlanksRemoveNulls 7 | /* ------------------------------ 8 | Author: Imran Haq - PBI QUERYOUS 9 | Description: fnReplaceBlanksRemoveNulls 10 | ---------------------------------*/ 11 | 12 | // 1.0: invoke function & define parameter inputs 13 | let 14 | invokeFunction = (inputTable as table) => 15 | 16 | // ------------------------------------------------------------------ 17 | // 2.0: function transformations 18 | let 19 | source = inputTable, 20 | headers = Table.ColumnNames(source), 21 | replacer = Table.ReplaceValue(source, "", null, Replacer.ReplaceValue, headers), 22 | cleanser = Table.SelectColumns( 23 | Table.SelectRows( 24 | replacer, 25 | each not List.IsEmpty(List.RemoveMatchingItems(Record.FieldValues(_), {"", null})) 26 | ), 27 | List.Select( 28 | Table.ColumnNames(replacer), 29 | each List.NonNullCount(Table.Column(replacer, _)) <> 0 30 | ) 31 | ) 32 | in 33 | cleanser 34 | , 35 | 36 | // ------------------------------------------------------------------ 37 | // 3.0: change parameter metadata here 38 | fnType = type function ( 39 | // 3.0.1: first parameter 40 | dataInput as ( 41 | type text 42 | meta 43 | [ 44 | Documentation.FieldCaption = " Select Query: #(lf) Or input previous step ", 45 | Documentation.FieldDescription = " Select Query/Step: #(cr,lf) Or input previous step ", 46 | Documentation.SampleValues = {"Table/Step"} 47 | ] 48 | ) 49 | 50 | // 3.0.2: second parameter 51 | /* , 52 | optional separator as ( 53 | type text 54 | meta 55 | [ 56 | Documentation.FieldCaption = " Choose Separator Type ", 57 | Documentation.FieldDescription = " Recommended to use #(lf) forward slash / ", 58 | Documentation.AllowedValues = {"-", "/"} 59 | ] 60 | ) 61 | ) */ 62 | // 3.1: parameter return type 63 | ) as list, 64 | // ------------------------------------------------------------------ 65 | // 4.0: edit function metadata here 66 | documentation = 67 | [ 68 | 69 | Documentation.Name = " fnReplaceBlanksRemoveNulls ", 70 | Documentation.Description = " Replaces blanks and removes null rows and columns ", 71 | Documentation.LongDescription = " Replaces blanks and removes null rows and columns ", 72 | Documentation.Category = " ETL Category ", 73 | Documentation.Source = " PBIQUERYOUS ", 74 | Documentation.Version = " 1.0 ", 75 | Documentation.Author = " Imran Haq ", 76 | Documentation.Examples = 77 | { 78 | [ 79 | Description = " Replaces blanks and removes null rows and columns ", 80 | Code = " fnReplaceBlanksRemoveNulls( prevStep ) ", 81 | Result = 82 | " 83 | 1. Takes previous step 84 | 2. Replaces blanks with nulls 85 | 3. Removes null rows and columns 86 | 87 | " 88 | 89 | ] 90 | /* , 91 | [ 92 | Description = " description ", 93 | Code = " code ", 94 | Result = " result #(cr,lf) new line 95 | #(cr,lf) new line #(cr,lf) 2 " 96 | ] */ 97 | } 98 | 99 | ] 100 | , 101 | 102 | // ------------------------------------------------------------------ 103 | // 5.0: Choose between Parameter Documentation or Function Documentation 104 | functionDocumentation = // -- function metadata 105 | Value.ReplaceType(invokeFunction, Value.ReplaceMetadata( Value.Type(invokeFunction), documentation)), 106 | 107 | parameterDocumentation = // -- parameter metadata 108 | Value.ReplaceType(invokeFunction, fnType), 109 | 110 | replaceMeta = // -- both metas 111 | Value.ReplaceType( 112 | Value.ReplaceType( invokeFunction, fnType ), 113 | Value.ReplaceMetadata( Value.Type(invokeFunction), documentation) 114 | ) 115 | in 116 | // ------------------------------------------------------------------ 117 | // select one of the above steps and paste below 118 | replaceMeta /* <-- Choose final documentation type */ 119 | 120 | in 121 | customFunction 122 | ``` 123 | -------------------------------------------------------------------------------- /Functions/TransformHeaders/fnTransformHeaders.md: -------------------------------------------------------------------------------- 1 | # Transform Headers Functions 2 | 3 | ### Basic 4 | ```ioke 5 | 6 | Table.TransformColumnNames( 7 | table as table, 8 | nameGenerator as function, 9 | optional options as nullable record 10 | ) 11 | 12 | ``` 13 | 14 | --- 15 | 16 | ### Replace Characters 17 | ```ioke 18 | 19 | = Table.TransformColumnNames( Source, each Text.Replace( _, "_", " " ) ) 20 | // Replaces all underscores with a space 21 | 22 | = Table.TransformColumnNames( Source, each Text.Replace( _, ".", " " ) ) 23 | // Replaces all full stops with a space 24 | 25 | ``` 26 | 27 | --- 28 | 29 | 30 | ### Replace Characters 31 | ```ioke 32 | 33 | = Table.TransformColumnNames( Source, each "Prefix." & _ ) 34 | // Adds the text "Prefix." in front of each column name 35 | 36 | = Table.TransformColumnNames( Source, each _ & ".Suffix" ) 37 | // Adds the text ".Suffix" after each column name 38 | 39 | ``` 40 | 41 | 42 | --- 43 | 44 | ### Changing Capatilisation 45 | ```ioke 46 | 47 | = Table.TransformColumnNames( Source, each Text.Lower( _ ) ) 48 | // Transforms column names to lowercase 49 | 50 | = Table.TransformColumnNames( Source, each Text.Upper( _ ) ) 51 | // Transforms column names to uppercase 52 | 53 | = Table.TransformColumnNames( Source, each Text.Proper( _ ) ) 54 | // Capitalizes each word in the column names 55 | 56 | ``` 57 | --- 58 | 59 | ### Clean or Trim Strings 60 | ```ioke 61 | 62 | = Table.TransformColumnNames( Source, each Text.Trim( _ ) ) 63 | // Removes leading and trailing whitespaces in column names 64 | 65 | = Table.TransformColumnNames( Source, each Text.Clean( _ ) ) 66 | // Removes non printable characters in column names 67 | 68 | ``` 69 | 70 | --- 71 | 72 | ### Conditional Transforms 73 | ```ioke 74 | 75 | Table.TransformColumnNames( Source, 76 | each if Text.Contains(_, "date" ) then "Bingo." & _ else _ ) 77 | // Adds a prefix to each column name that contains the text "date" 78 | 79 | ``` 80 | 81 | --- 82 | 83 | ### Split lower/upper case 84 | ```ioke 85 | 86 | Table.SplitColumn( 87 | #"Split Column by Character Transition", 88 | "Product Color", 89 | Splitter.SplitTextByCharacterTransition({"a" .. "z"}, {"A" .. "Z"}), 90 | {"Product Color.1", "Product Color.2"} 91 | ) 92 | 93 | // From here you only need to copy the following part: 94 | = Splitter.SplitTextByCharacterTransition({"a" .. "z"}, {"A" .. "Z"}) 95 | 96 | 97 | Table.TransformColumnNames( 98 | Source, 99 | each Text.Combine( 100 | Splitter.SplitTextByCharacterTransition({"a" .. "z"}, {"A" .. "Z"})(_) 101 | , " ") 102 | ) 103 | ``` 104 | 105 | --- 106 | 107 | ### rename transition table 108 | ```ioke 109 | 110 | = Table.RenameColumns( table as table, // the table to rename columns on 111 | renames as list, // pairs of old and new colum names as list 112 | optional missingField ) 113 | 114 | = Table.RenameColumns( Source, 115 | List.Zip( { Rename[OldName], Rename[NewName] } ), 116 | MissingField.Ignore ) 117 | 118 | = Table.RenameColumns( Source, 119 | Table.ToRows( Rename[[OldName],[NewName]] ), 120 | MissingField.Ignore ) 121 | ``` 122 | 123 | 124 | -------------------------------------------------------------------------------- /Functions/Year-Over-Year/Year-Over-Year_dates.pq: -------------------------------------------------------------------------------- 1 | let 2 | previous_step = col_like_for_like, 3 | add_records_tbl = Table.AddColumn( 4 | previous_step, 5 | "lfl_records", 6 | each 7 | let 8 | col_records = [ 9 | PY_like_for_like = Date.AddDays([Date], - 364), 10 | PY_minus_1_like_for_like = Date.AddDays([Date], - (364 * 2)) 11 | ] 12 | in 13 | col_records, 14 | type [PY_like_for_like = Date.Type, PY_minus_1_like_for_like = Date.Type] 15 | ), 16 | get_headers = Record.FieldNames(add_records_tbl[lfl_records]{0}), 17 | exp_record_fields = Table.ExpandRecordColumn( 18 | add_records_tbl, 19 | "lfl_records", 20 | get_headers, 21 | get_headers 22 | ) 23 | in 24 | exp_record_fields 25 | -------------------------------------------------------------------------------- /Functions/__GetGithubFunction/_getGithubPQFunction.md: -------------------------------------------------------------------------------- 1 | ```ioke 2 | let 3 | invokeFunction = ( rawContentURL as text ) => 4 | 5 | let 6 | // "https://raw.githubusercontent.com/PBIQueryous/M-Code/main/Functions/LastRefresh/fnLastRefresh.pq" 7 | pathURL = rawContentURL, 8 | extractMCode = Text.FromBinary( Web.Contents( pathURL )), 9 | runMCode = Expression.Evaluate( extractMCode, #shared ) 10 | in 11 | runMCode 12 | in 13 | invokeFunction 14 | ``` 15 | -------------------------------------------------------------------------------- /Functions/__GetGithubFunction/fnGetGithubFunction.pq: -------------------------------------------------------------------------------- 1 | let 2 | invokeFunction = ( rawContentURL as text ) => 3 | 4 | let 5 | // "https://raw.githubusercontent.com/PBIQueryous/M-Code/main/Functions/LastRefresh/fnLastRefresh.pq" 6 | pathURL = rawContentURL, 7 | extractMCode = Text.FromBinary( Web.Contents( pathURL )), 8 | runMCode = Expression.Evaluate( extractMCode, #shared ) 9 | in 10 | runMCode 11 | in 12 | invokeFunction 13 | -------------------------------------------------------------------------------- /Functions/filterMax/fnFilterMax.md: -------------------------------------------------------------------------------- 1 | ```C# 2 | // Filter by Max number 3 | Table.SelectRows(EXPANDinvokedColumn, let latest = List.Max(EXPANDinvokedColumn[FileDate]) in each [FileDate] = latest) 4 | ``` 5 | -------------------------------------------------------------------------------- /Functions/filterMax/fnFilterMax_v1.md: -------------------------------------------------------------------------------- 1 | ```C# 2 | Table.SelectRows( 3 | inputTable, 4 | let 5 | latest = List.Max(inputTable[Value]), 6 | filter = each [Value] = latest 7 | in 8 | filter 9 | ) 10 | ``` 11 | -------------------------------------------------------------------------------- /Functions/fnGetCalendarMonth/fnGetCalendarMonth.md: -------------------------------------------------------------------------------- 1 | # fnGetCalendarMonth 2 | ### PowerQuery function 3 | ##### Function to retrieve Calendar Month for a list of Fiscal Periods ordered by Fiscal Start Month 4 | 5 | ```C# 6 | let 7 | function1 = // fnGetCalendarMonth 8 | /* ------------------------------ 9 | Author: Imran Haq - PBI QUERYOUS 10 | Description: Get Calendar Month Number from Fiscal Period Number 11 | ---------------------------------*/ 12 | 13 | // invoke function & define parameter inputs 14 | let 15 | invokeFunction = (fiscalPeriod as any, fiscalStart as number) => 16 | 17 | // ------------------------------------------------------------------ 18 | // function transformations 19 | let 20 | fiscalMonth = if fiscalStart = null then 1 else fiscalStart, 21 | columnName = fiscalPeriod, 22 | calc = (12-fiscalMonth)+1, 23 | x = Number.Abs(columnName + fiscalMonth) - 1, 24 | y = Number.Abs(columnName + fiscalMonth) - 13, 25 | z = if columnName <= calc then x else y 26 | in 27 | z 28 | , 29 | 30 | // ------------------------------------------------------------------ 31 | // change parameter metadata here 32 | fnType = type function ( 33 | fiscalPeriod as ( 34 | type any 35 | meta 36 | [ 37 | Documentation.FieldCaption = " Invoke Custom Function and choose column ", 38 | Documentation.FieldDescription = " Select a column #(cr,lf) eg: [ColumnName] ", 39 | Documentation.SampleValues = {"[ColumnName]"} 40 | ] 41 | ), 42 | fiscalStart as ( 43 | type number 44 | meta 45 | [ 46 | Documentation.FieldCaption = " Choose Fiscal Month Start ", 47 | Documentation.FieldDescription = " Fiscal Month Start #(cr,lf) Choose a month number ", 48 | Documentation.AllowedValues = {1..12} 49 | ] 50 | ) 51 | ) as list, 52 | // ------------------------------------------------------------------ 53 | // edit function metadata here 54 | documentation = 55 | [ 56 | 57 | Documentation.Name = " fnGetCalendarMonth ", 58 | Documentation.Description = " Retrieves correct calendar month based on a fiscal period number ", 59 | Documentation.LongDescription = " Retrieves correct calendar month based on a fiscal period number ", 60 | Documentation.Category = " Fiscal Calendar Category ", 61 | Documentation.Source = " PBIQUERYOUS ", 62 | Documentation.Version = " 1.0 ", 63 | Documentation.Author = " Imran Haq ", 64 | Documentation.Examples = 65 | { 66 | [ 67 | Description = " ColumnName = [Column1]; Fiscal Month Start = 4 ", 68 | Code = " 69 | let #(cr,lf) 70 | fiscalMonth = if fiscalStart = null then 1 else fiscalStart, #(cr,lf) 71 | columnName = fiscalPeriod, #(cr,lf) 72 | calc = (12-fiscalMonth)+1, #(cr,lf) 73 | x = Number.Abs(columnName + fiscalMonth) - 1, #(cr,lf) 74 | y = Number.Abs(columnName + fiscalMonth) - 13, #(cr,lf) 75 | z = if columnName <= calc then x else y #(cr,lf) 76 | in #(cr,lf) 77 | z 78 | ", 79 | Result = " fnGetCalendarMonth([Column1], 4) " 80 | ] 81 | } 82 | 83 | ] 84 | , 85 | 86 | // ------------------------------------------------------------------ 87 | // Choose between Parameter Documentation or Function Documentation 88 | functionDocumentation = // -- function metadata 89 | Value.ReplaceType(invokeFunction, Value.ReplaceMetadata(Value.Type(invokeFunction), documentation)), 90 | 91 | parameterDocumentation = // -- parameter metadata 92 | Value.ReplaceType(invokeFunction, fnType) 93 | in 94 | // ------------------------------------------------------------------ 95 | // select one of the above steps and paste below 96 | parameterDocumentation /* <-- Choose final documentation type */ 97 | in 98 | function1 99 | ``` 100 | -------------------------------------------------------------------------------- /Functions/fnGetCalendarMonth/fnGetMonthFromFiscalPeriod.md: -------------------------------------------------------------------------------- 1 | # fnGetCalendarMonth 2 | ### PowerQuery function 3 | ##### Function to retrieve Calendar Month for a list of Fiscal Periods ordered by Fiscal Start Month 4 | 5 | ```C# 6 | 7 | let 8 | fn = // fnFiscalPeriodToMonth 9 | /* ------------------------------ 10 | Author: Imran Haq - PBI QUERYOUS 11 | GitHub: https://github.com/PBIQueryous/M-Code/ 12 | Description: Takes Fiscal Period and Converts to Month Number 13 | Credits: Gilbert Quevauvilliers 14 | Link: https://gqbi.wordpress.com/2016/09/13/power-bi-how-to-easily-create-dynamic-date-tabledimension-with-fiscal-attributes-using-power-query/comment-page-1/ 15 | Site: https://gqbi.wordpress.com/ 16 | ---------------------------------*/ 17 | 18 | // invoke function & define parameter inputs 19 | let 20 | invokeFn = (fiscalMonthNumber as number, dateColumn as any) => 21 | 22 | // ------------------------------------------------------------------ 23 | // function transformations 24 | let 25 | fiscalMonthStart = fiscalMonthNumber, 26 | fiscalMonthCalc = 10 + fiscalMonthStart, 27 | calculation = Number.Mod(dateColumn + fiscalMonthCalc , 12) + 1, 28 | Result = calculation 29 | in 30 | Result 31 | , 32 | 33 | // ------------------------------------------------------------------ 34 | // change parameter metadata here 35 | fnType = type function ( 36 | exampleInput as ( 37 | type number 38 | meta 39 | [ 40 | Documentation.FieldCaption = " Fiscal Month Number ", 41 | Documentation.FieldDescription = " Input Fiscal Month Start Number ", 42 | Documentation.SampleValues = {"123"} 43 | ] 44 | ), 45 | column1 as ( 46 | type any 47 | meta 48 | [ 49 | Documentation.FieldCaption = " Select Fiscal Period Column ", 50 | Documentation.FieldDescription = " Select Fiscal Period Column (eg: [Column1]) ", 51 | Documentation.SampleValues = {"[Column1]"} 52 | ] 53 | ) 54 | ) as list, 55 | // ------------------------------------------------------------------ 56 | // edit function metadata here 57 | documentation = 58 | [ 59 | 60 | Documentation.Name = " fnFiscalPeriodToMonth ", 61 | Documentation.Description = " Takes Fiscal Period and Converts to Month Number ", 62 | Documentation.LongDescription = " Takes Fiscal Period and Converts to Month Number ", 63 | Documentation.Category = " Fiscal Date ", 64 | Documentation.Source = " PBIQUERYOUS ", 65 | Documentation.Version = " 1.0 ", 66 | Documentation.Author = " Imran Haq ", 67 | Documentation.Examples = 68 | { 69 | [ 70 | Description = " ExampleDescription ", 71 | Code = " = Number.Mod(dateColumn + fiscalMonthCalc , 12)+1 ", 72 | Result = " ExampleOutput 73 | #(lf) 74 | #(lf) 75 | " 76 | ] 77 | } 78 | 79 | ] 80 | , 81 | 82 | // ------------------------------------------------------------------ 83 | // Choose between Parameter Documentation or Function Documentation 84 | funtionDocumentation = // -- function metadata 85 | Value.ReplaceType(invokeFn, Value.ReplaceMetadata(Value.Type(invokeFn), documentation)), 86 | 87 | parameterDocumentation = // -- parameter metadata 88 | Value.ReplaceType(invokeFn, fnType) 89 | in 90 | // ------------------------------------------------------------------ 91 | // select one of the above steps and paste below 92 | parameterDocumentation /* <-- Choose final documentation type */ 93 | in 94 | fn 95 | 96 | ``` 97 | -------------------------------------------------------------------------------- /Functions/fnGetFiscalPeriod.md: -------------------------------------------------------------------------------- 1 | # fnGetFiscalPeriod 2 | 3 | ```ioke 4 | let 5 | function1 = // fnGetCalendarMonth 6 | /* ------------------------------ 7 | Author: Imran Haq - PBI QUERYOUS 8 | Description: Get Calendar Month Number from Fiscal Period Number 9 | ---------------------------------*/ 10 | 11 | // invoke function & define parameter inputs 12 | let 13 | invokeFunction = (monthNum as any, fiscalMonthNum as number) => 14 | 15 | // ------------------------------------------------------------------ 16 | // function transformations 17 | let 18 | arg1 = monthNum >= fiscalMonthNum and fiscalMonthNum > 1, 19 | res1 = monthNum - (fiscalMonthNum - 1), 20 | arg2 = monthNum >= fiscalMonthNum and fiscalMonthNum = 1, 21 | res2 = monthNum, 22 | res3 = monthNum + (12-fiscalMonthNum+1), 23 | result = if arg1 then res1 else if arg2 then res2 else res3 24 | in 25 | result 26 | 27 | , 28 | 29 | // ------------------------------------------------------------------ 30 | // change parameter metadata here 31 | fnType = type function ( 32 | fiscalPeriod as ( 33 | type any 34 | meta 35 | [ 36 | Documentation.FieldCaption = " Invoke Custom Function and choose column ", 37 | Documentation.FieldDescription = " Select a column #(cr,lf) eg: [ColumnName] ", 38 | Documentation.SampleValues = {"[ColumnName]"} 39 | ] 40 | ), 41 | fiscalStart as ( 42 | type number 43 | meta 44 | [ 45 | Documentation.FieldCaption = " Choose Fiscal Month Start ", 46 | Documentation.FieldDescription = " Fiscal Month Start #(cr,lf) Choose a month number ", 47 | Documentation.AllowedValues = {1..12} 48 | ] 49 | ) 50 | ) as list, 51 | // ------------------------------------------------------------------ 52 | // edit function metadata here 53 | documentation = 54 | [ 55 | 56 | Documentation.Name = " fnGetCalendarMonth ", 57 | Documentation.Description = " Retrieves correct calendar month based on a fiscal period number ", 58 | Documentation.LongDescription = " Retrieves correct calendar month based on a fiscal period number ", 59 | Documentation.Category = " Fiscal Calendar Category ", 60 | Documentation.Source = " PBIQUERYOUS ", 61 | Documentation.Version = " 1.0 ", 62 | Documentation.Author = " Imran Haq ", 63 | Documentation.Examples = 64 | { 65 | [ 66 | Description = " ColumnName = [Column1]; Fiscal Month Start = 4 ", 67 | Code = " 68 | let #(cr,lf) 69 | fiscalMonth = if fiscalStart = null then 1 else fiscalStart, #(cr,lf) 70 | columnName = fiscalPeriod, #(cr,lf) 71 | calc = (12-fiscalMonth)+1, #(cr,lf) 72 | x = Number.Abs(columnName + fiscalMonth) - 1, #(cr,lf) 73 | y = Number.Abs(columnName + fiscalMonth) - 13, #(cr,lf) 74 | z = if columnName <= calc then x else y #(cr,lf) 75 | in #(cr,lf) 76 | z 77 | ", 78 | Result = " fnGetCalendarMonth([Column1], 4) " 79 | ] 80 | } 81 | 82 | ] 83 | , 84 | 85 | // ------------------------------------------------------------------ 86 | // Choose between Parameter Documentation or Function Documentation 87 | functionDocumentation = // -- function metadata 88 | Value.ReplaceType(invokeFunction, Value.ReplaceMetadata(Value.Type(invokeFunction), documentation)), 89 | 90 | parameterDocumentation = // -- parameter metadata 91 | Value.ReplaceType(invokeFunction, fnType) 92 | in 93 | // ------------------------------------------------------------------ 94 | // select one of the above steps and paste below 95 | parameterDocumentation /* <-- Choose final documentation type */ 96 | in 97 | function1 98 | 99 | ``` 100 | -------------------------------------------------------------------------------- /Functions/fnGetInitials/fnGetInitials.md: -------------------------------------------------------------------------------- 1 | # fnGetInitials 2 | ## get initials of each word (replacing " and " & " of ") 3 | 4 | ```c# 5 | Table.AddColumn( 6 | PrevStep, 7 | "NewColumnName", 8 | each Text.Combine( 9 | List.Transform( 10 | Text.Split(Text.Replace(Text.Replace([ColumnName], " text1 ", ""), " text2 ", ""), " "), 11 | each Text.Start(_, 1) 12 | ), 13 | "" 14 | ) 15 | ) 16 | ``` 17 | -------------------------------------------------------------------------------- /Functions/fnGetInitials/fnGetInitials_v2.pq: -------------------------------------------------------------------------------- 1 | 2 | Table.AddColumn( 3 | Custom, 4 | "Prov1", 5 | each 6 | let 7 | x = "", 8 | xx = each Text.Start(_, 1), 9 | y = Text.Replace( 10 | Text.Replace(Text.Replace([ProviderName], 11 | " and ", ""), 12 | " of ", ""), 13 | "The ", 14 | "" 15 | ), 16 | z = Text.Combine(List.Transform(Text.Split(y, " "), xx), ""), 17 | zz = Text.Start(Text.Replace([ProviderName], " ", ""), 4) 18 | in 19 | zz & "-" & z 20 | ) 21 | -------------------------------------------------------------------------------- /Functions/fnGetInitials/fnGetInitials_v3.pqm: -------------------------------------------------------------------------------- 1 | Table.AddColumn(Custom, "Prov1", each let 2 | x = "", 3 | xx = each Text.Start(_, 1), 4 | y = 5 | Text.Replace( 6 | Text.Replace( 7 | Text.Replace([ProviderName], 8 | " and ", x), 9 | " of ", x), 10 | "The ", x), 11 | z = Text.Combine(List.Transform(Text.Split(y, " "), xx), ""), 12 | zz1 = Text.Start(Text.Replace([ProviderName], " ", ""), 3), 13 | zz2 = Text.Start(Text.Replace([ProviderName], " ", ""), 5), 14 | zzz = if( Text.Length( Text.BeforeDelimiter([ProviderName], " ", 0)) >= 6) then 5 else 3, 15 | zz3 = Text.Start(Text.Replace([ProviderName], " ", ""), zzz) 16 | in 17 | zz3 & "-" & z , 18 | type text) 19 | -------------------------------------------------------------------------------- /Functions/fnSuperCleanTextString/fnSuperCleanTextString.pq: -------------------------------------------------------------------------------- 1 | let 2 | CleanAndTransformText = (inputText as text, toProperCase as logical) as text => 3 | let 4 | // Step 1: Remove underscores and replace with spaces 5 | noUnderscores = Text.Replace(inputText, "_", " "), 6 | 7 | // Step 2: Replace double spaces recursively 8 | ReplaceDoubleSpaces = (text as text) as text => 9 | let 10 | replacedText = Text.Replace(text, " ", " "), 11 | result = if Text.Contains(replacedText, " ") then @ReplaceDoubleSpaces(replacedText) else replacedText 12 | in 13 | result, 14 | 15 | noDoubleSpaces = ReplaceDoubleSpaces(noUnderscores), 16 | 17 | // Step 3: Trim the text 18 | trimmedText = Text.Trim(noDoubleSpaces), 19 | 20 | // Step 4: Handle CamelCase by inserting spaces before capital letters (except at the start or after hyphens) 21 | HandleCamelCase = (text as text) as text => 22 | let 23 | // Split text into characters 24 | charList = Text.ToList(text), 25 | // Initialize an empty list for the new characters 26 | newList = List.Transform({0..List.Count(charList)-1}, each 27 | if _ = 0 then 28 | charList{_} 29 | else if charList{_} = "-" then 30 | charList{_} 31 | else if Text.Upper(charList{_}) = charList{_} and Text.Upper(charList{_ - 1}) <> "-" and Text.Upper(charList{_}) <> Text.Lower(charList{_}) then 32 | " " & charList{_} 33 | else 34 | charList{_}), 35 | insertSpaces = Text.Combine(newList, "") 36 | in 37 | insertSpaces, 38 | 39 | camelCaseHandledText = HandleCamelCase(trimmedText), 40 | 41 | // Step 5: Transform to Proper Case 42 | ToProperCase = (text as text) as text => 43 | let 44 | properCasedText = Text.Proper(text) 45 | in 46 | properCasedText, 47 | 48 | // Step 6: Transform to Sentence Case 49 | ToSentenceCase = (text as text) as text => 50 | let 51 | lowerText = Text.Lower(text), 52 | sentenceCasedText = if Text.Length(lowerText) > 0 then 53 | Text.Upper(Text.Start(lowerText, 1)) & Text.End(lowerText, Text.Length(lowerText) - 1) 54 | else 55 | lowerText 56 | in 57 | sentenceCasedText, 58 | 59 | // Step 7: Apply the appropriate transformation based on the toProperCase parameter 60 | transformedText = if toProperCase then 61 | ToProperCase(camelCaseHandledText) 62 | else 63 | ToSentenceCase(camelCaseHandledText) 64 | in 65 | transformedText 66 | in 67 | CleanAndTransformText 68 | -------------------------------------------------------------------------------- /Functions/zzzExcel/flashFillAlphabet.md: -------------------------------------------------------------------------------- 1 | # Excel FlashFill Alphabet 2 | 3 | ```vba 4 | 5 | 6 | =LEFT(ADDRESS(1, ROW(A1), 4, TRUE), (ROW(A1)>26)+1) 7 | 8 | 9 | ``` 10 | -------------------------------------------------------------------------------- /GetDataFromSharePoint/fnCombineFolder.md: -------------------------------------------------------------------------------- 1 | # Get folder and combine files 2 | ## Credit to Imke Feldmann 3 | 4 | 5 | ```c# 6 | let 7 | Source = 8 | let 9 | func = // fnGetSharepointFile 10 | 11 | let 12 | Source = (FullPath as text) => 13 | let 14 | 15 | // Helper function 16 | fnUriUnescapeString = //Source: https://stackoverflow.com/questions/36242695/how-to-decodeuricomponent-ex-2f3f263d 17 | (data as text) as text => 18 | let 19 | ToList = List.Buffer(Text.ToList(data)), 20 | Accumulate = List.Accumulate( 21 | ToList, 22 | [Bytes = {}], 23 | (state, current) => 24 | let 25 | HexString = state[HexString]?, 26 | NextHexString = HexString & current, 27 | NextState = 28 | if HexString <> null then 29 | if Text.Length(NextHexString) = 2 then 30 | [ 31 | Bytes = state[Bytes] 32 | & Binary.ToList( 33 | Binary.FromText(NextHexString, BinaryEncoding.Hex) 34 | ) 35 | ] 36 | else 37 | [HexString = NextHexString, Bytes = state[Bytes]] 38 | else if current = "%" then 39 | [HexString = "", Bytes = state[Bytes]] 40 | else 41 | [Bytes = state[Bytes] & {Character.ToNumber(current)}] 42 | in 43 | NextState 44 | ), 45 | FromBinary = Text.FromBinary(Binary.FromList(Accumulate[Bytes])) 46 | in 47 | FromBinary, 48 | StaticRoot = SharePoint.Contents(RootPath, [ApiVersion = 15]), 49 | ExtractRoot = fnUriUnescapeString(Text.BeforeDelimiter(FullPath, "/", 4)), 50 | FileName = fnUriUnescapeString( 51 | Text.AfterDelimiter(FullPath, "/", {0, RelativePosition.FromEnd}) 52 | ), 53 | NonRootFolders = fnUriUnescapeString( 54 | Text.BeforeDelimiter( 55 | Text.AfterDelimiter(FullPath, ExtractRoot), 56 | "/", 57 | {0, RelativePosition.FromEnd} 58 | ) 59 | ), 60 | SubfoldersList = List.Buffer( 61 | List.Select(Text.Split(NonRootFolders, "/"), each _ <> null and _ <> "") 62 | ), 63 | NavigateIn = List.Accumulate( 64 | SubfoldersList, 65 | StaticRoot, 66 | (state, current) => state{[Name = current]}[Content] 67 | ), 68 | #"Filtered Rows" = Table.SelectRows(NavigateIn, each ([Name] = FileName))[Content]{0} 69 | in 70 | #"Filtered Rows" 71 | in 72 | Source, 73 | documentation = [ 74 | Documentation.Name = " Sharepoint.GetFile ", 75 | Documentation.Description = " Convenient way to get SP file by entering full URL. ", 76 | Documentation.LongDescription 77 | = " Convenient way to get SP file by entering full URL. !! Root path to SP file has to be hardcoded in the function code itself !! ", 78 | Documentation.Category = " Accessing Data Functions ", 79 | Documentation.Source = " www.TheBIccountant.com, see: https://wp.me/p6lgsG-2kR . ", 80 | Documentation.Version = " 1.2: 30-Mar-2021-ImprovedSpeed ", 81 | Documentation.Author = " Imke Feldmann ", 82 | Documentation.Examples = {[Description = " ", Code = " ", Result = " "]} 83 | ] 84 | in 85 | Value.ReplaceType(func, Value.ReplaceMetadata(Value.Type(func), documentation)) 86 | in 87 | Source 88 | ``` 89 | -------------------------------------------------------------------------------- /GetDataFromSharePoint/fnGetFile.md: -------------------------------------------------------------------------------- 1 | # Get SharePoint File 2 | ## Credit to Imke Feldmann 3 | 4 | ```c# 5 | 6 | let 7 | Source = 8 | let 9 | func = // fnGetSharepointFile 10 | 11 | let 12 | Source = (FullPath as text) => 13 | let 14 | 15 | // Helper function 16 | fnUriUnescapeString = //Source: https://stackoverflow.com/questions/36242695/how-to-decodeuricomponent-ex-2f3f263d 17 | (data as text) as text => 18 | let 19 | ToList = List.Buffer(Text.ToList(data)), 20 | Accumulate = List.Accumulate( 21 | ToList, 22 | [Bytes = {}], 23 | (state, current) => 24 | let 25 | HexString = state[HexString]?, 26 | NextHexString = HexString & current, 27 | NextState = 28 | if HexString <> null then 29 | if Text.Length(NextHexString) = 2 then 30 | [ 31 | Bytes = state[Bytes] 32 | & Binary.ToList( 33 | Binary.FromText(NextHexString, BinaryEncoding.Hex) 34 | ) 35 | ] 36 | else 37 | [HexString = NextHexString, Bytes = state[Bytes]] 38 | else if current = "%" then 39 | [HexString = "", Bytes = state[Bytes]] 40 | else 41 | [Bytes = state[Bytes] & {Character.ToNumber(current)}] 42 | in 43 | NextState 44 | ), 45 | FromBinary = Text.FromBinary(Binary.FromList(Accumulate[Bytes])) 46 | in 47 | FromBinary, 48 | StaticRoot = SharePoint.Contents(RootPath, [ApiVersion = 15]), 49 | ExtractRoot = fnUriUnescapeString(Text.BeforeDelimiter(FullPath, "/", 4)), 50 | FileName = fnUriUnescapeString( 51 | Text.AfterDelimiter(FullPath, "/", {0, RelativePosition.FromEnd}) 52 | ), 53 | NonRootFolders = fnUriUnescapeString( 54 | Text.BeforeDelimiter( 55 | Text.AfterDelimiter(FullPath, ExtractRoot), 56 | "/", 57 | {0, RelativePosition.FromEnd} 58 | ) 59 | ), 60 | SubfoldersList = List.Buffer( 61 | List.Select(Text.Split(NonRootFolders, "/"), each _ <> null and _ <> "") 62 | ), 63 | NavigateIn = List.Accumulate( 64 | SubfoldersList, 65 | StaticRoot, 66 | (state, current) => state{[Name = current]}[Content] 67 | ), 68 | #"Filtered Rows" = Table.SelectRows(NavigateIn, each ([Name] = FileName))[Content]{0} 69 | in 70 | #"Filtered Rows" 71 | in 72 | Source, 73 | documentation = [ 74 | Documentation.Name = " Sharepoint.GetFile ", 75 | Documentation.Description = " Convenient way to get SP file by entering full URL. ", 76 | Documentation.LongDescription 77 | = " Convenient way to get SP file by entering full URL. !! Root path to SP file has to be hardcoded in the function code itself !! ", 78 | Documentation.Category = " Accessing Data Functions ", 79 | Documentation.Source = " www.TheBIccountant.com, see: https://wp.me/p6lgsG-2kR . ", 80 | Documentation.Version = " 1.2: 30-Mar-2021-ImprovedSpeed ", 81 | Documentation.Author = " Imke Feldmann ", 82 | Documentation.Examples = {[Description = " ", Code = " ", Result = " "]} 83 | ] 84 | in 85 | Value.ReplaceType(func, Value.ReplaceMetadata(Value.Type(func), documentation)) 86 | in 87 | Source 88 | 89 | ``` 90 | -------------------------------------------------------------------------------- /GetDataFromSharePoint/fnGetFolder.md: -------------------------------------------------------------------------------- 1 | # Get Folder from SharePoint 2 | ## Credit to Imke Feldmann 3 | 4 | ```ioke 5 | let 6 | Source = 7 | let 8 | func = // fnGetSharepointFile 9 | 10 | let 11 | Source = (FullPath as text) => 12 | let 13 | 14 | // Helper function 15 | fnUriUnescapeString = //Source: https://stackoverflow.com/questions/36242695/how-to-decodeuricomponent-ex-2f3f263d 16 | (data as text) as text => 17 | let 18 | ToList = List.Buffer(Text.ToList(data)), 19 | Accumulate = List.Accumulate( 20 | ToList, 21 | [Bytes = {}], 22 | (state, current) => 23 | let 24 | HexString = state[HexString]?, 25 | NextHexString = HexString & current, 26 | NextState = 27 | if HexString <> null then 28 | if Text.Length(NextHexString) = 2 then 29 | [ 30 | Bytes = state[Bytes] 31 | & Binary.ToList( 32 | Binary.FromText(NextHexString, BinaryEncoding.Hex) 33 | ) 34 | ] 35 | else 36 | [HexString = NextHexString, Bytes = state[Bytes]] 37 | else if current = "%" then 38 | [HexString = "", Bytes = state[Bytes]] 39 | else 40 | [Bytes = state[Bytes] & {Character.ToNumber(current)}] 41 | in 42 | NextState 43 | ), 44 | FromBinary = Text.FromBinary(Binary.FromList(Accumulate[Bytes])) 45 | in 46 | FromBinary, 47 | StaticRoot = SharePoint.Contents(RootPath, [ApiVersion = 15]), 48 | ExtractRoot = fnUriUnescapeString(Text.BeforeDelimiter(FullPath, "/", 4)), 49 | FileName = fnUriUnescapeString( 50 | Text.AfterDelimiter(FullPath, "/", {0, RelativePosition.FromEnd}) 51 | ), 52 | NonRootFolders = fnUriUnescapeString( 53 | Text.BeforeDelimiter( 54 | Text.AfterDelimiter(FullPath, ExtractRoot), 55 | "/", 56 | {0, RelativePosition.FromEnd} 57 | ) 58 | ), 59 | SubfoldersList = List.Buffer( 60 | List.Select(Text.Split(NonRootFolders, "/"), each _ <> null and _ <> "") 61 | ), 62 | NavigateIn = List.Accumulate( 63 | SubfoldersList, 64 | StaticRoot, 65 | (state, current) => state{[Name = current]}[Content] 66 | ), 67 | #"Filtered Rows" = Table.SelectRows(NavigateIn, each ([Name] = FileName))[Content]{0} 68 | in 69 | #"Filtered Rows" 70 | in 71 | Source, 72 | documentation = [ 73 | Documentation.Name = " Sharepoint.GetFile ", 74 | Documentation.Description = " Convenient way to get SP file by entering full URL. ", 75 | Documentation.LongDescription 76 | = " Convenient way to get SP file by entering full URL. !! Root path to SP file has to be hardcoded in the function code itself !! ", 77 | Documentation.Category = " Accessing Data Functions ", 78 | Documentation.Source = " www.TheBIccountant.com, see: https://wp.me/p6lgsG-2kR . ", 79 | Documentation.Version = " 1.2: 30-Mar-2021-ImprovedSpeed ", 80 | Documentation.Author = " Imke Feldmann ", 81 | Documentation.Examples = {[Description = " ", Code = " ", Result = " "]} 82 | ] 83 | in 84 | Value.ReplaceType(func, Value.ReplaceMetadata(Value.Type(func), documentation)) 85 | in 86 | Source 87 | 88 | ``` 89 | -------------------------------------------------------------------------------- /GoogleAnalytics/fnGoogleConnector.md: -------------------------------------------------------------------------------- 1 | # Google Analytics 2 | ### fnGoogleConnector 3 | get data from Google analytics, (un)comment out variables 4 | 5 | ```C# 6 | let 7 | fnGetGAData = ( //fnGetGAData: see code to check dimensions/measures 8 | 9 | AccountId as text, // Account GUID 10 | PropertyId as text, // Property GUID 11 | ViewId as text // View GUID 12 | ) => 13 | let 14 | Source = GoogleAnalytics.Accounts(), 15 | Account = Source{[Id=AccountId]}[Data], 16 | Property = Account{[Id=PropertyId]}[Data], 17 | View = Property{[Id=ViewId]}[Data], 18 | 19 | //** DIMENSIONS **// 20 | // Date Dimension 21 | vDate = {Cube.AddAndExpandDimensionColumn, "ga:date", {"ga:date"}, {"Date"}}, 22 | vUserType = {Cube.AddAndExpandDimensionColumn, "ga:userType", {"ga:userType"}, {"User Type"}}, 23 | vGender = {Cube.AddAndExpandDimensionColumn, "ga:userGender", {"ga:userGender"}, {"Gender"}}, 24 | vAge = {Cube.AddAndExpandDimensionColumn, "ga:userAgeBracket", {"ga:userAgeBracket"}, {"Age"}}, 25 | vSocialNetwork = {Cube.AddAndExpandDimensionColumn, "ga:socialNetwork", {"ga:socialNetwork"}, {"Social Network"}}, 26 | 27 | //** MEASURES **// 28 | // PageViews Measure 29 | vPageViews = {Cube.AddMeasureColumn, "Pageviews", "ga:pageviews"}, 30 | // NewUsers Measures 31 | vNewUsers = {Cube.AddMeasureColumn, "New Users", "ga:newUsers"}, 32 | // Hits Measures (Users) 33 | vUsers = {Cube.AddMeasureColumn, "Users", "ga:users"}, 34 | 35 | //** CREATE QUERY **// 36 | addDimensions = Cube.Transform(View, 37 | //You have to susbstitute this part with a your new query (dimensions, metrics) and create a new function for each query. Just create the query as a simple table and copy it here. 38 | { 39 | // vSocialNetwork, 40 | // vAge, 41 | // vGender, 42 | // vUserType, 43 | vDate, 44 | vPageViews, 45 | vUsers, 46 | vNewUsers 47 | 48 | }) 49 | in 50 | addDimensions 51 | in fnGetGAData 52 | ``` 53 | -------------------------------------------------------------------------------- /JSON/fnTableFromJSON.md: -------------------------------------------------------------------------------- 1 | ## Table.FromRecords for JSON file 2 | ```js 3 | (URL as text) => 4 | let 5 | MyJsonRecord = Json.Document(Web.Contents(URL)), 6 | MyJsonTable= Table.FromRecords( { MyJsonRecord } ) 7 | in 8 | MyJsonTable 9 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright (c) 2012-2021 Scott Chacon and others 2 | 3 | Permission is hereby granted, free of charge, to any person obtaining 4 | a copy of this software and associated documentation files (the 5 | "Software"), to deal in the Software without restriction, including 6 | without limitation the rights to use, copy, modify, merge, publish, 7 | distribute, sublicense, and/or sell copies of the Software, and to 8 | permit persons to whom the Software is furnished to do so, subject to 9 | the following conditions: 10 | 11 | The above copyright notice and this permission notice shall be 12 | included in all copies or substantial portions of the Software. 13 | 14 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, 15 | EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF 16 | MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND 17 | NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE 18 | LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION 19 | OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION 20 | WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. 21 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # M-Code Repository 2 | M-Code 3 | This repo contains custom (template) functions in the language M, which can be used in Power Query (for PowerBI and Excel) and/or Analysis Services. 4 | 5 | | Project | Description | 6 | | --- | --- | 7 | | [Calendar](https://github.com/PBIQueryous/M-Code/tree/main/Calendars) | M-code Standard and Financial Calendar | 8 | | [Functions](https://github.com/PBIQueryous/M-Code/tree/main/Functions) | M-code related transformations and functions | 9 | | [Templates](https://github.com/PBIQueryous/M-Code/tree/main/Functions/Templates) | M-code templates for functions including metadata | 10 | 11 | 12 | 13 | - [x] In Development 14 | - [ ] Deprecated 15 | -------------------------------------------------------------------------------- /SyntaxHighlight.md: -------------------------------------------------------------------------------- 1 | 2 | # ioke 3 | 4 | ```ioke 5 | 6 | = Table.AddColumn(Match_Substrings, "Custom.1", each 7 | let arg1 = List.ContainsAny( Text.Split( [Country] , " "), {"Russia", "Mexico"} ), // exact match 8 | arg2 = List.ContainsAny( Text.Split( [Country] , " "), {"Canada", "Germany"} ), // exact match 9 | arg3 = List.AnyTrue( { [Country] = "United Kingdom" , [Country] = "United States of America" }), // exact match 10 | arg4 = List.ContainsAny( {[Country]}, {"France", "Country of the World"}), 11 | arg5 = List.AnyTrue( List.Transform( {"United States of America", " World", "anc"}, 12 | (substring)=> Text.Contains([Country], 13 | substring, Comparer.OrdinalIgnoreCase)) ), 14 | arg7 = List.AnyTrue( List.Transform( {" World", "anc"}, 15 | (substring)=> Text.Contains(([Country]), 16 | substring, Comparer.OrdinalIgnoreCase))), 17 | 18 | calc1 = if arg7 then 1 else if arg2 then 2 else if arg3 then 3 else /* if arg4 then 4 else */if arg5 then 5 else "9" 19 | in calc1 20 | ) 21 | ``` 22 | 23 | # ocaml 24 | 25 | ```ocaml 26 | 27 | = Table.AddColumn(Match_Substrings, "Custom.1", each 28 | let arg1 = List.ContainsAny( Text.Split( [Country] , " "), {"Russia", "Mexico"} ), // exact match 29 | arg2 = List.ContainsAny( Text.Split( [Country] , " "), {"Canada", "Germany"} ), // exact match 30 | arg3 = List.AnyTrue( { [Country] = "United Kingdom" , [Country] = "United States of America" }), // exact match 31 | arg4 = List.ContainsAny( {[Country]}, {"France", "Country of the World"}), 32 | arg5 = List.AnyTrue( List.Transform( {"United States of America", " World", "anc"}, 33 | (substring)=> Text.Contains([Country], 34 | substring, Comparer.OrdinalIgnoreCase)) ), 35 | arg7 = List.AnyTrue( List.Transform( {" World", "anc"}, 36 | (substring)=> Text.Contains(([Country]), 37 | substring, Comparer.OrdinalIgnoreCase))), 38 | 39 | calc1 = if arg7 then 1 else if arg2 then 2 else if arg3 then 3 else /* if arg4 then 4 else */if arg5 then 5 else "9" 40 | in calc1 41 | ) 42 | ``` 43 | # Jade 44 | 45 | ```jade 46 | 47 | = Table.AddColumn(Match_Substrings, "Custom.1", each 48 | let arg1 = List.ContainsAny( Text.Split( [Country] , " "), {"Russia", "Mexico"} ), // exact match 49 | arg2 = List.ContainsAny( Text.Split( [Country] , " "), {"Canada", "Germany"} ), // exact match 50 | arg3 = List.AnyTrue( { [Country] = "United Kingdom" , [Country] = "United States of America" }), // exact match 51 | arg4 = List.ContainsAny( {[Country]}, {"France", "Country of the World"}), 52 | arg5 = List.AnyTrue( List.Transform( {"United States of America", " World", "anc"}, 53 | (substring)=> Text.Contains([Country], 54 | substring, Comparer.OrdinalIgnoreCase)) ), 55 | arg7 = List.AnyTrue( List.Transform( {" World", "anc"}, 56 | (substring)=> Text.Contains(([Country]), 57 | substring, Comparer.OrdinalIgnoreCase))), 58 | 59 | calc1 = if arg7 then 1 else if arg2 then 2 else if arg3 then 3 else /* if arg4 then 4 else */if arg5 then 5 else "9" 60 | in calc1 61 | ) 62 | ``` 63 | 64 | 65 | 66 | # vim 67 | 68 | ```vim 69 | 70 | = Table.AddColumn(Match_Substrings, "Custom.1", each 71 | let arg1 = List.ContainsAny( Text.Split( [Country] , " "), {"Russia", "Mexico"} ), // exact match 72 | arg2 = List.ContainsAny( Text.Split( [Country] , " "), {"Canada", "Germany"} ), // exact match 73 | arg3 = List.AnyTrue( { [Country] = "United Kingdom" , [Country] = "United States of America" }), // exact match 74 | arg4 = List.ContainsAny( {[Country]}, {"France", "Country of the World"}), 75 | arg5 = List.AnyTrue( List.Transform( {"United States of America", " World", "anc"}, 76 | (substring)=> Text.Contains([Country], 77 | substring, Comparer.OrdinalIgnoreCase)) ), 78 | arg7 = List.AnyTrue( List.Transform( {" World", "anc"}, 79 | (substring)=> Text.Contains(([Country]), 80 | substring, Comparer.OrdinalIgnoreCase))), 81 | 82 | calc1 = if arg7 then 1 else if arg2 then 2 else if arg3 then 3 else /* if arg4 then 4 else */if arg5 then 5 else "9" 83 | in calc1 84 | ) 85 | ``` 86 | 87 | -------------------------------------------------------------------------------- /Templates/M-code Function Template.md: -------------------------------------------------------------------------------- 1 | # fnName 2 | ### PowerQuery function 3 | ##### description 4 | 5 | ```C# 6 | let 7 | fn = // fnName 8 | /* ------------------------------ 9 | Author: Imran Haq - PBI QUERYOUS 10 | GitHub: https://github.com/PBIQueryous/M-Code/ 11 | Description: 12 | Credits: 13 | Link: 14 | Site: 15 | ---------------------------------*/ 16 | 17 | // invoke function & define parameter inputs 18 | let 19 | invokeFn = (exampleInput) => 20 | 21 | // ------------------------------------------------------------------ 22 | // function transformations 23 | let 24 | ReplacedText = Text.Replace(exampleInput, " ", " "), 25 | Result = 26 | if not (Text.Contains(ReplacedText, " ")) then 27 | ReplacedText 28 | else 29 | @invokeFn(ReplacedText) 30 | in 31 | Text.Trim(Result), 32 | 33 | // ------------------------------------------------------------------ 34 | // change parameter metadata here 35 | fnType = type function ( 36 | exampleInput as ( 37 | type text 38 | meta 39 | [ 40 | Documentation.FieldCaption = " Select Column: #(lf) Trim Text in Column ", 41 | Documentation.FieldDescription = " Select Column to Trim #(lf) eg: Column1 ", 42 | Documentation.SampleValues = {"Column1"} 43 | // or Documentation.AllowedValues = {"Text1", "Text2", "Etc"} for multiple values in dropdown 44 | // Formatting.IsMultiLine = true, for text box with multiple-code lines (eg: for native queries) 45 | // Formatting.IsCode = true, formats text into coding style 46 | ] 47 | ) 48 | ) as list, 49 | // ------------------------------------------------------------------ 50 | // edit function metadata here 51 | documentation = 52 | [ 53 | 54 | Documentation.Name = " fnName ", 55 | Documentation.Description = " ExampleDescription ", 56 | Documentation.LongDescription = " ExampleDescription ", 57 | Documentation.Category = " Trim (columns) ", 58 | Documentation.Source = " PBIQUERYOUS ", 59 | Documentation.Version = " 1.0 ", 60 | Documentation.Author = " Imran Haq ", 61 | Documentation.Examples = 62 | { 63 | [ 64 | Description = " ExampleDescription ", 65 | Code = " ExampleInput ", 66 | Result = " ExampleOutput 67 | #(lf) 68 | #(lf) 69 | " 70 | ] 71 | } 72 | 73 | ] 74 | , 75 | 76 | // ------------------------------------------------------------------ 77 | // Choose between Parameter Documentation or Function Documentation 78 | funtionDocumentation = // -- function metadata 79 | Value.ReplaceType(invokeFn, Value.ReplaceMetadata(Value.Type(invokeFn), documentation)), 80 | 81 | parameterDocumentation = // -- parameter metadata 82 | Value.ReplaceType(invokeFn, fnType) 83 | in 84 | // ------------------------------------------------------------------ 85 | // select one of the above steps and paste below 86 | funtionDocumentation /* <-- Choose final documentation type */ 87 | in 88 | fn 89 | ``` 90 | -------------------------------------------------------------------------------- /Templates/M-functionTemplate.md: -------------------------------------------------------------------------------- 1 | # M-code Template without annotation 2 | 3 | ```C# 4 | let 5 | // --- Function segment --- 6 | // Author: Imran Haq (PBI Queryous) 7 | output = //fnFunctionName 8 | (input as list) as table => 9 | let 10 | step1 = "PowerQueryFunctionsHere" 11 | in 12 | step1 13 | , 14 | // --- Documentation segment --- 15 | documentation = [ 16 | Documentation.Name = " fnGetUniques ", 17 | Documentation.Description = " Extract column of unique values ", 18 | Documentation.LongDescription 19 | = " Select Table, Select Column and Invoke. Extracts a column of unique values ", 20 | Documentation.Category = " Data Extraction ", 21 | Documentation.Source = " https://github.com/PBIQueryous - PBI Queryous - Stay Queryous ", 22 | Documentation.Version = " 1.0 (21/04/2022) ", 23 | Documentation.Author = " Imran Haq (Newcastle upon Tyne) ", 24 | Documentation.Examples = {[Description = " ", Code = " ", Result = " "]} 25 | ] 26 | // --- Output --- 27 | in 28 | Value.ReplaceType( 29 | output, 30 | Value.ReplaceMetadata( 31 | Value.Type(output), 32 | documentation 33 | ) 34 | ) 35 | ``` 36 | -------------------------------------------------------------------------------- /Templates/M-template.md: -------------------------------------------------------------------------------- 1 | # M-code Template 2 | 3 | ```C# 4 | /*--------------------------------- 5 | | Title: | 6 | | Power Query - M-code template | 7 | ---------------------------------- 8 | | AboutMe: | 9 | | Imran Haq, PBI Queryous | 10 | | https://github.com/PBIQueryous | 11 | | STAY QUERYOUS! | 12 | ---------------------------------*/ 13 | 14 | /* AUTHOR AND CREDITS 15 | *--------------------------------------------------* 16 | | Author and Credits: | 17 | | Štěpán Rešl | github.com/tirnovar | 18 | *--------------------------------------------------* 19 | */ 20 | 21 | /* DESCRIPTION 22 | * ----------------------------------- 23 | * M-code function template, with section for documentation 24 | * ----------------------------------- 25 | */ 26 | 27 | // --------------------------- Function ------------------------------ 28 | let 29 | // --------------------------- Function segment ----------------------------------- 30 | output = 31 | (/* parameter as text, optional opt_parameter as text */) /* as text */ => // Input definition + Function output type definition 32 | let // Inner function steps declaration 33 | initStep = "", 34 | lastStep = "" 35 | in 36 | lastStep, // Output from inner steps 37 | // --------------------------- Documentation segment ------------------------------ 38 | documentation = [ 39 | Documentation.Name = " NAME OF FUNCTION ", // Name of the function 40 | Documentation.Description = " DESCRIPTION ", // Decription of the function 41 | Documentation.Source = " URL / SOURCE DESCRIPTION ", // Source of the function 42 | Documentation.Version = " VERSION ", // Version of the function 43 | Documentation.Author = " AUTHOR ", // Author of the function 44 | Documentation.Examples = // Examples of the functions 45 | { 46 | [ 47 | Description = " EXAMPLE DESCRIPTION ", // Description of the example 48 | Code = " EXAMPLE CODE ", // Code of the example 49 | Result = " EXAMPLE RESULT " // Result of the example 50 | ] 51 | } 52 | ] 53 | // --------------------------- Output -------------------------------------------- 54 | in 55 | Value.ReplaceType( // Replace type of the value 56 | output, // Function caller 57 | Value.ReplaceMetadata( // Replace metadata of the function 58 | Value.Type(output), // Return output type of function 59 | documentation // Documentation assigment 60 | ) 61 | ) 62 | // ------------------------------------------------------------------------------------ 63 | -------------------------------------------------------------------------------- /UnzipContents/fnUnzipContents.md: -------------------------------------------------------------------------------- 1 | 2 | ## function code 3 | ```js 4 | (ZIPFile) => 5 | let 6 | Header = BinaryFormat.Record([ 7 | MiscHeader = BinaryFormat.Binary(14), 8 | BinarySize = BinaryFormat.ByteOrder(BinaryFormat.UnsignedInteger32, ByteOrder.LittleEndian), 9 | FileSize = BinaryFormat.ByteOrder(BinaryFormat.UnsignedInteger32, ByteOrder.LittleEndian), 10 | FileNameLen= BinaryFormat.ByteOrder(BinaryFormat.UnsignedInteger16, ByteOrder.LittleEndian), 11 | ExtrasLen = BinaryFormat.ByteOrder(BinaryFormat.UnsignedInteger16, ByteOrder.LittleEndian) 12 | ]), 13 | 14 | HeaderChoice = BinaryFormat.Choice( 15 | BinaryFormat.ByteOrder(BinaryFormat.UnsignedInteger32, ByteOrder.LittleEndian), 16 | each if _ <> 67324752 // not the IsValid number? then return a dummy formatter 17 | then BinaryFormat.Record([IsValid = false, Filename=null, Content=null]) 18 | else BinaryFormat.Choice( 19 | BinaryFormat.Binary(26), // Header payload - 14+4+4+2+2 20 | each BinaryFormat.Record([ 21 | IsValid = true, 22 | Filename = BinaryFormat.Text(Header(_)[FileNameLen]), 23 | Extras = BinaryFormat.Text(Header(_)[ExtrasLen]), 24 | Content = BinaryFormat.Transform( 25 | BinaryFormat.Binary(Header(_)[BinarySize]), 26 | (x) => try Binary.Buffer(Binary.Decompress(x, Compression.Deflate)) otherwise null 27 | ) 28 | ]), 29 | type binary // enable streaming 30 | ) 31 | ), 32 | 33 | ZipFormat = BinaryFormat.List(HeaderChoice, each _[IsValid] = true), 34 | 35 | Entries = List.Transform( 36 | List.RemoveLastN( ZipFormat(ZIPFile), 1), 37 | (e) => [FileName = e[Filename], Content = e[Content] ] 38 | ) 39 | in 40 | Table.FromRecords(Entries) 41 | ``` 42 | 43 | ## invoke function 44 | ```js 45 | let 46 | Source = File.Contents("[Full path to your zip file]"), 47 | Files = UnzipContents(Source) 48 | in 49 | Files 50 | ``` 51 | -------------------------------------------------------------------------------- /recordvalueListExample.md: -------------------------------------------------------------------------------- 1 | # Records, Values, Lists 2 | 3 | 4 | ```c# 5 | //GetCodeFromGithub 6 | let 7 | Source = //Record.ToTable ( 8 | 9 | [ NewNested = 10 | 11 | [ 12 | Nested = 13 | [ 14 | Record1 = "Text", 15 | Record2 = {1 .. 10} 16 | ] 17 | ], 18 | SubNested2 = 19 | [ 20 | Nested = 21 | [ 22 | Record1 = "Text", 23 | Record2 = {1 .. 10} 24 | ] 25 | ] 26 | ], 27 | #"Converted to Table1" = Record.ToTable(Source), 28 | #"Expanded Value1" = Table.ExpandRecordColumn(#"Converted to Table1", "Value", {"Nested"}, {"Nested"}), 29 | #"Expanded Nested" = Table.ExpandRecordColumn(#"Expanded Value1", "Nested", {"Record1", "Record2"}, {"Record1", "Record2"}), 30 | #"Expanded Record2" = Table.ExpandListColumn(#"Expanded Nested", "Record2") 31 | in 32 | #"Expanded Record2" 33 | ``` 34 | -------------------------------------------------------------------------------- /zInProgressDump/Dump.md: -------------------------------------------------------------------------------- 1 | ```cs 2 | 3 | // Dynamic Rename Headers 4 | = Table.RenameColumns(PromotedHeaders, Headers, MissingField.Ignore) 5 | // where headers are a flat (transposed lists) table 6 | Table.ToColumns(Source) //-- source is 2 rows of headers, OLD{0}; NEW{1} 7 | 8 | // Filter by Max number 9 | Table.SelectRows(EXPANDinvokedColumn, let latest = List.Max(EXPANDinvokedColumn[FileDate]) in each [FileDate] = latest) 10 | 11 | // Get date integer from date 12 | AddDateInt = Table.AddColumn( 13 | AddMonthEnd, 14 | "DateInt", 15 | each [Year] * 10000 + [MonthOfYear] * 100 + [DayOfMonth], 16 | type number 17 | ) 18 | 19 | // Function Code 20 | = (QueryStart as table) => 21 | 22 | // Remove Top Rows upt Specified Rows 23 | = Table.Skip(PrevSTEP, each[Column1] <> "TEXT") 24 | 25 | // Remove Bottom Rows upto Specified Rows 26 | = Table.RemoveLastN(Custom1, each[Column1] <> "TEXT") 27 | 28 | // Remove First Rows upto Specified Rows 29 | = Table.RemoveFirstN(Prep,each [Column1] <> "TEXT") 30 | 31 | // Replace Values where the Text Starts with Specific Characters 32 | = Table.ReplaceValue(PrevSTEP,each [Column1],each if Text.StartsWith([Column1], ";0") then "" else null,Replacer.ReplaceText,{"Column1"}) 33 | 34 | // Remove rows until first null 35 | = Table.FirstN(PrevSTEP,each [Column1] <> null) 36 | 37 | // Remove nulls until first value 38 | = Table.RemoveFirstN(PrevSTEP,each [Column1] = null) 39 | 40 | // Keep Rows until Desired Text Found in Column 41 | = Table.FirstN(PrevSTEP,each [Column1] <> "TEXT") 42 | 43 | // Table Schema 44 | Table.Schema 45 | 46 | // Count Splits 47 | = Table.AddColumn(#"Removed Columns2", "Count Item", each List.Count(Text.Split([Custom],";"))) 48 | = Table.AddColumn(LISTcount, "Custom.1", each List.NonNullCount(Text.Split([Custom], ";" ))) 49 | 50 | 51 | // Get Previous Rows 52 | = Table.AddColumn(IDnext, "IDprevPos", each 53 | try 54 | // PrevStep[columnName]{0} 55 | prevStep[columnName]{[indexColumn]-1} 56 | otherwise null) 57 | 58 | // Get Next Rows 59 | = Table.AddColumn(IDpos, "IDnextPos", each 60 | try 61 | prevStep[columnName]{[indexColumn]+1} 62 | otherwise null) 63 | 64 | // Days Laps Examples 65 | Table.AddColumn(ADDindex1, "Stage Days Lapsed", each try 66 | if [Stage] = "Date S/L Complete" then [Days Lapsed] else [Days Lapsed] - ADDindex1[Days Lapsed]{[Index0]-1} 67 | otherwise null, Int64.Type) 68 | 69 | // Get Headers 70 | GetHEADERS = Table.ColumnNames(Table.Combine(QUERYSTART[fnCustom])) 71 | // List Headers 72 | HEADERSTOUNPIVOT = {"Name", "SortID", "ProjID", "ProjName", "Fiscal Period", "Item", "EXPENDITURE", "PaymentType"} 73 | // Expand Headers 74 | ExpandCustomFunction = Table.ExpandTableColumn(QUERYSTART, "fnCustom", GetHEADERS) 75 | 76 | // Function to Trim Leadings Spaces and/or Characters 77 | let 78 | Source = let 79 | func = // fnPowerRemoveSpaces 80 | 81 | let 82 | Source = (Text as text, optional SpecialCharacter as text) => 83 | let 84 | char = if SpecialCharacter = null then " " else SpecialCharacter, 85 | split = Text.Split(Text, char), 86 | removeblanks = List.Select(split, each _ <> ""), 87 | removespaces = Replacer.ReplaceText(Text.Combine(removeblanks, char), " ", "") 88 | 89 | in 90 | removespaces 91 | in 92 | Source, 93 | documentation = [ 94 | Documentation.Name = " Function.PowerRemoveSpaces ", 95 | Documentation.Description = " Trims Excess Spaces. ", 96 | Documentation.LongDescription 97 | = " Add Column, Invoke Custom Function, Choose Column to RemoveSpaces. ", 98 | Documentation.Category = " Trim Function ", 99 | Documentation.Source = " TVCA PowerBI Team ", 100 | Documentation.Version = " 02 / 09 / 2022 ", 101 | Documentation.Author = " Imran Haq ", 102 | Documentation.Examples = {[Description = " Neat function to remove excess spaces ", Code = " Removes All Spaces ", Result = " RemovesAllSpaces "]} 103 | ] 104 | in 105 | Value.ReplaceType(func, Value.ReplaceMetadata(Value.Type(func), documentation)) 106 | in 107 | Source 108 | 109 | Rename2022Allocation = Table.RenameColumns(FilterRows3,{{"2022/23;Variance", "2022/23ProjectAllocation"}}) 110 | 111 | 112 | // Remove null columns 113 | (Source as table) as table => 114 | 115 | let 116 | RemoveEmptyColumns = Table.SelectColumns( 117 | Source, 118 | List.Select( 119 | Table.ColumnNames(Source), 120 | each List.NonNullCount(Table.Column(Source,_)) <> 0 121 | ) 122 | ) 123 | in 124 | RemoveEmptyColumns 125 | 126 | // Remove null columns Custom Step 127 | = Table.SelectColumns(Source, 128 | List.Select(Table.ColumnNames(Source), 129 | each List.NonNullCount(Table.Column(Source,_)) <> 0)) 130 | ``` 131 | --------------------------------------------------------------------------------