Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Mknotes1279
New Member

problem: Extracting lists and refer to query table

Dear Community,

 

I have a question concerining extracting lists in Power Query. So in my query I have multiple columns. One of them ist called "TeamID" an contains numbers. Another one is called "statistics" and contains a number of lists. The data is from a football API.

 

The lists have a structure like this:

"statistics": [
            {
                "id"27282493,
                "player_id"25162,
                "team_id"1016,
                "season_id"186,
                "has_values"true,
                "position_id"null,
                "jersey_number"17,
                "details": [
                    {
                        "id"26869160,
                        "player_statistic_id"27282493,
                        "type_id"52,
                        "value": {
                            "total"1,
                            "goals"1,
                            "penalties"0
                        }
                    },
                    },
                    {
                        "id"2036855,
                        "player_statistic_id"27282493,
                        "type_id"321,
                        "value": {
                            "total"10
                        }
                    },
                    
                    }
                ]
            },
            {
                "id"27283108,
                "player_id"25162,
                "team_id"1016,
                "season_id"188,
                "has_values"true,
                "position_id"null,
                "jersey_number"7,
                "details": [
                    {
                        "id"23724412,
                        "player_statistic_id"27283108,
                        "type_id"52,
                        "value": {
                            "total"4,
                            "goals"4,
                            "penalties"0
 
I would like to add up all the "total" values if the connected "type_id" is 321 (appearances of certain player). Additionally I want to filter by team_id. In the it'll show all the games a player appeared in for one team.
 
Therefore I've created this code for a new column: = 

List.Sum(List.Transform([statistics], each if [team_id] = 1079 and Record.HasFields(_, "details") then List.Sum(List.Transform(_[details], each if _[type_id] = 321 then _[value][total] else 0)) else 0))

 

Now my problem: This code works perfectly. But I don't want to go deep into Power Query to change the team_id everytime I change the team. So instead of the absolute number I wanted to connect this part with my column "TeamID" from the query. Like this...

 

= List.Sum(List.Transform([statistics], each if [team_id] = @Abfrage3[TeamID] and Record.HasFields(_, "details") then List.Sum(List.Transform(_[details], each if _[type_id] = 321 then _[value][total] else 0)) else 0))

 

But this doesnt work. Everytime I get "0" as a result. It's the same when I try it with a parameter or a similar field in another query. Maybe some of you will have a hint for me.

 

Thanks in Advance, Greetings, Marvin

1 ACCEPTED SOLUTION
v-jingzhang
Community Support
Community Support

Hi @Mknotes1279 

 

You may try the following code for a new column:

= let vTeamId = [TeamID] in List.Sum(List.Transform([statistics], each if [team_id] = vTeamId and Record.HasFields(_, "details") then List.Sum(List.Transform(_[details], each if _[type_id] = 321 then _[value][total] else 0)) else 0))

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

View solution in original post

3 REPLIES 3
v-jingzhang
Community Support
Community Support

Hi @Mknotes1279 

 

You may try the following code for a new column:

= let vTeamId = [TeamID] in List.Sum(List.Transform([statistics], each if [team_id] = vTeamId and Record.HasFields(_, "details") then List.Sum(List.Transform(_[details], each if _[type_id] = 321 then _[value][total] else 0)) else 0))

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

Thank you so much, you're my hero 😍

ppm1
Solution Sage
Solution Sage

Why not just parse the JSON with Json.Document to simplify things? You may need to add/remove characters to create valid JSON but should still be easier.

 

Pat

Microsoft Employee

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.

Top Solution Authors
Top Kudoed Authors