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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
Corey-Flinders
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
d_gosbell
Super User
Super User

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
d_gosbell
Super User
Super User

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]
)

Helpful resources

Announcements
March Fabric Community Update

Fabric Community Update - March 2024

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

Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.