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

Grow your Fabric skills and prepare for the DP-600 certification exam by completing the latest Microsoft Fabric challenge.

Reply
cgrimes
Advocate II
Advocate II

Error MDXScript(model)(201,9) with LINESTX in DAX Formula

I am working on a DAX formula in Power BI to perform a linear regression analysis using the LINESTX function. The goal is to predict next month's sales based on several variables from previous data. However, I am encountering an error: MDXScript(model)(201,9) when I try to run my formula. Below is the DAX formula I am using:

 

 

 

Next Month Fill2 = 

VAR Fit = LINESTX(
    CALCULATETABLE(
        SUMMARIZECOLUMNS(
            'Date Master'[FirstOfMonth],
            "Sales", SUM('Data Sales'[Net Amount (USD)]),
            "WDays", SUM('Date Master'[WorkDay]),
            "RRS", CALCULATE([d day $ RRQR per Workday], 'Measures MMT'[Catagory] = "Sales"),
            "SoMLBL", [start of month latBL]^.5,
            "SoMOD", [StartOfMonthOrdersDue]
        ),
        ALL('Date Master'),
        'Date Master'[FirstOfMonth] >= EOMONTH(MIN(TODAY(),MAX('Date Master'[Date])), -14) + 1,
        'Date Master'[FirstOfMonth] <= EOMONTH(MIN(TODAY(),MAX('Date Master'[Date])), -2) + 1
    )    ,
        [Sales],
        [WDays],
        [RRS],
        [SoMLBL],
        [SoMOD]
    )

VAR Slope1 = SELECTCOLUMNS( Fit , [Slope1])
VAR Slope2 = SELECTCOLUMNS( Fit , [Slope2])
VAR Slope3 = SELECTCOLUMNS( Fit , [Slope3])
VAR Slope4 = SELECTCOLUMNS( Fit , [Slope4])
VAR Intercept = SELECTCOLUMNS( Fit , [Intercept])
VAR x1 = CALCULATE(SUM('Date Master'[WorkDay]))
VAR x2 = CALCULATE(
    [d day $ RRQR per Workday],
    'Measures MMT'[Catagory] = "Sales",
    PREVIOUSMONTH('Date Master'[Date])
)
VAR x3 = [start of month latBL]^.5
VAR x4 = [StartOfMonthOrdersDue]
VAR y = Slope1 * x1 + Slope2 * x2 + Slope3 * x3 + Slope4 * x4 + Intercept

RETURN
y

 

 

I would greatly appreciate any insight into what might be causing this error and how I can resolve it. Thank you in advance for your help!


1 ACCEPTED SOLUTION

well, it was a weird fix, it did not like that I was using summarizecolumns, had to change to summarize 

Next Month Fill2 = 

VAR Fit = LINESTX(
    CALCULATETABLE(
        SUMMARIZE(
            'Date Master',
            'Date Master'[FirstOfMonth],
            "Sales", SUM('Data Sales'[Net Amount (USD)]),
            "WDays", SUM('Date Master'[WorkDay]),
            "RRS", CALCULATE([d day $ RRQR per Workday], 'Measures MMT'[Catagory] = "Sales"),
            "SoMLBL", [start of month latBL]^.5,
            "SoMOD", [StartOfMonthOrdersDue]
        ),
        ALL('Date Master'),
        'Date Master'[FirstOfMonth] >= EOMONTH(MIN(TODAY(),MAX('Date Master'[Date])), -14) + 1,
        'Date Master'[FirstOfMonth] <= EOMONTH(MIN(TODAY(),MAX('Date Master'[Date])), -2) + 1
    )    ,
        [Sales],
        [WDays],
        [RRS],
        [SoMLBL],
        [SoMOD]
    )

