Join us for an expert-led overview of the tools and concepts you'll need to pass exam PL-300. The first session starts on June 11th. See you there!
Get registeredPower BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.
Hello
I have two tables, one with current subscriptions and ones with expired subscriptions linked by memberID. I need to check from the current subscriptions who have renewed and is not a new member. To do this I want to check for any subscriptions in the Expired table where the end date is between the Current subscription start date - 1 Day and -1 Month. I then need to use the results as part of a pivot table where the row will be subscription type and the column will be start date.
This is an example of my required output
Below is my dax query but I keep getting "a table of multiple values was supplied where a single value was expected"
Solved! Go to Solution.
Hi, @nicole1995
Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.
Current Subscription:
Expired Subscription:
You may create a measure as below.
Result =
var t =
ADDCOLUMNS(
ALL('Current Subscriptions'),
"Result",
var _startdate = [StartDate]
var _date = EOMONTH(_startdate,-1)
var _d = DATE(YEAR(_date),MONTH(_date),DAY(_startdate))
return
COUNTROWS(
FILTER(
ALL('Expired Subscriptions'),
[MemberID]=EARLIER('Current Subscriptions'[MemberID])&&
[EndDate]>=_d&&
[EndDate]<=_startdate-1
)
)
)
var _result =
SUMX(
SUMMARIZE(
'Current Subscriptions',
'Current Subscriptions'[Type],
'Current Subscriptions'[StartDate].[Month],
"Re",
SUMX(
FILTER(
t,
[Type]=SELECTEDVALUE('Current Subscriptions'[Type])&&
'Current Subscriptions'[StartDate].[Month]=EARLIER('Current Subscriptions'[StartDate].[Month])
),
[Result]
)
),
[Re]
)
return
IF(
ISBLANK(_result),
0,
_result
)
Result:
Best Regards
Allan
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi, @nicole1995
Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.
Current Subscription:
Expired Subscription:
You may create a measure as below.
Result =
var t =
ADDCOLUMNS(
ALL('Current Subscriptions'),
"Result",
var _startdate = [StartDate]
var _date = EOMONTH(_startdate,-1)
var _d = DATE(YEAR(_date),MONTH(_date),DAY(_startdate))
return
COUNTROWS(
FILTER(
ALL('Expired Subscriptions'),
[MemberID]=EARLIER('Current Subscriptions'[MemberID])&&
[EndDate]>=_d&&
[EndDate]<=_startdate-1
)
)
)
var _result =
SUMX(
SUMMARIZE(
'Current Subscriptions',
'Current Subscriptions'[Type],
'Current Subscriptions'[StartDate].[Month],
"Re",
SUMX(
FILTER(
t,
[Type]=SELECTEDVALUE('Current Subscriptions'[Type])&&
'Current Subscriptions'[StartDate].[Month]=EARLIER('Current Subscriptions'[StartDate].[Month])
),
[Result]
)
),
[Re]
)
return
IF(
ISBLANK(_result),
0,
_result
)
Result:
Best Regards
Allan
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
@nicole1995 - DATEADD will return a column of values. Try:
CALCULATE(
COUNTROWS('CurrentSubscriptions'),
FILTER(
'ExpiredSubscriptions',
'ExpiredSubscriptions'[EndDate] <= ('CurrentSubscriptions'[StartDate].[Date] -1) * 1.
&& 'ExpiredSubscriptions'[EndDate] >= EOMONT('CurrentSubscriptions'[StartDate].[Date],-1)
))
Thanks for your quick reply.
I have tried the query but it won't let me filter between two tables. Is there something I'm missing ?
@nicole1995 - Oh, you probably need an aggregator around a column reference (MAX, MIN, etc.) or MAXX(RELATEDTABLE(...)...)
@nicole1995 , Can you share sample data and sample output in table format? Or a sample pbix after removing sensitive data.
A approach on this blog should help
Two date join to same date table. Here, in one date we can have -1
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
84 | |
76 | |
73 | |
42 | |
36 |
User | Count |
---|---|
109 | |
56 | |
52 | |
48 | |
43 |