form from/to areas of single lines works very slow

pinarello

New Member
Joined
Jun 1, 2019
Messages
42
Hello,


actually I just wanted to find out how to create intervals from a list of single values with Power Query.


For example, a sales representative can easily see which postal code areas he is responsible for.


As an exercise object I found a list containing the postal codes of counties and cities in Germany. In this case, it is not important whether the list is complete, since it is only an exercise.


In the first version I am I am in such a way vorgegengen, as I would have realized it also with Excel formulas. I also came to a useful result, but with catastrophic response times.


I suspected that this could be due to the fact that I use both backward and forward indexing in the query and also address several fields using indexing.


So I changed the query so that now only a backward indexing is necessary and to avoid the multiple use, I concatenated the relevant fields. I also deleted all necessary auxiliary columns as fast as possible.


But no matter what I do, the query always calculates forever. In the total list it's about forming the intervals from about 8200 lines, but even if I only run the query for 105 lines and 19 from7to ranges are formed, it takes about 12 seconds on my PC. My company laptop even needs about 20 seconds.


Maybe someone has an idea what could be the cause and how the problem of the long runtime can be solved.


See here the code and examples of input

let
Source = Excel.CurrentWorkbook(){[Name="Tabelle3"]}[Content],
Userdefined_Col = Table.AddColumn(Quelle, "County/City - Type", each [#"County / City"] & "@" & [Type]),
Removed_col = Table.RemoveColumns(Userdefined_Col,{"County / City", "Type"}),
sorted_lines = Table.Sort(Removed_col,{{"zip", Order.Ascending}, {"County/City - Type", Order.Ascending}}),
Index_Col = Table.AddIndexColumn(sorted_lines, "Index", 0, 1),
userdefined_col = Table.AddColumn(Index_Col, "from", each if [Index] = 0
or [#"County/City - Type"] <> Index_Col[#"County/City - Type"]{[Index]-1}
then [zip]
else null),
fill_down = Table.FillDown(userdefined_col,{"from"}),
Removed_col2 = Table.RemoveColumns(fill_down,{"Index"}),
sorted_lines2 = Table.Sort(Removed_col2,{{"zip", Order.Descending}, {"County/City - Type", Order.Descending}}),
Index_Col2 = Table.AddIndexColumn(sorted_lines2, "Index", 0, 1),
Userdefined_col2 = Table.AddColumn(Index_Col2, "to", each if [Index] = 0
or Index_Col2[#"from"]{[Index]-1} <> [#"from"]
then [zip]
else null),
filtered_lines = Table.SelectRows(Userdefined_col2, each ([#"to"] <> null)),
Removed_col3 = Table.RemoveColumns(filtered_lines,{"Index", "zip"}),
Changed_type = Table.TransformColumnTypes(Removed_col3,{{"from", type text}, {"to", type text}}),
Userdefined_col3 = Table.AddColumn(Changed_type,
"from_2", each "0" & [#"from"]),
Userdefined_col4 = Table.AddColumn(Userdefined_col3, "to_2", each "0" & [#"to"]),
Changed_type2 = Table.TransformColumnTypes(Userdefined_col4,{{"from_2", type text}, {"to_2", type text}}),
Split_col_by_pos = Table.SplitColumn(Changed_type2, "from_2", Splitter.SplitTextByPositions({0, 5}, true), {"del_1", "zip-from"}),
Split_col_by_pos2 = Table.SplitColumn(Split_col_by_pos, "to_2", Splitter.SplitTextByPositions({0, 5}, true), {"del_2", "zip-to"}),
Removed_col4 = Table.RemoveColumns(Split_col_by_pos2,{"from", "to", "del_1", "del_2"}),
Split_col_by_sign = Table.SplitColumn(Removed_col4, "County/City - Type", Splitter.SplitTextByDelimiter("@", QuoteStyle.Csv), {"County/City", "Type"}),
sorted_lines3 = Table.Sort(Split_col_by_sign,{{"Federal state", Order.Ascending}, {"County/City", Order.Ascending}, {"Type", Order.Ascending}, {"zip-from", Order.Ascending}})
in
sorted_lines3


zipFederal stateCounty / CityType
4880SachsenNordsachsenCounty
4886SachsenNordsachsenCounty
4889SachsenNordsachsenCounty
4895BrandenburgElbe-ElsterCounty
4910BrandenburgElbe-ElsterCounty
4916BrandenburgElbe-ElsterCounty
4924BrandenburgElbe-ElsterCounty
4928BrandenburgElbe-ElsterCounty
4931BrandenburgElbe-ElsterCounty
4932BrandenburgElbe-ElsterCounty
4934BrandenburgElbe-ElsterCounty
4936BrandenburgElbe-ElsterCounty
4938BrandenburgElbe-ElsterCounty
6108Sachsen-AnhaltHalle SaaleTown
6110Sachsen-AnhaltHalle SaaleTown
6112Sachsen-AnhaltHalle SaaleTown
6114Sachsen-AnhaltHalle SaaleTown
6116Sachsen-AnhaltHalle SaaleTown
6118Sachsen-AnhaltHalle SaaleTown
6120Sachsen-AnhaltHalle SaaleTown
6122Sachsen-AnhaltHalle SaaleTown
6124Sachsen-AnhaltHalle SaaleTown
6126Sachsen-AnhaltHalle SaaleTown
6128Sachsen-AnhaltHalle SaaleTown
6130Sachsen-AnhaltHalle SaaleTown
6132Sachsen-AnhaltHalle SaaleTown
6179Sachsen-AnhaltSaalekreisCounty
6184Sachsen-AnhaltSaalekreisCounty
6188Sachsen-AnhaltSaalekreisCounty
6193Sachsen-AnhaltSaalekreisCounty
6198Sachsen-AnhaltSaalekreisCounty
6217Sachsen-AnhaltSaalekreisCounty
6231Sachsen-AnhaltSaalekreisCounty
6237Sachsen-AnhaltSaalekreisCounty
6242Sachsen-AnhaltSaalekreisCounty
6246Sachsen-AnhaltSaalekreisCounty
6249Sachsen-AnhaltSaalekreisCounty
6255Sachsen-AnhaltSaalekreisCounty
6258Sachsen-AnhaltSaalekreisCounty
6259Sachsen-AnhaltSaalekreisCounty
6268Sachsen-AnhaltSaalekreisCounty
6279Sachsen-AnhaltSaalekreisCounty
6295Sachsen-AnhaltMansfeld-SüdharzCounty
6308Sachsen-AnhaltMansfeld-SüdharzCounty
6311Sachsen-AnhaltMansfeld-SüdharzCounty
6313Sachsen-AnhaltMansfeld-SüdharzCounty
6317Sachsen-AnhaltMansfeld-SüdharzCounty
6333Sachsen-AnhaltMansfeld-SüdharzCounty
6343Sachsen-AnhaltMansfeld-SüdharzCounty
6347Sachsen-AnhaltMansfeld-SüdharzCounty
6366Sachsen-AnhaltAnhalt-BitterfeldCounty
6369Sachsen-AnhaltAnhalt-BitterfeldCounty
6385Sachsen-AnhaltAnhalt-BitterfeldCounty
6386Sachsen-AnhaltAnhalt-BitterfeldCounty
6388Sachsen-AnhaltAnhalt-BitterfeldCounty
6406Sachsen-AnhaltSalzlandkreisCounty
6408Sachsen-AnhaltSalzlandkreisCounty
6420Sachsen-AnhaltSaalekreisCounty
6425Sachsen-AnhaltSalzlandkreisCounty
6429Sachsen-AnhaltSalzlandkreisCounty
6449Sachsen-AnhaltSalzlandkreisCounty
6456Sachsen-AnhaltMansfeld-SüdharzCounty
6458Sachsen-AnhaltHarzCounty
6463Sachsen-AnhaltHarzCounty
6464Sachsen-AnhaltMansfeld-SüdharzCounty
6466Sachsen-AnhaltMansfeld-SüdharzCounty
6467Sachsen-AnhaltMansfeld-SüdharzCounty
6469Sachsen-AnhaltMansfeld-SüdharzCounty
6484Sachsen-AnhaltHarzCounty
6485Sachsen-AnhaltHarzCounty
6493Sachsen-AnhaltHarzCounty
6502Sachsen-AnhaltHarzCounty
6526Sachsen-AnhaltMansfeld-SüdharzCounty
6528Sachsen-AnhaltMansfeld-SüdharzCounty
6536Sachsen-AnhaltMansfeld-SüdharzCounty
6537Sachsen-AnhaltMansfeld-SüdharzCounty
6542Sachsen-AnhaltMansfeld-SüdharzCounty
6543Sachsen-AnhaltMansfeld-SüdharzCounty
6556ThüringenKyffhäuserkreisCounty
6567ThüringenKyffhäuserkreisCounty
6571ThüringenKyffhäuserkreisCounty
6577ThüringenKyffhäuserkreisCounty
6578ThüringenKyffhäuserkreisCounty
6618Sachsen-AnhaltBurgenlandkreisCounty
6628Sachsen-AnhaltBurgenlandkreisCounty
6632Sachsen-AnhaltBurgenlandkreisCounty
6636Sachsen-AnhaltBurgenlandkreisCounty
6638Sachsen-AnhaltBurgenlandkreisCounty
6642Sachsen-AnhaltBurgenlandkreisCounty
6647Sachsen-AnhaltBurgenlandkreisCounty
6648Sachsen-AnhaltBurgenlandkreisCounty
6667Sachsen-AnhaltBurgenlandkreisCounty
6679Sachsen-AnhaltBurgenlandkreisCounty
6682Sachsen-AnhaltBurgenlandkreisCounty
6686Sachsen-AnhaltBurgenlandkreisCounty
6688Sachsen-AnhaltBurgenlandkreisCounty
6711Sachsen-AnhaltBurgenlandkreisCounty
6712Sachsen-AnhaltBurgenlandkreisCounty
6721Sachsen-AnhaltBurgenlandkreisCounty
6722Sachsen-AnhaltBurgenlandkreisCounty
6729Sachsen-AnhaltBurgenlandkreisCounty
6749Sachsen-AnhaltAnhalt-BitterfeldCounty
6766Sachsen-AnhaltAnhalt-BitterfeldCounty
6772Sachsen-AnhaltWittenbergCounty
6773Sachsen-AnhaltAnhalt-BitterfeldCounty

<colgroup><col><col><col><col></colgroup><tbody>
</tbody>





<colgroup><col></colgroup><tbody>
</tbody>






Translated from German to English with www.DeepL.com
 

Excel Facts

How can you turn a range sideways?
Copy the range. Select a blank cell. Right-click, Paste Special, then choose Transpose.
My Code:

Code:
let
   Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Sorted Rows" = Table.Sort(Source,{{"zip", Order.Ascending}}),
    #"Added Index" = Table.AddIndexColumn(#"Sorted Rows", "Index", 0, 1),
    #"Grouped Rows" = Table.Group(#"Added Index", {"County/City"}, {{"CountCC", each _, type table [zip=number, Federal state=text, #"County/City"=text, Type=text, Index=number]}}),
    #"Added Index1" = Table.AddIndexColumn(#"Grouped Rows", "Index", 0, 1),
    #"Expanded CountCC" = Table.ExpandTableColumn(#"Added Index1", "CountCC", {"zip", "Federal state", "County/City", "Type", "Index"}, {"zip", "Federal state", "County/City.1", "Type", "Index.1"}),
    #"Removed Columns" = Table.RemoveColumns(#"Expanded CountCC",{"County/City.1"}),
    Reord_Col = Table.ReorderColumns(#"Removed Columns",{"zip", "Federal state", "County/City", "Type", "Index.1", "Index"}),
    #"Sorted Rows1" = Table.Sort(Reord_Col,{{"zip", Order.Ascending}}),
    Add_From = Table.AddColumn(#"Sorted Rows1", "From", each if [Index.1]=0 or [Index] <> #"Sorted Rows1"[Index]{[Index.1]-1} then [zip] else null),
    Filled_Down = Table.FillDown(Add_From,{"From"}),
    #"Grouped Rows1" = Table.Group(Filled_Down, {"From"}, {{"AllColumns", each _, type table [zip=number, Federal state=text, #"County/City"=text, Type=text, Index.1=number, Index=number, From=number]}, {"To", each List.Max([zip]), type number}}),
    #"Expanded AllColumns" = Table.ExpandTableColumn(#"Grouped Rows1", "AllColumns", {"zip", "Federal state", "County/City", "Type", "Index.1", "Index", "From"}, {"zip", "Federal state", "County/City", "Type", "Index.1", "Index", "From.1"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Expanded AllColumns",{"zip", "Federal state", "County/City", "Type", "Index.1", "Index", "From.1", "From", "To"}),
    #"Removed Columns1" = Table.RemoveColumns(#"Reordered Columns",{"Index.1", "Index", "From.1", "zip"}),
    #"Removed Duplicates" = Table.Distinct(#"Removed Columns1", {"From", "To"})
in
    #"Removed Duplicates"
 
Upvote 0
Hi citizenbh,


this is a very interesting solution, which is also much faster than mine. But when I applied your solution to the entire input (8200 lines), it took almost 15 minutes to get the result
 
Upvote 0
I think this is the Right Solution:

Code:
let
   Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Sorted Rows" = Table.Sort(Source,{{"zip", Order.Ascending}}),
    #"Grouped Rows" = Table.Group(#"Sorted Rows", {"County/City"}, {{"help1", each _, type table [zip=number, Federal state=text, #"County/City"=text, Type=text]}, {"From", each List.Min([zip]), type number}, {"To", each List.Max([zip]), type number}}),
    #"Expanded help1" = Table.ExpandTableColumn(#"Grouped Rows", "help1", {"zip", "Federal state", "County/City", "Type"}, {"zip", "Federal state", "County/City.1", "Type"}),
    #"Sorted Rows1" = Table.Sort(#"Expanded help1",{{"zip", Order.Ascending}}),
    #"Removed Duplicates" = Table.Distinct(#"Sorted Rows1", {"From", "To"}),
    #"Removed Columns" = Table.RemoveColumns(#"Removed Duplicates",{"zip", "County/City.1"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Removed Columns",{"Federal state", "County/City", "Type", "From", "To"})
in
    #"Reordered Columns"

1. Enable in Query Options Fast Data Load On
2. You can still view Query Dependencies in View Tab
 
Last edited:
Upvote 0
I saw the error in the last code. There are overlapping numbers. The same County / City are in different groups of numbers!

FINAL:

Code:
let
   Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    #"Sorted Rows" = Table.Sort(Source,{{"zip", Order.Ascending}}),
    #"Added Index" = Table.AddIndexColumn(#"Sorted Rows", "Index", 0, 1),
    Custom_index = Table.AddColumn(#"Added Index", "custom column", each if [Index] = 0 then 1 else if #"Added Index"{[Index]-1}[#"County/City"] = #"Added Index"{[Index]}[#"County/City"] then 0 else 1),
    #"Removed Columns" = Table.RemoveColumns(Custom_index,{"Index"}),
    #"Grouped Rows" = Table.Group(#"Removed Columns", {"County/City"}, {{"Help", each _, type table [zip=number, Federal state=text, #"County/City"=text, Type=text, custom column=number]}, {"From", each List.Min([zip]), type number}, {"To", each List.Max([zip]), type number}}),
    #"Expanded Help" = Table.ExpandTableColumn(#"Grouped Rows", "Help", {"zip", "Federal state", "County/City", "Type", "custom column"}, {"zip", "Federal state", "County/City.1", "Type", "custom column"}),
    #"Filtered Rows" = Table.SelectRows(#"Expanded Help", each ([custom column] = 1)),
    #"Removed Columns1" = Table.RemoveColumns(#"Filtered Rows",{"zip", "County/City.1", "custom column"}),
    #"Reordered Columns" = Table.ReorderColumns(#"Removed Columns1",{"Federal state", "County/City", "Type", "From", "To"})
in
    #"Reordered Columns"
 
Upvote 0
I'd add
Code:
#"Removed Duplicates" = Table.Distinct(#"Reordered Columns")
on the end
 
Upvote 0
or a bit shorter:

Code:
[SIZE=1]let
   Source = Excel.CurrentWorkbook(){[Name="Table1"]}[Content],
    Group = Table.Group(Source, {"County / City"}, {{"Help", each _, type table}, {"From", each List.Min([zip]), type number}, {"To", each List.Max([zip]), type number}}),
    ListFederalState = Table.AddColumn(Group, "Federal state", each List.Distinct(Table.Column([Help],"Federal state"))),
    ListType = Table.AddColumn(ListFederalState, "Type", each List.Distinct(Table.Column([Help],"Type"))),
    ExpandFederalState = Table.ExpandListColumn(ListType, "Federal state"),
    ExpandType = Table.ExpandListColumn(ExpandFederalState, "Type"),
    ROC = Table.SelectColumns(ExpandType,{"Federal state", "County / City", "Type", "From", "To"})
in
    ROC[/SIZE]
 
Upvote 0
Hello sandy666 and citizenbh,


I have now tested all the codes and seen some interesting solutions. But unfortunately none of them gives the right result. Therefore here is a small example and the expected result:


60000 Town A
60010 Town A
60200 Town B
60210 Town B
60500 Town A
60600 Town B


Expected result
Town A 60000 - 60010
Town A 60500 - 60500
Town B 60200 - 60210
Town B 60600 - 60600


But the result of your solutions is:
Town A 60000 - 60500
Town B 60200 - 60600


I have also loaded a folder on OneDrive that contains all the solutions.


And as already mentioned, my solutions determine the correct ranges, but Power Query is probably very slow when comparing values of different rows in queries using INDEX. This seems to be a general weakness of Power Query at the moment.


This may be due to the fact that this great tool has been around for several years, but most Excel users don't use it yet. One or the other vulnerability has not yet been detected.


When I tell colleagues about Power Query, most people have never heard of it, even though my employer is a global company with almost 300,000 employees.


Even though at the moment there may not be a way to solve the problem with the long runtime, I would like to thank you for the great ideas, which helped me to learn a lot again

https://1drv.ms/x/s!AjraeoAbqhhv7S_ZM2FxBFu7Ekrn
 
Upvote 0
I didn't read the first post (sorry :) ) I just modified and optimized M-code from above of my post.
I'll look at the file and read description(s).
 
Upvote 0

Forum statistics

Threads
1,214,642
Messages
6,120,701
Members
448,980
Latest member
CarlosWin

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top