VAR Slope1 = SELECTCOLUMNS( Fit , [Slope1])
VAR Slope2 = SELECTCOLUMNS( Fit , [Slope2])
VAR Slope3 = SELECTCOLUMNS( Fit , [Slope3])
VAR Slope4 = SELECTCOLUMNS( Fit , [Slope4])
VAR Intercept = SELECTCOLUMNS( Fit , [Intercept])
VAR x1 = CALCULATE(SUM('Date Master'[WorkDay]))
VAR x2 = CALCULATE(
    [d day $ RRQR per Workday],
    'Measures MMT'[Catagory] = "Sales",
    PREVIOUSMONTH('Date Master'[Date])
)
VAR x3 = [start of month latBL]^.5
VAR x4 = [StartOfMonthOrdersDue]
VAR y = Slope1 * x1 + Slope2 * x2 + Slope3 * x3 + Slope4 * x4 + Intercept

RETURN
y



View solution in original post

3 REPLIES 3
Sahir_Maharaj
Super User
Super User

Hello @cgrimes,

 

The SELECTCOLUMNS function returns a table, not a single scalar value. So, when you use:

VAR Slope1 = SELECTCOLUMNS( Fit , [Slope1])

When you use Slope1 * x1 further in your formula, this might be causing an error as you can't multiply a table directly with a scalar value. To get the actual value, you may need to do something like:

VAR Slope1 = SUMX(SELECTCOLUMNS( Fit , [Slope1]), [Slope1])

Should you require any further assistance, please do not hesitate to reach out to me.


Did I answer your question? Mark my post as a solution, this will help others!

If my response(s) assisted you in any way, don't forget to drop me a "Kudos" 🙂

Kind Regards,
Sahir Maharaj
Data Scientist | Data Engineer | Data Analyst | AI Engineer
P.S. Want me to build your Power BI solution?
➤ Lets connect on LinkedIn: Join my network of 13K+ professionals
➤ Join my free newsletter: Data Driven: From 0 to 100
➤ Website: https://sahirmaharaj.com
➤ Email: sahir@sahirmaharaj.com
➤ Want me to build your Power BI solution? Lets chat about how I can assist!
➤ Join my Medium community of 30K readers! Sharing my knowledge about data science and artificial intelligence
➤ Explore my latest project (350K+ views): Wordlit.net
➤ 100+ FREE Power BI Themes: Download Now
LinkedIn Top Voice in Artificial Intelligence, Data Science and Machine Learning

I got the same error,

 

I have a diferent version that was working but behaving unexpectedly when filtered on the date table.

it used the selectcolumn() without issue.

Next Month Fill = 

VAR Fit = LINESTX(
    CALCULATETABLE(
        VALUES('Date Master'[FirstOfMonth]),
        ALLSELECTED('Date Master'),
        'Date Master'[FirstOfMonth] >= EOMONTH(MAX('Date Master'[Date]), -14) + 1,
        'Date Master'[FirstOfMonth] <= EOMONTH(MAX('Date Master'[Date]), -2)+1
       
    ),
    VAR CurrentFirstOfMonth = 'Date Master'[FirstOfMonth] -- Capture the current [FirstOfMonth] value
    RETURN
        CALCULATE(
            SUM('Data Sales'[Net Amount (USD)]),
            ALLSELECTED('Date Master'),
            'Date Master'[FirstOfMonth] = CurrentFirstOfMonth
        ),
    VAR CurrentFirstOfMonth = 'Date Master'[FirstOfMonth] -- Capture the current [FirstOfMonth] value
    RETURN
        CALCULATE(
            SUM('Date Master'[WorkDay]),
            ALLSELECTED('Date Master'),
            'Date Master'[FirstOfMonth] = CurrentFirstOfMonth
        ),
    VAR CurrentFirstOfMonth = EDATE('Date Master'[FirstOfMonth],-1)-- Capture the current [FirstOfMonth] value
    RETURN
        CALCULATE(
            [d day $ RRQR per Workday],
            'Measures MMT'[Catagory] = "Sales",
            ALLSELECTED('Date Master'),
            'Date Master'[FirstOfMonth] = CurrentFirstOfMonth
        ),
    VAR CurrentFirstOfMonth = 'Date Master'[FirstOfMonth] -- Capture the current [FirstOfMonth] value
    RETURN
        CALCULATE(
            [start of month latBL]^.5,
            ALLSELECTED('Date Master'),
            'Date Master'[FirstOfMonth] = CurrentFirstOfMonth
        ),
    VAR CurrentFirstOfMonth = 'Date Master'[FirstOfMonth] -- Capture the current [FirstOfMonth] value
    RETURN
        CALCULATE(
    [StartOfMonthOrdersDue],
            ALLSELECTED('Date Master'),
            'Date Master'[FirstOfMonth] = CurrentFirstOfMonth
        )

)

