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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
mm5308
Helper I
Helper I

Create New Table Based on DIstinct Values of One Column and Calculated Values of Another Column

I've been searching around for a couple hours now and can't figure out what I'm missing...hopefully someone here can guide me to the right solution.

 

Out of a large table, I want to create a smaller table summarizing two of the columns (ID and PostedDate). The new table should only contain a row count equal to distinct values from the ID column. Unfortunately, many of the ID values are associated with multiple PostedDate values. To avoid creating a summary of the ID/PostedDate combo distinct values, I only want the new table to contain the earliest PostedDate for each ID.

 

Here's a sample of the data:

IDPostedDate
751/8/21
301/15/21
301/16/21
981/18/21
981/16/21
981/16/21
981/17/21

 

Note that it has only 3 distinct ID values but the second and third ones contain multiple PostedDate values each.

 

Ideally, here's the output I want:

IDPostedDate (Earliest/Min)
751/8/21
301/15/21
981/16/21

 

I've tried several iterations of formulas to create a table but they all result in the same error, which is that the earliest PostedDate of the entire original table (1/8/21) is reapeated on all rows instead of the earliest PostedDate for each individual ID. Below are some examples of DAX I've tried.

 

New Table = 

ADDCOLUMNS(
DISTINCT('Table'[ID]),
"Post",MIN('Table'[PostedDate]))
 
New Table =
ADDCOLUMNS(
SUMMARIZE('Table',
'Table'[ID]),
"Post",MIN('Table'[PostedDate]))
 
New Table =
SUMMARIZE('Table',
'Table'[ID],
"Post",MIN('Table'[PostedDate]))

 

The output of any of these looks like the following:

IDPostedDate
751/8/21
301/8/21
981/8/21

 

What am I doing wrong? (To emphasize again, I am looking to create a table here, not a measure.)

1 ACCEPTED SOLUTION
PaulDBrown
Community Champion
Community Champion

Try:

New Table = 

ADDCOLUMNS(
DISTINCT('Table'[ID]),
"Post", CALCULATE(MIN('Table'[PostedDate]), ALLEXCEPT(Table, Table [ID]))




Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






View solution in original post

4 REPLIES 4
mm5308
Helper I
Helper I

Thank you both for your replies! The accepted solution worked perfectly. When I first saw the new table, I was scared because all the visible "Post" dates were all the same still. But when I clicked the drop-down arrow on that column, it showed that there were indeed a ton of PostDate values. The metadata at the bottom confirmed as much.

 

Realizing this "check the data" error, I wondered if my original DAX expressions worked without me realizing it because I'd focused only on the visible results. Turns out, the third expression above (that starts with SUMMARIZE) actually did work. I feel silly for posting now.

 

Again, thanks to the two users who helped. More than a simple solution to this particular problem, I learned a more valuable lesson: check my work better (and don't be in a rush)!

PaulDBrown
Community Champion
Community Champion

Try:

New Table = 

ADDCOLUMNS(
DISTINCT('Table'[ID]),
"Post", CALCULATE(MIN('Table'[PostedDate]), ALLEXCEPT(Table, Table [ID]))




Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






truptis
Community Champion
Community Champion

Hi @mm5308 ,

Try this:

Earliest Date result = CALCULATE( MIN ( tablename[posted date] ), ALLEXCEPT(tablename, tablename[id] ) )

This works as a partial solution because it only addresses the "Post" calculation instead of creating the whole table. Nonetheless, good contribution. Thanks.

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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