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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
amaan91
Helper I
Helper I

logical error in dynamic filtering for calculated tables using summarize

Hi All 

I have created a measure using summarize which dynamically calculates a list for last year and this works fine for all the filters. Still, i  am unable to filter it dynamically using the column u have created the filter for(Append1[CustomerList_Filtered]).  

if i insert Append1[CustomerList_Filtered] in the Allexcept condition  i am getting an error "The column 'CustomerList_Filtered' specified in the 'SUMMARIZE' function was not found in the input table."

amaan91_0-1734569358988.png

 



VAR My_table =
               SUMMARIZE (
        FILTER (
            ALLEXCEPT(  Append1 ,
                    Append1[Service Centre Name],
                    Append1[Channel V1] ,
                    Append1[NSO] ,
                    Append1[CustomerOrganisation],
                    Append1[Month No]
               
            ) ,
            Append1[StatusDateTime] >= start_Date_LY &&
            Append1[StatusDateTime] <= End_Date_LY
        )
            ,
        Append1[CustomerList_Filtered],
        "Accepted Jobs2", [Accepted Jobs.AG],
        "Accepted Revenue2", [Accepted Sales.AG]
    )
   
1 ACCEPTED SOLUTION

HI @v-shamiliv 

Apologies for the late reply , but i have magaed to resolve it myself.

The issue with the code was regardig data lineage calculated columns. 
work around was to created indipendant calculated coumns for the selections. 
Please find the updated code below . 

var Start_Date = FIRSTNONBLANK( 'Trading Days'[Date] , 'Trading Days'[Date] )
var start_Date_LY =  DATEADD( Start_Date , -1 ,  YEAR)

var End_Date =   LASTNONBLANK( 'Trading Days'[Date] , 'Trading Days'[Date] )
var End_Date_LY = DATEADD( End_Date , -1 ,  YEAR)

var Selected_Segment = SELECTEDVALUE( 'Customer Segmentation'[ID] , 0 )

 VAR My_table =
               SUMMARIZE ( Append1 ,
       
        Append1[CustomerList_Filtered],
        "Accepted Jobs2", [Accepted Jobs.AG],
        "Accepted Revenue2", [Accepted Sales.AG]
    )
   
                           
VAR final_IC =  FILTER ( My_table, [Accepted Jobs2] = 1  && [Accepted Revenue2] <= 3000 &&   Append1[CustomerList_Filtered] <> "NO NAME" )

VAR final_MSC =  FILTER ( My_table, [Accepted Jobs2] > 1 && [Accepted Revenue2] <= 3000 &&  Append1[CustomerList_Filtered] <> "NO NAME" )

VAR final_MC =FILTER ( My_table,  [Accepted Revenue2] > 3000 && [Accepted Revenue2] <= 12000 &&  Append1[CustomerList_Filtered] <> "NO NAME" )

VAR final_KC =  FILTER ( My_table,   [Accepted Revenue2] > 12000 &&  Append1[CustomerList_Filtered] <> "NO NAME" )

return
IF( Selected_Segment = 1 , SUMX(  final_IC , [Accepted Revenue2])  ,
IF( Selected_Segment = 2 ,  SUMX( final_MSC , [Accepted Revenue2]) ,
IF( Selected_Segment = 3 ,  SUMX( final_MC , [Accepted Revenue2]) ,
IF( Selected_Segment = 4 ,  SUMX( final_KC , [Accepted Revenue2]) ,
IF( Selected_Segment = 5 , SUMX( final_MSC , [Accepted Revenue2])+SUMX( final_MC , [Accepted Revenue2])+SUMX( final_KC , [Accepted Revenue2]) ,
SUMX( My_table , [Accepted Revenue2]  ) )
))))


FYI everything is based on only one fact table and there is no join between the fact table(Append1) and the refrence table(Customer Segmentation)

View solution in original post

11 REPLIES 11
v-shamiliv
Community Support
Community Support

Hi @amaan91 
can you please provide sample data?
Thank you

HI @v-shamiliv 

Apologies for the late reply , but i have magaed to resolve it myself.

The issue with the code was regardig data lineage calculated columns. 
work around was to created indipendant calculated coumns for the selections. 
Please find the updated code below . 

var Start_Date = FIRSTNONBLANK( 'Trading Days'[Date] , 'Trading Days'[Date] )
var start_Date_LY =  DATEADD( Start_Date , -1 ,  YEAR)

var End_Date =   LASTNONBLANK( 'Trading Days'[Date] , 'Trading Days'[Date] )
var End_Date_LY = DATEADD( End_Date , -1 ,  YEAR)

var Selected_Segment = SELECTEDVALUE( 'Customer Segmentation'[ID] , 0 )

 VAR My_table =
               SUMMARIZE ( Append1 ,
       
        Append1[CustomerList_Filtered],
        "Accepted Jobs2", [Accepted Jobs.AG],
        "Accepted Revenue2", [Accepted Sales.AG]
    )
   
                           
VAR final_IC =  FILTER ( My_table, [Accepted Jobs2] = 1  && [Accepted Revenue2] <= 3000 &&   Append1[CustomerList_Filtered] <> "NO NAME" )

VAR final_MSC =  FILTER ( My_table, [Accepted Jobs2] > 1 && [Accepted Revenue2] <= 3000 &&  Append1[CustomerList_Filtered] <> "NO NAME" )

VAR final_MC =FILTER ( My_table,  [Accepted Revenue2] > 3000 && [Accepted Revenue2] <= 12000 &&  Append1[CustomerList_Filtered] <> "NO NAME" )

