Login     Register

        Contact Us     Search

XLeratorDB/statistics Documentation

SQL Server chi-squared statistic for normalized data


CHISQN2_q

Updated: 6 August 2010

Use CHISQN2_q to calculate the chi-square (χ2) statistic for normalized tables. This function calculates the chi-square statistic by finding the difference between each observed and theoretical frequency for each possible outcome, squaring them, dividing each by the theoretical frequency, and taking the sum of the results. A second important part of determining the test statistic is to define the degrees of freedom of the test: this is essentially the number of squares errors involving the observed frequencies adjusted for the effect of using some of those observations to define the expected frequencies.
 
CHISQN2_q requires the expected results as input to the function.
 
The value of the chi-square statistic is:


 
Where
                r              is the number of rows
                c              is the number of columns
                O             is the Observed result
                E              is the Expected result
 
Syntax
SELECT [wctStatistics].[wct].[CHISQN2_q] (
  <@Actual_range_RangeQuery, nvarchar(max),>
 ,<@Expected_range_RangeQuery, nvarchar(max),>
 ,<@CompareByKeys, bit,>)
Arguments
@Actual_range_RangeQuery
the select statement, as text, used to determine the actual, or observed, results to be used in the calculation.
@Expected_range_RangeQuery
the select statement, as text, used to determine the expected results to be used in the calculation.
@CompareByKeys
A bit value (True/False) that tells the function to use the relative position (False) or the column names (True) when comparing the observed and the expected results.
Return Types
float
Remarks
·         CHISQN2_q is designed for normalized tables. For de-normalized tables, use the CHISQ2_q function.
·         CHISQN2_q requires the expected results as input. To calculate the chi-squared statistic without entering the expected results, use the CHISQN_q function.
·         For simpler queries, consider using the CHISQN2 function.
·         No GROUP BY is required for this function even though it produces aggregated results.
Examples
In this hypothetical situation, we want to determine if there is an association between population density and the preference for a sport from among baseball, football, and basketball. We will use the CHISQN2_q function to calculate the chi-squared statistic.
CREATE TABLE #O (
      [Sport]     [varchar] (20) NOT NULL,
      [Locale]    [varchar] (20) NOT NULL,
      [Result]    [float] NOT NULL
)
INSERT INTO #O VALUES ('Basketball', 'Rural', 28)
INSERT INTO #O VALUES ('Basketball', 'Suburban', 35)
INSERT INTO #O VALUES ('Basketball', 'Urban', 54)
INSERT INTO #O VALUES ('Baseball', 'Rural', 60)
INSERT INTO #O VALUES ('Baseball', 'Suburban', 43)
INSERT INTO #O VALUES ('Baseball', 'Urban', 35)
INSERT INTO #O VALUES ('Football', 'Rural', 52)
INSERT INTO #O VALUES ('Football', 'Suburban', 48)
INSERT INTO #O VALUES ('Football', 'Urban', 28)
 
CREATE TABLE #E (
      [Sport]     [varchar] (20) NOT NULL,
      [Locale]    [varchar] (20) NOT NULL,
      [Result]    [float] NOT NULL
)
INSERT INTO #E VALUES ('Basketball', 'Rural', 42.77)
INSERT INTO #E VALUES ('Basketball', 'Suburban', 38.49)
INSERT INTO #E VALUES ('Basketball', 'Urban', 35.74)
INSERT INTO #E VALUES ('Baseball', 'Rural', 50.44)
INSERT INTO #E VALUES ('Baseball', 'Suburban', 45.4)
INSERT INTO #E VALUES ('Baseball', 'Urban', 42.16)
INSERT INTO #E VALUES ('Football', 'Rural', 46.79)
INSERT INTO #E VALUES ('Football', 'Suburban', 42.11)
INSERT INTO #E VALUES ('Football', 'Urban', 39.1)
 
SELECT wct.CHISQN2_q(
 'SELECT * FROM #O'
,'SELECT * FROM #E'
,'True')
 
This produces the following result
----------------------
22.4562079299414
 
(1 row(s) affected)
We could have also invoked the function by passing the data directly to it.
SELECT wct.CHISQN2_q (
'SELECT ''Basketball'', ''Rural'', 28 UNION ALL
 SELECT ''Basketball'', ''Suburban'', 35 UNION ALL
 SELECT ''Basketball'', ''Urban'', 54 UNION ALL
 SELECT ''Baseball'', ''Rural'', 60 UNION ALL
 SELECT ''Baseball'', ''Suburban'', 43 UNION ALL
 SELECT ''Baseball'', ''Urban'', 35 UNION ALL
 SELECT ''Football'', ''Rural'', 52 UNION ALL
 SELECT ''Football'', ''Suburban'', 48 UNION ALL
 SELECT ''Football'', ''Urban'', 28'
,'SELECT ''Basketball'', ''Rural'', 42.77 UNION ALL
 SELECT ''Basketball'', ''Suburban'', 38.49 UNION ALL
 SELECT ''Basketball'', ''Urban'', 35.74 UNION ALL
 SELECT ''Baseball'', ''Rural'', 50.44 UNION ALL
 SELECT ''Baseball'', ''Suburban'', 45.4 UNION ALL
 SELECT ''Baseball'', ''Urban'', 42.16 UNION ALL
 SELECT ''Football'', ''Rural'', 46.79 UNION ALL
 SELECT ''Football'', ''Suburban'', 42.11 UNION ALL
 SELECT ''Football'', ''Urban'', 39.1'
,'True')
 
This produces the following result
 
----------------------
22.4562079299414
 

(1 row(s) affected)



Copyright 2008-2024 Westclintech LLC         Privacy Policy        Terms of Service