Oracle® Database SQL Reference 10g Release 1 (10.1) Part Number B10759-01 |
|
|
View PDF |
COVAR_POP
returns the population covariance of a set of number pairs. You can use it as an aggregate or analytic function.
This function takes as arguments any numeric datatype or any nonnumeric datatype that can be implicitly converted to a numeric datatype. Oracle determines the argument with the highest numeric precedence, implicitly converts the remaining arguments to that datatype, and returns that datatype.
See Also: Table 2-11, "Implicit Type Conversion Matrix" for more information on implicit conversion and "Numeric Precedence " for information on numeric precedence |
Oracle Database applies the function to the set of (expr1
, expr2
) pairs after eliminating all pairs for which either expr1
or expr2
is null. Then Oracle makes the following computation:
(SUM(expr1 * expr2) - SUM(expr2) * SUM(expr1) / n) / n
where n
is the number of (expr1
, expr2
) pairs where neither expr1
nor expr2
is null.
The function returns a value of type NUMBER
. If the function is applied to an empty set, then it returns null.
See Also: "About SQL Expressions " for information on valid forms ofexpr and "Aggregate Functions " |
The following example calculates the population covariance for the sales revenue amount and the units sold for each year from the sample table sh.sales
:
SELECT t.calendar_month_number, COVAR_POP(s.amount_sold, s.quantity_sold) AS covar_pop, COVAR_SAMP(s.amount_sold, s.quantity_sold) AS covar_samp FROM sales s, times t WHERE s.time_id = t.time_id AND t.calendar_year = 1998 GROUP BY t.calendar_month_number; CALENDAR_MONTH_NUMBER COVAR_POP COVAR_SAMP --------------------- ---------- ---------- 1 5437.68586 5437.88704 2 5923.72544 5923.99139 3 6040.11777 6040.38623 4 5946.67897 5946.92754 5 5986.22483 5986.4463 6 5726.79371 5727.05703 7 5491.65269 5491.9239 8 5672.40362 5672.66882 9 5741.53626 5741.80025 10 5050.5683 5050.78195 11 5256.50553 5256.69145 12 5411.2053 5411.37709
The following example calculates cumulative sample covariance of the list price and minimum price of the products in the sample schema oe
:
SELECT product_id, supplier_id, COVAR_POP(list_price, min_price) OVER (ORDER BY product_id, supplier_id) AS CUM_COVP, COVAR_SAMP(list_price, min_price) OVER (ORDER BY product_id, supplier_id) AS CUM_COVS FROM product_information p WHERE category_id = 29 ORDER BY product_id, supplier_id; PRODUCT_ID SUPPLIER_ID CUM_COVP CUM_COVS ---------- ----------- ---------- ---------- 1774 103088 0 1775 103087 1473.25 2946.5 1794 103096 1702.77778 2554.16667 1825 103093 1926.25 2568.33333 2004 103086 1591.4 1989.25 2005 103086 1512.5 1815 2416 103088 1475.97959 1721.97619 . . .