cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
Corey-Flinders Frequent Visitor
Frequent Visitor

Approach to generate a sample of records for each group of records in a table

Hi All,

 

I have a table that contains data for years 2005 to 2018. I need to generate a sample of records for each year in the table. My working DAX expression looks like this:

 

Sample Table = UNION(
    SAMPLE(
        10,
        FILTER('Consolidated Data', AND('Consolidated Data'[Year Commenced] = 2005, ISBLANK('Consolidated Data'[Year Completed]) = FALSE)),
        'Consolidated Data'[Student ID]
    ),
    SAMPLE(
        10,
        FILTER('Consolidated Data', AND('Consolidated Data'[Year Commenced] = 2006, ISBLANK('Consolidated Data'[Year Completed]) = FALSE)),
        'Consolidated Data'[Student ID]
    ),
    SAMPLE(
        10,
        FILTER('Consolidated Data', AND('Consolidated Data'[Year Commenced] = 2007, ISBLANK('Consolidated Data'[Year Completed]) = FALSE)),
        'Consolidated Data'[Student ID]
    )
)

While this approach works, it feels wrong. I'm copying and pasting each call to the SAMPLE function and only changing the filter, and then using the UNION function to consolidate the returned records together into a single table.

 

Does anyone have any suggestions for an alternative approach?

 

With thanks.

 

-Corey

1 ACCEPTED SOLUTION

Accepted Solutions
Super User III
Super User III

Re: Approach to generate a sample of records for each group of records in a table

You could use a pattern like the following to avoid duplicating code, you then just add to the list of years that you are generating over (or you could use the GENERATESERIES() function to generate a continuous list of years)

 

Sample Table = 
SELECTCOLUMNS(
	GENERATE( {2005,2006,2007},
		SAMPLE(
			10,
			FILTER('Consolidated Data', AND('Consolidated Data'[Year Commenced] = [VALUE], ISBLANK('Consolidated Data'[Year Completed]) = FALSE)),
			'Consolidated Data'[Student ID]
		)
	)
	, "Student ID"
	,[Student ID]
)

View solution in original post

1 REPLY 1
Super User III
Super User III

Re: Approach to generate a sample of records for each group of records in a table

You could use a pattern like the following to avoid duplicating code, you then just add to the list of years that you are generating over (or you could use the GENERATESERIES() function to generate a continuous list of years)

 

Sample Table = 
SELECTCOLUMNS(
	GENERATE( {2005,2006,2007},
		SAMPLE(
			10,
			FILTER('Consolidated Data', AND('Consolidated Data'[Year Commenced] = [VALUE], ISBLANK('Consolidated Data'[Year Completed]) = FALSE)),
			'Consolidated Data'[Student ID]
		)
	)
	, "Student ID"
	,[Student ID]
)

View solution in original post

Helpful resources

Announcements
Exclusive LIVE Community Event #3 – Ask Arun Anything

Exclusive LIVE Community Event #3 – Ask Arun Anything

Join us in the third Triple A event!

Meet the 2020 Season 1 Power BI Super Users!

Meet the 2020 Season 1 Power BI Super Users!

It’s the start of a new Super User season! Learn all about the new Super Users and brand-new tiered recognition system.

January 2020 Community Highlights

January 2020 Community Highlights

Make sure you didn't miss any of the things that happened in the community in January!

Top Solution Authors
Top Kudoed Authors