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

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

Reply
rinaibrhm
New Member

Time Intelligence for Sales and Customer Problem

I have 4 tables as below.

 

The Current and Previous tables are used to store different time period selections from two slicers, used for comparison.

 

For sake of simplicity, lets say :-

'Sales' table contain a record for each unique OrderID, Total Revenue, UserID, Product.

'Customer' table contain a record for each unique UserID, Age, Location.

 

rinaibrhm_0-1696818544681.png

 

In the 'Sales' table, I was able to create 2 measures for 'Sales_Current_Period' and 'Sales_Previous Period'.

 

My issue now is :-

  • how do I create two columns in Customer i.e. Customer['Orders_Current_Period'] and Customer['Orders_Previous_Period']? I want to know COUNT([OrderID]) for each customer in two different periods. (Note: I am aware I can just visualize this in a table easily to get what I need, but just know I need the columns).
  • how do I create a column in Customer i.e. Customer['Top_Product'] where it returns the Sales['Product'] with the highest COUNT([OrderID])?
1 ACCEPTED SOLUTION
v-tangjie-msft
Community Support
Community Support

Hi @rinaibrhm ,

 

According to your description, here are my steps you can follow as a solution.

(1) This is my test data. 

vtangjiemsft_0-1697003927384.png

(2) We can create calculated columns.

Orders_Previous_Period = COUNTROWS(FILTER('Sales','Sales'[Order_Date] in VALUES('Previous'[Date]) && 'Sales'[UserID]=EARLIER('Customer'[UserID])))
Orders_Current_Period = COUNTROWS(FILTER('Sales','Sales'[Order_Date] in VALUES('Current'[Date]) && 'Sales'[UserID]=EARLIER('Customer'[UserID])))
Top_Product = 
var _a=SUMMARIZE('Sales','Sales'[UserID],'Sales'[Product],"count",COUNT('Sales'[Product]))
var _b=MAXX(FILTER(_a,[UserID] = EARLIER('Customer'[UserID])),[count])
var _c=FILTER(_a,[count]=_b && [UserID]=EARLIER('Customer'[UserID]))
return CONCATENATEX(_c,[Product],"&")

(3) Then the result is as follows.

vtangjiemsft_1-1697004032341.png

 

If the above one can't help you get the desired result, please provide some sample data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples. It is better if you can share a simplified pbix file. Thank you.

 

Best Regards,

Neeko Tang

If this post  helps, then please consider Accept it as the solution  to help the other members find it more quickly. 

View solution in original post

3 REPLIES 3
v-tangjie-msft
Community Support
Community Support

Hi @rinaibrhm ,

 

According to your description, here are my steps you can follow as a solution.

(1) This is my test data. 

vtangjiemsft_0-1697003927384.png

(2) We can create calculated columns.

Orders_Previous_Period = COUNTROWS(FILTER('Sales','Sales'[Order_Date] in VALUES('Previous'[Date]) && 'Sales'[UserID]=EARLIER('Customer'[UserID])))
Orders_Current_Period = COUNTROWS(FILTER('Sales','Sales'[Order_Date] in VALUES('Current'[Date]) && 'Sales'[UserID]=EARLIER('Customer'[UserID])))
Top_Product = 
var _a=SUMMARIZE('Sales','Sales'[UserID],'Sales'[Product],"count",COUNT('Sales'[Product]))
var _b=MAXX(FILTER(_a,[UserID] = EARLIER('Customer'[UserID])),[count])
var _c=FILTER(_a,[count]=_b && [UserID]=EARLIER('Customer'[UserID]))
return CONCATENATEX(_c,[Product],"&")

(3) Then the result is as follows.

vtangjiemsft_1-1697004032341.png

 

If the above one can't help you get the desired result, please provide some sample data in your tables (exclude sensitive data) with Text format and your expected result with backend logic and special examples. It is better if you can share a simplified pbix file. Thank you.

 

Best Regards,

Neeko Tang

If this post  helps, then please consider Accept it as the solution  to help the other members find it more quickly. 

rinaibrhm
New Member

Hi @amitchandak  I am currently not using the built-in time intelligence and my current solution is using the 'Current' and 'Previous' tables to serve this purpose.

 

In my Sales table, I already am able to get the time intelligence calculations as below :-

 

Sales_Previous_Period = 
CALCULATE (
    SUM([Total Revenue]),
    ALL ( 'Current' ),
    USERELATIONSHIP ( 'Current'[Date], 'Previous'[Date] )
) * [Normalization Factor]

 

 

Sales_Current_Period = SUM([Total Revenue])

 

 

 

My issue now is to reference the Current and Previous Date selections in my 'Customer' table, since the only relationship it has is on Sales[User ID].

amitchandak
Super User
Super User

@rinaibrhm , Please use Time intelligence function for that

 

Time Intelligence, Part of learn Power BI https://youtu.be/cN8AO3_vmlY?t=27510
Time Intelligence, DATESMTD, DATESQTD, DATESYTD, Week On Week, Week Till Date, Custom Period on Period,
Custom Period till date: https://youtu.be/aU2aKbnHuWs&t=145s

 

 

Power BI Custom Period Till Date (PTD)- https://youtu.be/rQ3Z_LtxwQM

Helpful resources

Announcements
Europe Fabric Conference

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.

RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel1

Power BI Monthly Update - May 2024

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