VAR final_KC =  FILTER ( My_table,   [Accepted Revenue2] > 12000 &&  Append1[CustomerList_Filtered] <> "NO NAME" )

return
IF( Selected_Segment = 1 , SUMX(  final_IC , [Accepted Revenue2])  ,
IF( Selected_Segment = 2 ,  SUMX( final_MSC , [Accepted Revenue2]) ,
IF( Selected_Segment = 3 ,  SUMX( final_MC , [Accepted Revenue2]) ,
IF( Selected_Segment = 4 ,  SUMX( final_KC , [Accepted Revenue2]) ,
IF( Selected_Segment = 5 , SUMX( final_MSC , [Accepted Revenue2])+SUMX( final_MC , [Accepted Revenue2])+SUMX( final_KC , [Accepted Revenue2]) ,
SUMX( My_table , [Accepted Revenue2]  ) )
))))


FYI everything is based on only one fact table and there is no join between the fact table(Append1) and the refrence table(Customer Segmentation)

v-shamiliv
Community Support
Community Support

Hi @amaan91 
Could you please confirm whether this data is connected to a live query or if it is connected to import mode/Excel?

The data is connected from SQL server and not a direct query. 

v-shamiliv
Community Support
Community Support

Hi @amaan91 
I hope this information is helpful. Please let me know if you have any further questions or if you'd like to discuss this further. If this answers your question, please Accept it as a solution and give it a 'Kudos' so others can find it easily.
Thank you.

Hi 

Thank you for the reply, but I am trying to generate a dynamic virtual table that will react to the filters. 


 

v-shamiliv
Community Support
Community Support

Hi @amaan91 
We haven’t heard back since our last response and wanted to check if your query has been resolved. If not, please feel free to reach out for further assistance. If it has been resolved, kindly mark the helpful reply as the solution to make it easier for others to find. A kudos would also be greatly appreciated!
Thank you.

v-shamiliv
Community Support
Community Support

Hi @amaan91 
Thank you for your patience.please let us know if anything was helpful to you, so that we can convert it into a formal answer. If so, we would appreciate it if you could Accept it as a solution and drop a 'Kudos' so other members can find it more easily.
Thank you.

v-shamiliv
Community Support
Community Support

Hi @amaan91,

Thank you for reaching out on the Microsoft Fabric Community Forum!


I’ve created a PBIX file using some sample data and executed the code you mentioned. It worked fine on my end. Please find the attached PBIX file for your reference.

Let me know if you need further assistance!

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

Thank you.

 

Dangar332
Super User
Super User

Hi ,@amaan91 

Since the measure accept a scalar value and the above code you have provided returns a table, the code you supplied above is unacceptable in the measure. Could you please supply the entire measure code?

 

Hi @Dangar332 

please find below the full code


var Start_Date = DATEADD( FIRSTNONBLANK( 'Trading Days'[Date] , 'Trading Days'[Date] ) , -1 , YEAR)
var start_Date_LY =  DATEADD( Start_Date , -1 ,  YEAR)

var End_Date =  DATEADD( LASTNONBLANK( 'Trading Days'[Date] , 'Trading Days'[Date] ) , -1, YEAR)
var End_Date_LY = DATEADD( End_Date , -1 ,  YEAR)

var Selected_Segment = SELECTEDVALUE( 'Customer Segmentation'[ID] , 0 )


 VAR My_table =
               SUMMARIZE (
        FILTER (
            ALLEXCEPT(  Append1 ,
                    Append1[Service Centre Name],
                    Append1[Channel V1] ,
                    Append1[NSO] ,
                    Append1[Month No] ,
                    Append1[CustomerOrganisation]
                 
               
            ) ,
            Append1[StatusDateTime] >= Start_Date &&
            Append1[StatusDateTime] <= End_Date
        )
            ,
        Append1[CustomerList_Filtered],
        "Accepted Jobs2", [Accepted Jobs.AG],
        "Accepted Revenue2", [Accepted Sales.AG]
    )
   
                           
VAR final_IC =  FILTER (  My_table   , [Accepted Jobs2] = 1  && [Accepted Revenue2] <= 3000 &&   Append1[CustomerList_Filtered] <> "NO NAME" )

VAR final_MSC =  FILTER ( My_table, [Accepted Jobs2] > 1 && [Accepted Revenue2] <= 3000 &&  Append1[CustomerList_Filtered] <> "NO NAME" )

VAR final_MC =FILTER ( My_table,  [Accepted Revenue2] > 3000 && [Accepted Revenue2] <= 12000 &&  Append1[CustomerList_Filtered] <> "NO NAME" )

VAR final_KC =  FILTER ( My_table,   [Accepted Revenue2] > 12000 &&  Append1[CustomerList_Filtered] <> "NO NAME" )

return
IF( Selected_Segment = 1 , SUMX(  final_IC , [Accepted Revenue2])  ,
IF( Selected_Segment = 2 ,  SUMX( final_MSC , [Accepted Revenue2]) ,
IF( Selected_Segment = 3 ,  SUMX( final_MC , [Accepted Revenue2]) ,
IF( Selected_Segment = 4 ,  SUMX( final_KC , [Accepted Revenue2]) ,
IF( Selected_Segment = 5 , SUMX( final_MSC , [Accepted Revenue2])+SUMX( final_MC , [Accepted Revenue2])+SUMX( final_KC , [Accepted Revenue2]) ,
SUMX( My_table , [Accepted Revenue2]  ) )
))))

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

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