Groupwise Anomaly Detection with SQL

Overview

I’m going to demonstrate a straightforward anomaly detection procedure using a limited toolset: SQLite. Given the limited toolset, the algorithm must use nothing more than fundamental statistics (avg, variance, z-score) to identify atypical, anomalous events. We will be taking a step-by-step approach to build up the SQL query incrementally.

So, imagine you are monitoring some thing, taking multiple observations of various metrics. This could be:

  • Account balances
  • Heart rate and blood pressure of a patient
  • CPU and memory utilization of a server

The goal is to identify when a anomaly, an outlier, an oddball occurs.

The dataset

This exact method imposes some requirements on the dataset. The dataset we’ll be using is stored in a SQLite table with the following columns:

  • ts
  • group_name
  • metric
  • value

ts is for timestamp, and it is expressed in unix time. That is, the number of seconds since January 1, 1970. This allows for easy date arithmetic and efficient date comparisons.

In this dataset, there are two groups and two metrics, with an observation recorded in the events table every five minutes. There is one row for each observation, so four rows for each observation period.

SELECT
  datetime(ts, 'unixepoch', 'localtime') as ts_local,
  ts,
  group_name,
  metric,
  value
FROM events

Top 12 rows:

ts_localtsgroup_namemetricvalue
2018-12-22 00:00:001545458400Group AMetric 1222.24127
2018-12-22 00:00:001545458400Group BMetric 1252.97452
2018-12-22 00:00:001545458400Group AMetric 234.57067
2018-12-22 00:00:001545458400Group BMetric 238.94976
2018-12-22 00:05:001545458700Group AMetric 1253.60885
2018-12-22 00:05:001545458700Group BMetric 1200.50453
2018-12-22 00:05:001545458700Group AMetric 232.67214
2018-12-22 00:05:001545458700Group BMetric 235.75465
2018-12-22 00:10:001545459000Group AMetric 1231.62960
2018-12-22 00:10:001545459000Group BMetric 1225.97594
2018-12-22 00:10:001545459000Group AMetric 241.10389
2018-12-22 00:10:001545459000Group BMetric 236.27989

If you’d like, skip the explanation; get to the query.

Essential statistics

To compute the Z-score for each point, we will need the window average and variance. We will build up to these stats using the window count mov_n, window sum mov_sum, and window sum squared mov_sum_sq.

Since SQLite lacks functions for these window operations, they will instead be calculated after performing a self-join of the table on the ts column. Here you can define the window size, in seconds, by subtracting a number of seconds from the timestamp of each point. Each point then has a unique set of observations from which to calculate the average and variance for. In this example, the window size is 10800 seconds, or 3 hours.

SELECT
  t1.ts,
  t1.group_name,
  t1.metric,
  t1.value,
  count(t2.value) AS mov_n,
  sum(t2.value) AS mov_sum,
  sum(t2.value*t2.value) AS mov_sum_sq
FROM events t1 LEFT JOIN events t2
  ON t1.group_name = t2.group_name
  AND t1.metric = t2.metric
  AND t2.ts >= t1.ts - 10800
  AND t2.ts < t1.ts
GROUP BY t1.ts,
  t1.group_name,
  t1.metric,
  t1.value

Top 16 rows:

tsgroup_namemetricvaluemov_nmov_summov_sum_sq
1545458400Group AMetric 1222.241270NANA
1545458400Group AMetric 234.570670NANA
1545458400Group BMetric 1252.974520NANA
1545458400Group BMetric 238.949760NANA
1545458700Group AMetric 1253.608851222.2412749391.182
1545458700Group AMetric 232.67214134.570671195.131
1545458700Group BMetric 1200.504531252.9745263996.105
1545458700Group BMetric 235.75465138.949761517.083
1545459000Group AMetric 1231.629602475.85012113708.631
1545459000Group AMetric 241.10389267.242812262.600
1545459000Group BMetric 1225.975942453.47904104198.170
1545459000Group BMetric 236.27989274.704402795.478
1545459300Group AMetric 1245.584833707.47972167360.904
1545459300Group AMetric 229.744863108.346713952.130
1545459300Group BMetric 1239.159603679.45498155263.294
1545459300Group BMetric 236.642983110.984294111.709

