cancel
Showing results for 
Search instead for 
Did you mean: 
Reply

Challenging for me: How do you mark the Start and End of values for each column

I've been struggling with this for some time.  I'm not sure how to approach this one.
For each XRef, I need to mark the beginning and end of the data for each column by adding a "FFFF".
(I've truncated the data for simplicity)

This is where I'm stuck now.

 

Below is an example of the expected results.  "FFFF" added to the beginning and end for the list of values in each column
for each XRef:


The .pbix contains the M code for power query.

Download_pbix 



17 REPLIES 17

@roncruiser List.PositionOf : (x, y) => represents a comparison criteria mentioned in the documentation. We compare each item of the list with "value" argument. Occurrence.First/Last/All is

optional occurrence as nullable number

Check list functions documentation, parameter values section. 

Lets take a list 

{"","","",1,2,3,4,5,6,"","",""}

All positions of "" in the list: 

    List.PositionOf(
        {"","","",1,2,3,4,5,6,"","",""}, 
        "",
        Occurrence.All
    )

default equationCriteria is a function that returns true or false if values are equal or not. But we want to get a first of last position of item which is <> "". That's why we use custom 

optional equationCriteria as any

that returns true when list item is <> "". With combination of Occurrence argument we find first or last item that is <> "". 

@AlienSx 
This is great.  Makes a bit more sense now.  I was trying to understand your code better yesterday by breaking it down and running piece by piece separately.

At a high level I understand what's going on, but the syntax and the way everything ties together is bit confusing.

I added some of my own comments.  Please ccomment if they look incorrect.
I have a question please:

//Question: Table.ColumnNames(x) grabs the column names.  How are the column names then 
//added back?
//After each column is converted to a list, the column names are lost.  Which part 
//of the syntax adds the column names back to the table?  

 group = Table.Group(
        idx, "XRef", 
        {"x", (x) =>  //"x" is the name of the column for the grouped tables 
            [to_col = Table.ToColumns(Table.Sort(x, "idx")), 
            //create list from each column in the table and sort each table by column "idx"

            result = Table.FromColumns(
                List.FirstN(to_col, 2) & 
                    List.Transform(List.RemoveFirstN(to_col, 2), ffff), 
                    //removes the first 2 columns and runs the ffff function on remaining.
                Table.ColumnNames(x)  
                //gets the columns names from the original source table.
            )][result]}
    ),
    z = Table.Combine(group[x])

 

@roncruiser column names are added back here: 

Table.FromColumns(lists as list, optional columns as any) as table

result = Table.FromColumns(...) 

@AlienSx 
Thanks for my knowledge support.
I learned how powerful lists are in the past 5 days.  Thanks to you.

@AlienSx 

I'm still not understanding something with the code below relative to your code.
I'm trying to replace the last value in the list "11" with "**".  I broke down your code and was able to replace the last value in the last row in the list with "**" using the code below.

let
    Source = {1,2,3,4,5,"",10,11},

        first = List.PositionOf(Source, "", Occurrence.First, (x, y) => x <> y),
        last = List.PositionOf(Source, "", Occurrence.Last, (x, y) => x <> y),
        last_ = List.Last(Source),
        replace_first = 
            if List.Contains({-1, 0}, first +1 ) 
            then Source 
            else List.ReplaceRange(Source, first  , 1, {"*"}), 
        replace_last = 
            if List.Contains({-1, List.Count(Source)  -1 }, last+1) 
            then replace_first
            else List.ReplaceRange(replace_first, last, 1, {"**"})
            in
            replace_last


My confusion, I am not able to do the same with the original code you wrote here:

    ffff = (lst) => 
        [first = List.PositionOf(lst, "", Occurrence.First, (x, y) => x <> y),
        last = List.PositionOf(lst, "", Occurrence.Last, (x, y) => x <> y),
        replace_first = 
            if List.Contains({-1, 0}, first) 
            then lst 
            else List.ReplaceRange(lst, first - 1, 1, {"*"}),
        replace_last = 
            if List.Contains({-1, List.Count(lst) - 1}, last) 
            then replace_first 
            else List.ReplaceRange(replace_first, last + 1, 1, {"**"})][replace_last],

 

 Other than the source list, the only difference is this line:
Yours
replace_last =
if List.Contains({-1, List.Count(lst) - 1}, last)  //If I add a +1 to your code, the group table shows errors.

Mine:
replace_last =
if List.Contains({-1, List.Count(Source) -1 }, last+1)  // I added a +1 and it works perfectly to replace the last value in the list.  In my break down code.

 

How can I get it to work in your code?  Replacing the last value in the last row in the list with "**" in your code for all columns.

if List.Contains({-1, List.Count(lst) - 1}, last)

works as preventer. Last time you wanted to replace the very last occurrence of "". This piece of code does not allow to change anything if item <> "" is not found or the very last item <> "". Now you want to replace that last item if it is <> "". Try simple if last = -1 then <do_nothing> else List.ReplaceRange(...) with exact position of item instead. 

let
    ffff = (lst) => 
        [first = List.PositionOf(lst, "", Occurrence.First, (x, y) => x <> y),
        last = List.PositionOf(lst, "", Occurrence.Last, (x, y) => x <> y),
        replace_first = 
            if List.Contains({-1, 0}, first) 
            then lst 
            else List.ReplaceRange(lst, first - 1, 1, {"*"}),
        replace_last = 
            if last = -1 
            then replace_first 
            else List.ReplaceRange(replace_first, last, 1, {"**"})][replace_last],
    Source = {1,2,3,4,5,"",10,11},
    zz = ffff(Source)
in
    zz

Hi @roncruiser, different approach here:

 

Result

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("jZZdbsMgEAbv4uc+AMbYPNYlXKLq/a/R7EcMGNjFUhtLzMiJ+Znk93fRy9ei3v/pL8a40+WMcfn7SlRX9GXp4t/SRU2m7lR0I+ety3TN1ChQRZeL2kzVgG4idSLdRXqI1ItUKxlrGRtMY6Bni1vwnEbz5reDPmjQhbeaxYs68LlwGWpb0WreajSlyl6Avdv+TDvSm7bv1mo+3W3y2Yy63Y17U6NvT8pq5pmGVbD6nGi0Ct75mUar4Pf3wRIXy9AqxKQFpyOnfXZ4iJFV5G1u5H2+yvt8ve1z02Ej47XGrsN1GBAk3CTjUgZ3Xo+/FlzSQMZ7Lgvaa1SGj/GwHw5b1Q3jAfPQJ6KZ3AL6yeueaR1QewsokSqg+r4KRPmAEuUDSpQPKFE+oET5nUWU31iYDX5jAes0g6Fchhq9hBjIDm4YUmjpCAOEcV5SC5ZZrKDRjKq55p5p+zPteKb5RxpC+kDTzzSzzOoNbU3a90RLIZ1qCKnbhN5Cq0LqnTk57QrpPgwpFHm7CyHFCZb3uxBSYD6kwHVItetwCYRpQgpcCvG6vkdMLLgJaaxQH1IM9yHFcB9S1KsPKTZKHqpDSkS3JP9OJWoq+kMP7rzbMy0T5fx9FYjwISXKh5QoH1KifEiJ8jsL4RKpEFLgFNL0U3McUmgI6Z4KuQ0PHTS8pCDo8dlMxpi32jbmrTYPKbR5SKExlWq19rtkrBmGt5p+pn1OthBSaGsaEQoJzT7TaBV+7CqEFJpbch616W6atSukbhhSKPJ2F0KKE3zb76bDt5C6DhsZj0JqCi6BsOs9pMClEIS+11IlJqJAfUQx3EcUw31EUa4mon//", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [XRef = _t, TRef = _t, VALUE0000 = _t, VALUE0010 = _t, VALUE0001 = _t, VALUE0011 = _t]),
    // You can probably delete this step
    ReplaceBlankToNull = Table.TransformColumns(Source, {}, each if _ = "" then null else _),
    ChangedType = Table.TransformColumnTypes(ReplaceBlankToNull,{{"XRef", Int64.Type}, {"TRef", Int64.Type}}),
    
    fn_ReplaceValue = 
        (myTable) as table =>
        let
            // T = GroupedRows{[XRef=2]}[All],
            T = myTable,
            ToCols = Table.ToColumns(T),
            FirstNoNullPosition = List.Transform(ToCols, (x)=> 
                [ first = List.PositionOf(x, null, Occurrence.First, (y,z)=> y <> z),
                last = List.PositionOf(x, null, Occurrence.Last, (y,z)=> y <> z),
                b = List.Transform({0..List.Count(x)-1}, (y)=> if List.Contains({first -1, last +1}, y) then "FFFF" else x{y} )
                ][b]),
            FromCols = Table.FromColumns(FirstNoNullPosition, Value.Type(T))
        in 
            FromCols,

    GroupedRows = Table.Group(ChangedType, {"XRef"}, {{"All", each fn_ReplaceValue(_), type table}}),
    CombinedAll = Table.Combine(GroupedRows[All])
in
    CombinedAll

@AlienSx 
Some context:
The solution I was striving for with my original post simply was not good enough.  Your code, help, and guidance helped realize my approach was not good enough.  Replacing the <>"" at the top and bottom of the list is the better solution.

By marking the top and bottom of the list, I can then strip away everything in between.  The biggest benefit to that is reducing load time.  Sometimes I/we simply don't need everything in between the top of the list and the bottom of the list.  Marking the top and bottom is good enough.

Our current solution loads everything in between which has it's benefits.  The biggest benefit is resolution.  The downside is that it takes a very very very long time to load all the data.

50% of the time the user does need to load everything in between.  They just want a simple health check so to speak.  Reducing load time at the expense of resolution is the "New" added benefit.  Based on rough testing, the load times reduced up to 80%.  Best case.  Which is significant.  Thanks to your inspiration!  I'm still realizing more possibilities with the help of your code.  It's like a door opened up to another realm.

I'd like to give the user incremental resolution control. 
Below on the left side is every basic scenario your code can cover.  Which covers everything the data can throw at use.  In general.

Is there a way to mark the top two and mark the bottom two within the list like the right side example?  This will effectively double the resolution relative to the left side in the example below.

The trouble I see with this is the third example down on the right side.  How will doubling the markers be handled in yellow?   As long as a marker is indeed placed there will be good enough.


This is really cool stuff.   I know it's asking a lot, but I'm learning a lot too. 
Thank you again.

 

 

Helpful resources

Announcements

Community will be READ ONLY July 16th, 5p PDT -July 22nd

Dear Community Members,   We'd like to let you know of an upcoming change to the community platform: starting July 16th, the platform will transition to a READ ONLY mode until July 22nd.   During this period, members will not be able to Kudo, Comment, or Reply to any posts.   On July 22nd, please be on the lookout for a message sent to the email address registered on your community profile. This email is crucial as it will contain your unique code and link to register for the new platform encompassing all of the communities.   What to Expect in the New Community: A more unified experience where all products, including Power Apps, Power Automate, Copilot Studio, and Power Pages, will be accessible from one community.Community Blogs that you can syndicate and link to for automatic updates. We appreciate your understanding and cooperation during this transition. Stay tuned for the exciting new features and a seamless community experience ahead!

Summer of Solutions | Week 4 Results | Winners will be posted on July 24th

We are excited to announce the Summer of Solutions Challenge!   This challenge is kicking off on Monday, June 17th and will run for (4) weeks.  The challenge is open to all Power Platform (Power Apps, Power Automate, Copilot Studio & Power Pages) community members. We invite you to participate in a quest to provide solutions in the Forums to as many questions as you can. Answers can be provided in all the communities.    Entry Period: This Challenge will consist of four weekly Entry Periods as follows (each an “Entry Period”)   - 12:00 a.m. PT on June 17, 2024 – 11:59 p.m. PT on June 23, 2024 - 12:00 a.m. PT on June 24, 2024 – 11:59 p.m. PT on June 30, 2024 - 12:00 a.m. PT on July 1, 2024 – 11:59 p.m. PT on July 7, 2024 - 12:00 a.m. PT on July 8, 2024 – 11:59 p.m. PT on July 14, 2024   Entries will be eligible for the Entry Period in which they are received and will not carryover to subsequent weekly entry periods.  You must enter into each weekly Entry Period separately.   How to Enter: We invite you to participate in a quest to provide "Accepted Solutions" to as many questions as you can. Answers can be provided in all the communities. Users must provide a solution which can be an “Accepted Solution” in the Forums in all of the communities and there are no limits to the number of “Accepted Solutions” that a member can provide for entries in this challenge, but each entry must be substantially unique and different.    Winner Selection and Prizes: At the end of each week, we will list the top ten (10) Community users which will consist of: 5 Community Members & 5 Super Users and they will advance to the final drawing. We will post each week in the News & Announcements the top 10 Solution providers.  At the end of the challenge, we will add all of the top 10 weekly names and enter them into a random drawing.  Then we will randomly select ten (10) winners (5 Community Members & 5 Super Users) from among all eligible entrants received across all weekly Entry Periods to receive the prize listed below. If a winner declines, we will draw again at random for the next winner.  A user will only be able to win once overall. If they are drawn multiple times, another user will be drawn at random.  Individuals will be contacted before the announcement with the opportunity to claim or deny the prize.  Once all of the winners have been notified, we will post in the News & Announcements of each community with the list of winners.   Each winner will receive one (1) Pass to the Power Platform Conference in Las Vegas, Sep. 18-20, 2024 ($1800 value). NOTE: Prize is for conference attendance only and any other costs such as airfare, lodging, transportation, and food are the sole responsibility of the winner. Tickets are not transferable to any other party or to next year’s event.   ** PLEASE SEE THE ATTACHED RULES for this CHALLENGE**   Week 1 Results: Congratulations to the Week 1 qualifiers, you are being entered in the random drawing that will take place at the end of the challenge. Community MembersNumber of SolutionsSuper UsersNumber of Solutions @anandm08  23 @WarrenBelz  31 @DBO_DV  10 @Amik  19 AmínAA 6 @mmbr1606  12 @rzuber  4 @happyume  7 @Giraldoj  3@ANB 6 (tie)   @SpongYe  6 (tie)     Week 2 Results: Congratulations to the Week 2 qualifiers, you are being entered in the random drawing that will take place at the end of the challenge. Community MembersSolutionsSuper UsersSolutions @anandm08  10@WarrenBelz 25 @DBO_DV  6@mmbr1606 14 @AmínAA 4 @Amik  12 @royg  3 @ANB  10 @AllanDeCastro  2 @SunilPashikanti  5 @Michaelfp  2 @FLMike  5 @eduardo_izzo  2   Meekou 2   @rzuber  2   @Velegandla  2     @PowerPlatform-P  2   @Micaiah  2     Week 3 Results: Congratulations to the Week 3 qualifiers, you are being entered in the random drawing that will take place at the end of the challenge.   Week 3:Community MembersSolutionsSuper UsersSolutionsPower Apps anandm0861WarrenBelz86DBO_DV25Amik66Michaelfp13mmbr160647Giraldoj13FLMike31AmínAA13SpongYe27     Week 4 Results: Congratulations to the Week 4 qualifiers, you are being entered in the random drawing that will take place at the end of the challenge.   Week 4:Community MembersSolutionsSuper UsersSolutionsPower Apps DBO-DV21WarranBelz26Giraldoj7mmbr160618Muzammmil_0695067Amik14samfawzi_acml6FLMike12tzuber6ANB8   SunilPashikanti8

Check Out | 2024 Release Wave 2 Plans for Microsoft Dynamics 365 and Microsoft Power Platform

On July 16, 2024, we published the 2024 release wave 2 plans for Microsoft Dynamics 365 and Microsoft Power Platform. These plans are a compilation of the new capabilities planned to be released between October 2024 to March 2025. This release introduces a wealth of new features designed to enhance customer understanding and improve overall user experience, showcasing our dedication to driving digital transformation for our customers and partners.    The upcoming wave is centered around utilizing advanced AI and Microsoft Copilot technologies to enhance user productivity and streamline operations across diverse business applications. These enhancements include intelligent automation, AI-powered insights, and immersive user experiences that are designed to break down barriers between data, insights, and individuals. Watch a summary of the release highlights.    Discover the latest features that empower organizations to operate more efficiently and adaptively. From AI-driven sales insights and customer service enhancements to predictive analytics in supply chain management and autonomous financial processes, the new capabilities enable businesses to proactively address challenges and capitalize on opportunities.    

Updates to Transitions in the Power Platform Communities

We're embarking on a journey to enhance your experience by transitioning to a new community platform. Our team has been diligently working to create a fresh community site, leveraging the very Dynamics 365 and Power Platform tools our community advocates for.  We started this journey with transitioning Copilot Studio forums and blogs in June. The move marks the beginning of a new chapter, and we're eager for you to be a part of it. The rest of the Power Platform product sites will be moving over this summer.   Stay tuned for more updates as we get closer to the launch. We can't wait to welcome you to our new community space, designed with you in mind. Let's connect, learn, and grow together.   Here's to new beginnings and endless possibilities!   If you have any questions, observations or concerns throughout this process please go to https://aka.ms/PPCommSupport.   To stay up to date on the latest details of this migration and other important Community updates subscribe to our News and Announcements forums: Copilot Studio, Power Apps, Power Automate, Power Pages

Users online (1,731)