Per-Group Descriptive Statistics

13.3.1 Problem

You want to produce descriptive statistics for each subgroup of a set of observations.

13.3.2 Solution

Use aggregate functions, but employ a GROUP BY clause to arrange observations into the appropriate groups.

13.3.3 Discussion

The preceding section shows how to compute descriptive statistics for the entire set of scores in the testscore table. To be more specific, you can use GROUP BY to divide the observations into groups and calculate statistics for each of them. For example, the subjects in the testscore table are listed by age and sex, so it's possible to calculate similar statistics by age or sex (or both) by application of appropriate GROUP BY clauses.

By age:

mysql> SELECT age, COUNT(score) AS n, -> SUM(score) AS sum, -> MIN(score) AS minimum, -> MAX(score) AS maximum, -> AVG(score) AS mean, -> STD(score) AS 'std. dev.' -> FROM testscore -> GROUP BY age; +-----+---+------+---------+---------+--------+-----------+ | age | n | sum | minimum | maximum | mean | std. dev. | +-----+---+------+---------+---------+--------+-----------+ | 5 | 4 | 22 | 4 | 7 | 5.5000 | 1.1180 | | 6 | 4 | 27 | 4 | 9 | 6.7500 | 1.9203 | | 7 | 4 | 30 | 6 | 9 | 7.5000 | 1.1180 | | 8 | 4 | 32 | 6 | 10 | 8.0000 | 1.5811 | | 9 | 4 | 35 | 7 | 10 | 8.7500 | 1.0897 | +-----+---+------+---------+---------+--------+-----------+

By sex:

mysql> SELECT sex, COUNT(score) AS n, -> SUM(score) AS sum, -> MIN(score) AS minimum, -> MAX(score) AS maximum, -> AVG(score) AS mean, -> STD(score) AS 'std. dev.' -> FROM testscore -> GROUP BY sex; +-----+----+------+---------+---------+--------+-----------+ | sex | n | sum | minimum | maximum | mean | std. dev. | +-----+----+------+---------+---------+--------+-----------+ | M | 10 | 71 | 4 | 9 | 7.1000 | 1.7000 | | F | 10 | 75 | 4 | 10 | 7.5000 | 1.8574 | +-----+----+------+---------+---------+--------+-----------+

By age and sex:

mysql> SELECT age, sex, COUNT(score) AS n, -> SUM(score) AS sum, -> MIN(score) AS minimum, -> MAX(score) AS maximum, -> AVG(score) AS mean, -> STD(score) AS 'std. dev.' -> FROM testscore -> GROUP BY age, sex; +-----+-----+---+------+---------+---------+--------+-----------+ | age | sex | n | sum | minimum | maximum | mean | std. dev. | +-----+-----+---+------+---------+---------+--------+-----------+ | 5 | M | 2 | 9 | 4 | 5 | 4.5000 | 0.5000 | | 5 | F | 2 | 13 | 6 | 7 | 6.5000 | 0.5000 | | 6 | M | 2 | 17 | 8 | 9 | 8.5000 | 0.5000 | | 6 | F | 2 | 10 | 4 | 6 | 5.0000 | 1.0000 | | 7 | M | 2 | 14 | 6 | 8 | 7.0000 | 1.0000 | | 7 | F | 2 | 16 | 7 | 9 | 8.0000 | 1.0000 | | 8 | M | 2 | 15 | 6 | 9 | 7.5000 | 1.5000 | | 8 | F | 2 | 17 | 7 | 10 | 8.5000 | 1.5000 | | 9 | M | 2 | 16 | 7 | 9 | 8.0000 | 1.0000 | | 9 | F | 2 | 19 | 9 | 10 | 9.5000 | 0.5000 | +-----+-----+---+------+---------+---------+--------+-----------+

Категории