Notice how the first few rows are missing some values. Also, mov_n, the number of observations in the moving window, is 0. This is because each observation computes the stats for a window of observations that occured before it. Starting out, there are no past events to aggregate. As we proceed, the window grows incrementally larger until a “complete” window is obtained. See the last 12 observations:

tsgroup_namemetricvaluemov_nmov_summov_sum_sq
1545543900Group AMetric 1247.15789368354.3901950818.35
1545543900Group AMetric 228.81865361236.08842684.47
1545543900Group BMetric 1221.85380368209.6071880259.07
1545543900Group BMetric 236.27406361235.92942750.46
1545544200Group AMetric 1211.70171368367.3391957051.38
1545544200Group AMetric 237.93123361230.19442309.99
1545544200Group BMetric 1222.93765368212.0171881322.27
1545544200Group BMetric 237.95745361242.64843192.78
1545544500Group AMetric 1224.19434368362.0741954794.53
1545544500Group AMetric 236.77061361234.59842624.71
1545544500Group BMetric 1212.60191368198.7241875218.90
1545544500Group BMetric 234.03929361240.42543019.12

With the building blocks for average and variance, we compute them and derive the Z-score for each point.

Average

What is typical.

\[ \bar{X}=\frac {\Sigma x} {N} \]

To SQL:

mov_sum/mov_n AS mov_avg

Variance

The query below uses the computational formula for variance.

\[ \sigma^2=\frac{ \Sigma{x^2}- \frac{ (\Sigma{x})^2 } N } {N-1} \]

To SQL:

( mov_sum_sq - (mov_sum*mov_sum)/mov_n ) / (mov_n - 1) AS mov_var

Z-score

From the stats above, we compute a Z-score. The Z-score is defined as number of standard deviations from the window average the current point is. In other words, it tells us how typical a new point is given past data. A threshold value is compared to the Z-score to classify points.

\[ z=\frac {x-\bar{X}} {\sigma} \]

This formula requires the standard deviation, \(\sigma\), but we haven’t computed that. We have the variance, \(\sigma^2\), so we take the square root of variance to get the std. dev., right? Well, SQLite doesn’t have a square root sqrt() function. Are we doomed? Somewhat, but we will persevere. Sure, we could write a SQLite UDF, but let’s instead keep this organic and work with what we’ve got. Square everything to make use of the variance:

\[ z^2=\frac {(x-\bar{X})^2} {\sigma^2} \]

This is translated into SQL as:

((value - (mov_sum/mov_n)) * (value - (mov_sum/mov_n))) /   -- (value - mov_avg)^2 /
  ((mov_sum_sq - (mov_sum*mov_sum/mov_n)) / (mov_n - 1))    -- mov_var

Note that this is not the Z-score; this is the square of the Z-score. So what do we do to get the real Z-score without a sqrt() function? Beats me. But we don’t need the real Z-score; we can just square the threshold to keep everything consistent.

Threshold

Again, a threshold is compared to the Z-score to decide whether a given point is an anomaly. This is the number of allowed standard deviations, and is a number of your choosing.

A threshold of 3 is a good starting point. Given this, a value is an anomaly if mov_z_sq > 3*3.

That is:

\[ \frac {(x-\bar{X})^2} {\sigma^2}=z^2>\text{threshold}^2 \]

CASE
  WHEN
    ((value - (mov_sum/mov_n)) * (value - (mov_sum/mov_n))) /
    ((mov_sum_sq - (mov_sum*mov_sum/mov_n)) / (mov_n - 1)) > 3*3
    THEN 1
  ELSE 0
END is_anomaly

Remember to square the Z-score threshold.

The query

All together, the query starts by performing the non-equi self-join of itself, the window size is 10800 seconds (3 hrs). From this, it calculates the essential stats, the number of observerations mov_n, moving \(\text{sum}\) mov_sum, moving \(\text{sum}^2\) mov_sum_sq. Built atop that are statements that use these stats to return the moving average mov_avg, moving variance mov_var, and moving \(z^2\) mov_z_sq. Finally, the threshold value 3 is squared and compared to mov_z_sq to determine if the current point is atypical from previous points in the moving window.

SELECT
 ts,
 group_name,
 metric,
 value,
 mov_n,
 mov_sum / mov_n AS mov_avg,
 (mov_sum_sq - (mov_sum*mov_sum/mov_n)) / (mov_n - 1) AS mov_var,
 ((value - (mov_sum/mov_n)) * (value - (mov_sum/mov_n))) / ((mov_sum_sq - (mov_sum*mov_sum/mov_n)) / (mov_n - 1)) AS mov_z_sq,
 CASE
    WHEN
     ((value - (mov_sum/mov_n)) * (value - (mov_sum/mov_n))) /
      ((mov_sum_sq - (mov_sum*mov_sum/mov_n)) / (mov_n - 1)) > 3*3 THEN 1
    ELSE 0
 END is_anomaly
FROM (
 SELECT
     t1.ts,
     t1.group_name,
     t1.metric,
     t1.value,
     count(t2.value) AS mov_n,
     sum(t2.value) AS mov_sum,
     sum(t2.value*t2.value) AS mov_sum_sq
 FROM events t1 LEFT JOIN events t2
  ON t1.group_name = t2.group_name
 AND t1.metric = t2.metric
 AND t2.ts >= t1.ts - 10800
 AND t2.ts < t1.ts
 GROUP BY t1.ts,
          t1.group_name,
          t1.metric,
          t1.value
) as t

Top 12 rows:

tsgroup_namemetricvaluemov_nmov_avgmov_varmov_z_sqis_anomaly
1545543900Group AMetric 1247.1578936232.06639344.1481850.66178860
1545543900Group AMetric 228.818653634.335796.9259344.39490840
1545543900Group BMetric 1221.8538036228.04465231.4859980.16556770
1545543900Group BMetric 236.274063634.331359.1245840.41361950
1545544200Group AMetric 1211.7017136232.42607350.3911541.22577050
1545544200Group AMetric 237.931233634.172057.7639741.82012740
1545544200Group BMetric 1222.9376536228.11157230.4632540.11615510
1545544200Group BMetric 237.957453634.518008.5447281.38446040
1545544500Group AMetric 1224.1943436232.27983355.8120260.18373520
1545544500Group AMetric 236.770613634.294398.1404440.75323250
1545544500Group BMetric 1212.6019136227.74235229.2048091.00012260
1545544500Group BMetric 234.039293634.456267.9628660.02183490

View the results

Create a view of the query above to easily return anomalous records.

SELECT *
FROM v_anomaly
WHERE is_anomaly=1
tsgroup_namemetricvaluemov_nmov_avgmov_varmov_z_sqis_anomaly
1545459000Group AMetric 241.10389233.621411.80220531.066191
1545463500Group BMetric 1331.1598917226.16311376.94143529.246781
1545477900Group AMetric 1390.6506136229.25418267.41894197.408251
1545524700Group AMetric 217.130783634.064299.52703330.097921
1545525300Group AMetric 1119.0105236229.91305224.34101954.824441
1545528600Group BMetric 1369.9945336229.41003254.29181277.721731

Visualized

Now that our original dataset is augmented with valuable statistics and a classification, we can visualize the anomaly detection process. For this, we will need to switch to R and import the packages RSQLite and ggplot2. Also, since we’re now in R, we have a sqrt() function; sweet. Note that, while R is among the best tools for analytics, the anomaly detection process is being done entirely in SQL; we’re just using R for the viz.

In the plot below, each group is plotted in a pane. Each group metric is plotted as a colored line. The window average is plotted as a black dashed line within each group metric. The light gray lines illustrate the define threshold which determines the classification. Notice how the threshold increases after an anomaly occurs, then drops back down after the window size (3 hrs) elapses.

library(RSQLite)
library(ggplot2)
library(data.table)

### Connect to and retrieve teh data

db <- dbConnect(RSQLite::SQLite(), db_name)

df_anom <- RSQLite::dbGetQuery(db, 'SELECT * FROM v_anomaly')

RSQLite::dbDisconnect(db)

### Quick prep

df_anom <- as.data.table(df_anom) # makes working with dataframes nicer.

df_anom[is.na(mov_avg), mov_avg := value]
df_anom[is.na(mov_var), mov_var := 0]

z_thresh <- 3 # define the threshold to visualize it. The classification has already been made.

df_anom[, ':=' (thresh_high = mov_avg + (sqrt(mov_var) * z_thresh),
                thresh_low = mov_avg - (sqrt(mov_var) * z_thresh),
                is_anomaly = as.logical(is_anomaly))]

### Visualize

ggplot(df_anom, aes(x=as.POSIXct(ts, origin='1970-01-01'), y=value)) +
        geom_line(aes(group=metric, color=metric)) +
  
        geom_line(aes(group=metric, y=mov_avg), color='black', alpha=0.8, linetype='dashed') + 
        geom_line(aes(group=metric, y=thresh_high), color='gray', alpha=0.5) + 
        geom_line(aes(group=metric, y=thresh_low), color='gray', alpha=0.5) +
        geom_point(data=df_anom[is_anomaly==TRUE,], color='red', shape='O', size=5) +
  
        facet_grid(rows=vars(group_name)) +
        scale_x_datetime(date_labels='%H:%M',
                        breaks=unique(df_anom[ts %% 3600 == 0,]$ts) %>% as.POSIXct(origin='1970-01-01')) +
        scale_colour_manual(values=c('blue', 'purple')) +
        labs(x=NULL, y=NULL) +
        theme_bw() +
        ylim(0, NA) +
        theme(axis.text.x = element_text(angle = 90),
              legend.title = element_blank(),
              panel.grid = element_blank())

Another Approach

The above approach implements a non-equi self-join on the ts column with a window size defined in seconds. I felt this was the most suitable way to describe this method of anomaly detection. However, a faster query using windowing functions is shown below. Here, the window size is not defined by time, but by the number of preceding points, so it assumes periodic observations within the dataset. The clause ROWS BETWEEN 36 PRECEDING AND 1 PRECEDING defines the window size to be 35 preceding observations, not including the current observation. At 5 minute intervals, this equates to a window size of \(35\ points*5\ minutes*60\ seconds=10500\ seconds\). The query above has a window size of 10800 seconds, but the upper bound is non-inclusive; the current point is not considered. We could have made the upper bound <= 10500 seconds and achieve the same results. Long story short, the query below will produce the same results as the query above, but much faster, though with more assumptions and less flexibility.

SELECT
  ts,
  group_name,
  metric,
  value,
  avg(value) OVER w as mov_avg,
  case
    when ((value - (avg(value) OVER w)) * (value - (avg(value) OVER w))) /
            (( (sum(value * value) OVER w) - ((sum(value) OVER w) * (avg(value) OVER w))) /
                ( (count(*) OVER w) - 1))
            > 3*3 THEN 1
    ELSE 0
  END as is_outlier
FROM events
WINDOW w AS (PARTITION BY group_name, metric ORDER BY ts ROWS BETWEEN 36 PRECEDING AND 1 PRECEDING)
ORDER by ts asc

Parting words

While the methods are fairly simple, this process will not detect outliers that occur within the defined threshold. Tools such as R and Python offer libraries that are better suited for more advanced anomaly detection tasks. However, I hope the approach described in this post serves to demystify the fundamental aspects of anomaly detection by using a simple toolset and elementary statistics.

Until next time,
Donald

Related