VAR Slope1 = SELECTCOLUMNS( Fit , [Slope1])
VAR Slope2 = SELECTCOLUMNS( Fit , [Slope2])
VAR Slope3 = SELECTCOLUMNS( Fit , [Slope3])
VAR Slope4 = SELECTCOLUMNS( Fit , [Slope4])
VAR Intercept = SELECTCOLUMNS( Fit , [Intercept])
VAR x1 = CALCULATE(SUM('Date Master'[WorkDay]))
VAR x2 = CALCULATE(
    [d day $ RRQR per Workday],
    'Measures MMT'[Catagory] = "Sales",
    PREVIOUSMONTH('Date Master'[Date])
)
VAR x3 = [start of month latBL]^.5
VAR x4 = [StartOfMonthOrdersDue]
VAR y = Slope1 * x1 + Slope2 * x2 + Slope3 * x3 + Slope4 * x4 + Intercept

RETURN
y





 

well, it was a weird fix, it did not like that I was using summarizecolumns, had to change to summarize 

Next Month Fill2 = 

VAR Fit = LINESTX(
    CALCULATETABLE(
        SUMMARIZE(
            'Date Master',
            'Date Master'[FirstOfMonth],
            "Sales", SUM('Data Sales'[Net Amount (USD)]),
            "WDays", SUM('Date Master'[WorkDay]),
            "RRS", CALCULATE([d day $ RRQR per Workday], 'Measures MMT'[Catagory] = "Sales"),
            "SoMLBL", [start of month latBL]^.5,
            "SoMOD", [StartOfMonthOrdersDue]
        ),
        ALL('Date Master'),
        'Date Master'[FirstOfMonth] >= EOMONTH(MIN(TODAY(),MAX('Date Master'[Date])), -14) + 1,
        'Date Master'[FirstOfMonth] <= EOMONTH(MIN(TODAY(),MAX('Date Master'[Date])), -2) + 1
    )    ,
        [Sales],
        [WDays],
        [RRS],
        [SoMLBL],
        [SoMOD]
    )

VAR Slope1 = SELECTCOLUMNS( Fit , [Slope1])
VAR Slope2 = SELECTCOLUMNS( Fit , [Slope2])
VAR Slope3 = SELECTCOLUMNS( Fit , [Slope3])
VAR Slope4 = SELECTCOLUMNS( Fit , [Slope4])
VAR Intercept = SELECTCOLUMNS( Fit , [Intercept])
VAR x1 = CALCULATE(SUM('Date Master'[WorkDay]))
VAR x2 = CALCULATE(
    [d day $ RRQR per Workday],
    'Measures MMT'[Catagory] = "Sales",
    PREVIOUSMONTH('Date Master'[Date])
)
VAR x3 = [start of month latBL]^.5
VAR x4 = [StartOfMonthOrdersDue]
VAR y = Slope1 * x1 + Slope2 * x2 + Slope3 * x3 + Slope4 * x4 + Intercept

RETURN
y



Helpful resources

Announcements
RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.

MayPowerBICarousel1

Power BI Monthly Update - May 2024

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

Europe Fabric Conference

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.