Forum Discussion
Power Query - removing identical generic text from the start and end of multiple columns
- Nov 08, 2024
Hi Insert_Key
Thanks for sharing all what you shared and TBH I wouldn't have bet on GenAI regarding data types. What they came up with is very similar to what I've seen so far and what I referred to in my previous reply. Though, AI got it wrong when it comes to numbers vs. whole numbers... In the workbook you shared - just for testing purpose - enter a decimal number in column [Parent id] then refresh the query... 😒
In attached v1.2 I fixed it as follow:
DetectDataType = (column as list) as type => if List.IsEmpty(column) then type nullable text // Default to text if empty else let sampleValue = List.First(List.RemoveNulls(column)), // Get the first non-null value valueType = Value.Type(sampleValue) in if valueType = type text then type nullable text else if valueType = type number and (sampleValue = Number.Round(sampleValue)) then type nullable Int64.Type // Check for whole numbers else if valueType = type number then type nullable number // Decimal numbers else if valueType = type logical then type nullable logical else if valueType = type date or valueType = type datetime then type nullable datetime // Handle Date/Time else type nullable text, // Fallback to textand IMHO the last else should be type nullable any and not text but that doesn't matter in your context as any will end as text once the query loads to the Data Model
A comment, just in case... I see you added a Sort step at the end of your query. I guess that's for checks on the query output within Excel. Otherwise, as far as I know, the Data Model doesn't mind about ordered data
Last thing. Now that I understand your solution has no external connection, you can slightly speed up the time to refresh your query by disabling the PQ Firewall. Excel data (tab) > Get Data > Query Options... > CURRENT WORKBOOK > Privacy > Choose Ignore the Privacy Levels...
Hope this helps and makes sense
You wrote that all column merges are completed and you are now left with removing "Custom field (" and the right-most ")", without explicitly referencing column names.
Would that not work by inserting the following steps to your existing query?
Unpivot = Table.UnpivotOtherColumns(#"Created merged ""Country of Origin"" Column", {"ID", "Description", "Labels"}, "Attribute", "Value"),
Split = Table.SplitColumn(Unpivot, "Attribute", Splitter.SplitTextByEachDelimiter({")"}, QuoteStyle.Csv, true), {"Attribute", "Attribute.1"}),
Replace = Table.ReplaceValue(Split,"Custom field (","",Replacer.ReplaceText,{"Attribute"}),
Remove = Table.RemoveColumns(Replace,{"Attribute.1"}),
Pivot = Table.Pivot(Remove, List.Distinct(Remove[Attribute]), "Attribute", "Value")
in
Pivot
The end result will look like this:
Please ignore is I've misunderstood.
- Insert_KeyNov 04, 2024Brass Contributor
Riny_van_Eekelen - thank you for your help!
You definitely haven't misunderstood; the outcome is precisely what I am looking for. Unfortunately, the sample data I provided is massively simplified compared to the real file, which, I believe contains something in the order of 35 to 40 initial columns, 10 to 15 of which would need to be addressed by this renaming process.
Your solution works flawlessly, but I feel using a "search and replace" within the header text would be a better fit for me. I work with Jira exports quite a lot and they are often peppered with these "Custom field" header names. With this simple example, only three columns ("ID", "Description", "Labels") needed to be excluded from the unpivot, but for me to implement it in other exports I'd have to specify many more than that - maybe 15 to 20 - and to customise the majority of those for each export. None of this additional context was explained in my post or sample, apologies; I was trying to present the bare requirements with minimal information.
I might be wrong in my thinking, but the "search and replace" approach feels more flexible without needing to significantly adjust the code each time. Thanks again 🙂