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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
Anonymous
Not applicable

Conditional statements i.e countif

Hi 

 

I hope you can help?

I have a table like that shown below in Power BI. I'm trying to get a count of apples picked, appled delivered, bananas picked and bananas delivered by Date. 

 

Apples PickedApples deliveredBananas PickedBananas delivered
01/01/202402/01/202420/12/202324/12/2023
30/12/202331/12/202321/12/202324/12/2023
30/12/202302/01/202401/01/202401/01/2024
28/12/202302/01/202401/01/202402/01/2024

 

 

Therefore I would like to build the table below. Can this be done in power query? I would like it automatically based on today's date and descending for last 365 days? 

 

 Count of Apples PickedCount of Apples deliveredCount of Bananas PickedCount of Bananas Picked
02/01/20240301
01/01/20241021
31/12/20230100
30/12/20231000
29/12/20230000
28/12/20231000
27/12/20230000
26/12/20230000
25/12/20230002
24/12/20230020

 

 

5 REPLIES 5
jennratten
Super User
Super User

Hello - this is how you can do it...

jennratten_0-1704200652515.png

 

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("i45WMtQ31DcyMDJR0gEyjeBMEAvEMYZyTCCcWJ1oENcYWc7YEFmXITG6jJAtxWRC1RtZ4FcPF42NBQA=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"Apples Picked" = _t, #"Apples delivered" = _t, #"Bananas Picked" = _t, #"Bananas delivered" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"Apples Picked", type text}, {"Apples delivered", type text}, {"Bananas Picked", type text}, {"Bananas delivered", type text}}),
    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {}, "Attribute", "Value"),
    #"Duplicated Column" = Table.DuplicateColumn(#"Unpivoted Columns", "Value", "Date"),
    #"Pivoted Column" = Table.Pivot(#"Duplicated Column", List.Distinct(#"Duplicated Column"[Attribute]), "Attribute", "Value", List.Count),
    #"Changed Type1" = Table.TransformColumnTypes(#"Pivoted Column",{{"Date", type date}}),
    #"Filtered Rows" = Table.SelectRows(#"Changed Type1", each Date.IsInPreviousNYears([Date], 1)),
    #"Sorted Rows" = Table.Sort(#"Filtered Rows",{{"Date", Order.Descending}})
in
    #"Sorted Rows"

If this post helps to answer your questions, please consider marking it as a solution so others can find it more quickly when faced with a similar challenge.

Proud to be a Microsoft Fabric Super User

Anonymous
Not applicable

Hi

 

Thanks, did you create a new data table, or can i amend to the original table? 

I used your data but changed the dates in the source step to M/d/yyyy to work with my locale.  To apply this solution to your data table, use everything except for the source step, like so (just change #"Changed Type" to the name of your last step):

    #"Unpivoted Columns" = Table.UnpivotOtherColumns(#"Changed Type", {}, "Attribute", "Value"),
    #"Duplicated Column" = Table.DuplicateColumn(#"Unpivoted Columns", "Value", "Date"),
    #"Pivoted Column" = Table.Pivot(#"Duplicated Column", List.Distinct(#"Duplicated Column"[Attribute]), "Attribute", "Value", List.Count),
    #"Changed Type1" = Table.TransformColumnTypes(#"Pivoted Column",{{"Date", type date}}),
    #"Filtered Rows" = Table.SelectRows(#"Changed Type1", each Date.IsInPreviousNYears([Date], 1)),
    #"Sorted Rows" = Table.Sort(#"Filtered Rows",{{"Date", Order.Descending}})
in
    #"Sorted Rows"

 

If this post helps to answer your questions, please consider marking it as a solution so others can find it more quickly when faced with a similar challenge.

Proud to be a Microsoft Fabric Super User

Anonymous
Not applicable

Thanks but i've stumbled on an issue, the table above are appended to a data table with lots of columns. However when i attempt to pivot the required column is doesnt work due to the additional columns and repeats the dates. Can I create a linked data table to focus solely on the pivioted columns? Let me know if i need to show an example

 

Hi @Anonymous - Yes, you can create a linked reference, limit the columns omit those that are not needed and then perform the pivot.

If this post helps to answer your questions, please consider marking it as a solution so others can find it more quickly when faced with a similar challenge.

Proud to be a Microsoft Fabric Super User

Helpful resources

Announcements
July PBI25 Carousel

Power BI Monthly Update - July 2025

Check out the July 2025 Power BI update to learn about new features.

Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 community update carousel

Fabric Community Update - June 2025

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

Top Solution Authors