Logo

MovingSTEYX

Updated 2023-11-13 21:49:23.613000

Syntax

SELECT [westclintech].[wct].[MovingSTEYX](
  <@Y, float,>
 ,<@X, float,>
 ,<@Offset, int,>
 ,<@RowNum, int,>
 ,<@Id, tinyint,>)

Description

Use the scalar function MovingSTEYX function to calculate the standard error of the predicted y-value for each x in a regression within a resultant table or partition, without the need for a self-join. The standard error value is calculated for each value from the first value in the window to the last value in the window. If the column values are presented to the functions out of order, an error message will be generated.

Arguments

@Id

a unique identifier for the MovingSTEYX calculation. @Id allows you to specify multiple MovingSTEYX calculations within a resultant table. @Id is an expression of type tinyint or of a type that can be implicitly converted to tinyint.

@Offset

specifies the window size. @Offset is an expression of type int or of a type that can be implicitly converted to int.

@RowNum

the number of the row within the group for which the sum is being calculated. If @RowNum for the current row in a set is less than or equal to the previous @RowNum and @RowNum is not equal to 1, an error message will be generated. @RowNum is an expression of type int or of a type that can be implicitly converted to int.

@X

the x-value passed into the function. @X is an expression of type float or of a type that can be implicitly converted to float.

@Y

the y-value passed into the function. @Y is an expression of type float or of a type that can be implicitly converted to float.

Return Type

float

Remarks

If @Id is NULL then @Id = 0.

@RowNum must be in ascending order.

To calculate moving standard error from the beginning of a dataset or a partition, use the RunningSTEYX function.

If @RowNum = 1 then MovingSTEYX is NULL.

There may be cases where the order in which the data are returned to the function and the order in which the results are returned are different, generally due to parallelism. You can use OPTION(MAXDOP 1) or OPTION(MAXDOP 1,FORCE ORDER) to help eliminate this problem

Examples

In this example we will calculate the standard error in the relationship between square footage and house prices with a window of 5 rows. We will create a temporary table, #se, populate it with some data and then run the SELECT.

--Create the temporary table

CREATE TABLE #se

(

    rn int,

    id_lot int,

    amt_sqft int,

    amt_price int,

    PRIMARY KEY (rn)

);

--Put some date in the table

INSERT INTO #se

VALUES

(1, 21783, 1147, 393918);

INSERT INTO #se

VALUES

(2, 94729, 1313, 470479);

INSERT INTO #se

VALUES

(3, 33028, 1433, 512474);

INSERT INTO #se

VALUES

(4, 59446, 1724, 610477);

INSERT INTO #se

VALUES

(5, 97646, 1162, 388196);

INSERT INTO #se

VALUES

(6, 44823, 1813, 636916);

INSERT INTO #se

VALUES

(7, 88397, 1105, 374348);

INSERT INTO #se

VALUES

(8, 13588, 1555, 559149);

INSERT INTO #se

VALUES

(9, 13891, 1775, 623900);

INSERT INTO #se

VALUES

(10, 90957, 1585, 563947);

INSERT INTO #se

VALUES

(11, 44167, 1510, 529806);

INSERT INTO #se

VALUES

(12, 75533, 1628, 592533);

INSERT INTO #se

VALUES

(13, 56812, 1145, 408634);

INSERT INTO #se

VALUES

(14, 12897, 1632, 589522);

INSERT INTO #se

VALUES

(15, 93826, 1850, 668852);

INSERT INTO #se

VALUES

(16, 74510, 1867, 633400);

INSERT INTO #se

VALUES

(17, 17262, 1587, 552178);

INSERT INTO #se

VALUES

(18, 30929, 1809, 633141);

INSERT INTO #se

VALUES

(19, 49030, 1521, 555713);

INSERT INTO #se

VALUES

(20, 33431, 1195, 434542);

--Calculate STEYX

SELECT id_lot,

       amt_sqft,

       amt_price,

       wct.MovingSTEYX(amt_price, amt_sqft, 4, ROW_NUMBER() OVER (ORDER BY amt_sqft)

                 , NULL) as STEYX

FROM #se

ORDER BY amt_sqft;

--Clean up

DROP TABLE #se;

This produces the following result.

{"columns":[{"field":"id_lot","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"},{"field":"amt_sqft","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"},{"field":"amt_price","headerClass":"ag-right-aligned-header","cellClass":"ag-right-aligned-cell"},{"field":"STEYX"}],"rows":[{"id_lot":"88397","amt_sqft":"1105","amt_price":"374348","STEYX":"NULL"},{"id_lot":"56812","amt_sqft":"1145","amt_price":"408634","STEYX":"NULL"},{"id_lot":"21783","amt_sqft":"1147","amt_price":"393918","STEYX":"11324.5106146064"},{"id_lot":"97646","amt_sqft":"1162","amt_price":"388196","STEYX":"13814.6464073859"},{"id_lot":"33431","amt_sqft":"1195","amt_price":"434542","STEYX":"13808.1748717594"},{"id_lot":"94729","amt_sqft":"1313","amt_price":"470479","STEYX":"14707.4090820442"},{"id_lot":"33028","amt_sqft":"1433","amt_price":"512474","STEYX":"13842.033847512"},{"id_lot":"44167","amt_sqft":"1510","amt_price":"529806","STEYX":"15324.6983801421"},{"id_lot":"49030","amt_sqft":"1521","amt_price":"555713","STEYX":"9270.74078611125"},{"id_lot":"13588","amt_sqft":"1555","amt_price":"559149","STEYX":"9014.60375801778"},{"id_lot":"90957","amt_sqft":"1585","amt_price":"563947","STEYX":"9301.64582952582"},{"id_lot":"17262","amt_sqft":"1587","amt_price":"552178","STEYX":"11486.3605879237"},{"id_lot":"75533","amt_sqft":"1628","amt_price":"592533","STEYX":"12498.1629504527"},{"id_lot":"12897","amt_sqft":"1632","amt_price":"589522","STEYX":"10213.0540677386"},{"id_lot":"59446","amt_sqft":"1724","amt_price":"610477","STEYX":"11625.4481785994"},{"id_lot":"13891","amt_sqft":"1775","amt_price":"623900","STEYX":"12241.4632738191"},{"id_lot":"30929","amt_sqft":"1809","amt_price":"633141","STEYX":"2076.90766493355"},{"id_lot":"44823","amt_sqft":"1813","amt_price":"636916","STEYX":"1800.15275997456"},{"id_lot":"93826","amt_sqft":"1850","amt_price":"668852","STEYX":"8987.1902646192"},{"id_lot":"74510","amt_sqft":"1867","amt_price":"633400","STEYX":"16565.2113914595"}]}