Skip to content

Instantly share code, notes, and snippets.

@jonahharris
Last active September 12, 2021 18:59
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save jonahharris/6580433bd19ce0307c6064489d1ea0e4 to your computer and use it in GitHub Desktop.
Save jonahharris/6580433bd19ce0307c6064489d1ea0e4 to your computer and use it in GitHub Desktop.
A Portable Log Likelihood Ratio Implementation using SQL Common Table Expressions
BEGIN;
/*
* The following is a SQL common table expression (CTE) port of the Apache
* Mahout implementation for calculating the raw log-likelihood ratio of two
* events. I needed it for a project and couldn't seem to find anything out
* there in pure SQL. While a procedural implementation would be preferred,
* this is portable to both SQLite (>= 3.35) and Postgres, which I'm using.
*
* NOTE: While this gist contains a port of the Mahout unit test, YMMV.
*
* Credit for this algorithm goes Ted Dunning, who states:
* - k11 The number of times the two events occurred together
* - k12 The number of times the second event occurred WITHOUT the first event
* - k21 The number of times the first event occurred WITHOUT the second event
* - k22 The number of times something else occurred (i.e. neither event)
*
* http://tdunning.blogspot.com/2008/03/surprise-and-coincidence.html
*
* Copyright (c) 2021 Jonah H. Harris <jonah.harris@gmail.com>
*
* Permission is hereby granted, free of charge, to any person obtaining a copy
* of this software and associated documentation files (the "Software"), to
* deal in the Software without restriction, including without limitation the
* rights to use, copy, modify, merge, publish, distribute, sublicense, and/or
* sell copies of the Software, and to permit persons to whom the Software is
* furnished to do so, subject to the following conditions:
*
* The above copyright notice and this permission notice shall be included in
* all copies or substantial portions of the Software.
*
* THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
* IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
* FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
* AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
* LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING
* FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS
* IN THE SOFTWARE.
*/
.mode column
.headers on
DROP TABLE IF EXISTS llr_test;
CREATE TABLE llr_test (
test_id BIGINT NOT NULL,
expected_result DOUBLE PRECISION NOT NULL,
epsilon DOUBLE PRECISION NOT NULL,
k11 BIGINT NOT NULL,
k12 BIGINT NOT NULL,
k21 BIGINT NOT NULL,
k22 BIGINT NOT NULL,
PRIMARY KEY (k11, k12, k21, k22));
INSERT INTO llr_test
VALUES (1, 2.772589, 0.000001, 1, 0, 0, 1),
(2, 27.72589, 0.00001, 10, 0, 0, 10),
(3, 39.33052, 0.00001, 5, 1995, 0, 100000),
(4, 4730.737, 0.001, 1000, 1995, 1000, 100000),
(5, 5734.343, 0.001, 1000, 1000, 1000, 100000),
(6, 5714.932, 0.001, 1000, 1000, 1000, 99000);
WITH
llr_base
AS (SELECT k11,
k12,
k21,
k22
FROM llr_test
ORDER BY test_id
),
llr_step_one
AS (SELECT k11,
k12,
k21,
k22,
CASE WHEN k11 = 0 THEN 0
ELSE (k11 * ln(k11))
END AS xlog_k11,
CASE WHEN k12 = 0 THEN 0
ELSE (k12 * ln(k12))
END AS xlog_k12,
CASE WHEN k21 = 0 THEN 0
ELSE (k21 * ln(k21))
END AS xlog_k21,
CASE WHEN k22 = 0 THEN 0
ELSE (k22 * ln(k22))
END AS xlog_k22
FROM llr_base
),
llr_step_two
AS (SELECT k11,
k12,
k21,
k22,
xlog_k11,
xlog_k12,
xlog_k21,
xlog_k22,
CASE WHEN ((k11 + k12) = 0)
THEN (0.0 - xlog_k11 - xlog_k12)
ELSE (((k11 + k12) * ln(k11 + k12)) - xlog_k11 - xlog_k12)
END AS entropy_k11_k12,
CASE WHEN ((k21 + k22) = 0)
THEN (0.0 - xlog_k21 - xlog_k22)
ELSE (((k21 + k22) * ln(k21 + k22)) - xlog_k21 - xlog_k22)
END AS entropy_k21_k22,
CASE WHEN ((k11 + k21) = 0)
THEN (0.0 - xlog_k11 - xlog_k21)
ELSE (((k11 + k21) * ln(k11 + k21)) - xlog_k11 - xlog_k21)
END AS entropy_k11_k21,
CASE WHEN ((k12 + k22) = 0)
THEN (0.0 - xlog_k12 - xlog_k22)
ELSE (((k12 + k22) * ln(k12 + k22)) - xlog_k12 - xlog_k22)
END AS entropy_k12_k22,
CASE WHEN ((k11 + k12 + k21 + k22) = 0)
THEN (0.0 - xlog_k11 - xlog_k12 - xlog_k21 - xlog_k22)
ELSE (((k11 + k12 + k21 + k22) * ln(k11 + k12 + k21 + k22))
- xlog_k11 - xlog_k12 - xlog_k21 - xlog_k22)
END AS entropy_k11_k12_k21_k22
FROM llr_step_one
),
llr_step_three
AS (SELECT k11,
k12,
k21,
k22,
xlog_k11,
xlog_k12,
xlog_k21,
xlog_k22,
entropy_k11_k12,
entropy_k21_k22,
entropy_k11_k21,
entropy_k12_k22,
entropy_k11_k12_k21_k22,
(entropy_k11_k12 + entropy_k21_k22) AS row_entropy,
(entropy_k11_k21 + entropy_k12_k22) AS col_entropy,
entropy_k11_k12_k21_k22 AS matrix_entropy
FROM llr_step_two
),
llr
AS (SELECT k11,
k12,
k21,
k22,
xlog_k11,
xlog_k12,
xlog_k21,
xlog_k22,
entropy_k11_k12,
entropy_k21_k22,
entropy_k11_k21,
entropy_k12_k22,
entropy_k11_k12_k21_k22,
row_entropy,
col_entropy,
matrix_entropy,
CASE WHEN ((row_entropy + col_entropy) > matrix_entropy)
THEN 0.0
ELSE (2.0 * (matrix_entropy - row_entropy - col_entropy))
END AS llr
FROM llr_step_three
)
SELECT t.test_id,
CASE WHEN (abs(t.expected_result - r.llr) < t.epsilon)
THEN 'passed'
ELSE 'failed (expected ' || t.expected_result || ', got ' || r.llr || ')'
END test_result
FROM llr_test t,
(SELECT row_number () over () AS test_id,
llr
FROM llr) r
WHERE t.test_id = r.test_id
;
-- This is only a test, no need to store the test data.
ROLLBACK;
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment