From e156e41a2cd959a15235418dfe820e7d3e7cb53c Mon Sep 17 00:00:00 2001 From: Alistair Johnson Date: Mon, 25 Jan 2016 15:16:53 -0500 Subject: [PATCH] fix check in partitioning code --- benchmark/README.md | 66 ++++++++++++++++++++++++ benchmark/postgres-benchmark-4.sql | 101 +++++++------------------------------ 2 files changed, 83 insertions(+), 84 deletions(-) diff --git a/benchmark/README.md b/benchmark/README.md index 8ea7914..e1660dc 100644 --- a/benchmark/README.md +++ b/benchmark/README.md @@ -317,3 +317,69 @@ bucket | minitemid | maxitemid | freq | bar 7 | 3723 | 8522 | 1596741 | ============ 8 | 8523 | 220073 | 4515 | 9 | 220074 | 228647 | 2689753 | ==================== + + +Partitions are built using postgres-benchmark-4.sql. This results in a table called CHARTEVENTS_PARTITIONED which we can evaluate queries on. + + +## Benchmark + +```sql +EXPLAIN ANALYZE +select + ie.icustay_id + , min(case when itemid = 211 then valuenum else null end) as HeartRate_Min + , max(case when itemid = 211 then valuenum else null end) as HeartRate_Max + , min(case when itemid in (615,618) then valuenum else null end) as RespRate_Min + , max(case when itemid in (615,618) then valuenum else null end) as RespRate_Max +from icustays ie +-- join to the chartevents table to get the observations +left join chartevents_partitioned ce + -- match the tables on the patient identifier + on ie.icustay_id = ce.icustay_id + and ce.charttime >= ie.intime and ce.charttime <= ie.intime + interval '1' day + and ce.itemid in (211,615,618) +group by ie.icustay_id +order by ie.icustay_id; +``` + +Execution plan: + +``` +TODO +``` + +Add in some indexes on ITEMID (took ~5 seconds): + +```sql +drop index IF EXISTS CHARTEVENTS_PART_idx02; +CREATE INDEX CHARTEVENTS_PART_idx02 + ON CHARTEVENTS_PARTITIONED (ITEMID); +``` + +Re-run explain analyze: + +```sql +EXPLAIN ANALYZE +select + ie.icustay_id + , min(case when itemid = 211 then valuenum else null end) as HeartRate_Min + , max(case when itemid = 211 then valuenum else null end) as HeartRate_Max + , min(case when itemid in (615,618) then valuenum else null end) as RespRate_Min + , max(case when itemid in (615,618) then valuenum else null end) as RespRate_Max +from icustays ie +-- join to the chartevents table to get the observations +left join chartevents_partitioned ce + -- match the tables on the patient identifier + on ie.icustay_id = ce.icustay_id + and ce.charttime >= ie.intime and ce.charttime <= ie.intime + interval '1' day + and ce.itemid in (211,615,618) +group by ie.icustay_id +order by ie.icustay_id; +``` + +Should be faster. + +``` +TODO +``` diff --git a/benchmark/postgres-benchmark-4.sql b/benchmark/postgres-benchmark-4.sql index b2f6d91..c7c398e 100644 --- a/benchmark/postgres-benchmark-4.sql +++ b/benchmark/postgres-benchmark-4.sql @@ -20,74 +20,17 @@ -- PARTITIONNING -- CREATE CHARTEVENTS_PARTITIONED TABLE -CREATE TABLE CHARTEVENTS_PARTITIONED_0 ( CHECK ( itemid in - ( - -- HEART RATE - 211, --"Heart Rate" - 220045, --"Heart Rate" - - -- Systolic/diastolic - - 51, -- Arterial BP [Systolic] - 442, -- Manual BP [Systolic] - 455, -- NBP [Systolic] - 6701, -- Arterial BP #2 [Systolic] - 220179, -- Non Invasive Blood Pressure systolic - 220050, -- Arterial Blood Pressure systolic - - 8368, -- Arterial BP [Diastolic] - 8440, -- Manual BP [Diastolic] - 8441, -- NBP [Diastolic] - 8555, -- Arterial BP #2 [Diastolic] - 220180, -- Non Invasive Blood Pressure diastolic - 220051, -- Arterial Blood Pressure diastolic - - - -- MEAN ARTERIAL PRESSURE - 456, --"NBP Mean" - 52, --"Arterial BP Mean" - 6702, -- Arterial BP Mean #2 - 443, -- Manual BP Mean(calc) - 220052, --"Arterial Blood Pressure mean" - 220181, --"Non Invasive Blood Pressure mean" - 225312, --"ART BP mean" - - -- RESPIRATORY RATE - 618,-- Respiratory Rate - 615,-- Resp Rate (Total) - 220210,-- Respiratory Rate - 224690, -- Respiratory Rate (Total) - - - -- SPO2, peripheral - 646, 220277, - - -- GLUCOSE, both lab and fingerstick - 807,-- Fingerstick Glucose - 811,-- Glucose (70-105) - 1529,-- Glucose - 3745,-- BloodGlucose - 3744,-- Blood Glucose - 225664,-- Glucose finger stick - 220621,-- Glucose (serum) - 226537,-- Glucose (whole blood) - - -- TEMPERATURE - 223762, -- "Temperature Celsius" - 676, -- "Temperature C" - 223761, -- "Temperature Fahrenheit" - 678 -- "Temperature F" - ) +CREATE TABLE CHARTEVENTS_PARTITIONED_0 ( CHECK ( itemid in (211, 220045, 51, 442, 455, 6701, 220179, 220050, 8368, 8440, 8441, 8555, 220180, 220051, 456, 52, 6702, 443, 220052, 220181, 225312, 618, 615, 220210, 224690, 646, 220277, 223762, 676, 223761, 678 ) )) INHERITS (CHARTEVENTS_PARTITIONED); -CREATE TABLE CHARTEVENTS_PARTITIONED_1 ( CHECK ( itemid >= 1 AND itemid < 161 )) INHERITS (CHARTEVENTS_PARTITIONED); -CREATE TABLE CHARTEVENTS_PARTITIONED_2 ( CHECK ( itemid >= 161 AND itemid < 428 )) INHERITS (CHARTEVENTS_PARTITIONED); -CREATE TABLE CHARTEVENTS_PARTITIONED_3 ( CHECK ( itemid >= 428 AND itemid < 615 )) INHERITS (CHARTEVENTS_PARTITIONED); -CREATE TABLE CHARTEVENTS_PARTITIONED_4 ( CHECK ( itemid >= 615 AND itemid < 742 )) INHERITS (CHARTEVENTS_PARTITIONED); +CREATE TABLE CHARTEVENTS_PARTITIONED_1 ( CHECK ( itemid >= 1 AND itemid < 161 AND NEW.itemid not in (51, 52))) INHERITS (CHARTEVENTS_PARTITIONED); +CREATE TABLE CHARTEVENTS_PARTITIONED_2 ( CHECK ( itemid >= 161 AND itemid < 428 AND NEW.itemid != 211)) INHERITS (CHARTEVENTS_PARTITIONED); +CREATE TABLE CHARTEVENTS_PARTITIONED_3 ( CHECK ( itemid >= 428 AND itemid < 615 AND NEW.itemid not in (442, 455, 456, 443))) INHERITS (CHARTEVENTS_PARTITIONED); +CREATE TABLE CHARTEVENTS_PARTITIONED_4 ( CHECK ( itemid >= 615 AND itemid < 742 AND NEW.itemid not in (618, 615, 646, 676, 678))) INHERITS (CHARTEVENTS_PARTITIONED); CREATE TABLE CHARTEVENTS_PARTITIONED_5 ( CHECK ( itemid >= 742 AND itemid < 3338 )) INHERITS (CHARTEVENTS_PARTITIONED); CREATE TABLE CHARTEVENTS_PARTITIONED_6 ( CHECK ( itemid >= 3338 AND itemid < 3723 )) INHERITS (CHARTEVENTS_PARTITIONED); -CREATE TABLE CHARTEVENTS_PARTITIONED_7 ( CHECK ( itemid >= 3723 AND itemid < 8523 )) INHERITS (CHARTEVENTS_PARTITIONED); -CREATE TABLE CHARTEVENTS_PARTITIONED_8 ( CHECK ( itemid >= 8523 AND itemid < 220074 )) INHERITS (CHARTEVENTS_PARTITIONED); -CREATE TABLE CHARTEVENTS_PARTITIONED_9 ( CHECK ( itemid >= 220074 AND itemid < 323769 )) INHERITS (CHARTEVENTS_PARTITIONED); +CREATE TABLE CHARTEVENTS_PARTITIONED_7 ( CHECK ( itemid >= 3723 AND itemid < 8523 AND NEW.itemid not in (6701, 6702, 8368, 8440, 8441))) INHERITS (CHARTEVENTS_PARTITIONED); +CREATE TABLE CHARTEVENTS_PARTITIONED_8 ( CHECK ( itemid >= 8523 AND itemid < 220074 AND NEW.itemid not in (220045, 220050, 8555, 220051, 220052))) INHERITS (CHARTEVENTS_PARTITIONED); +CREATE TABLE CHARTEVENTS_PARTITIONED_9 ( CHECK ( itemid >= 220074 AND itemid < 323769 AND NEW.itemid not in (220179, 220050, 220180, 220181, 225312, 220210, 224690, 220277, 223762, 223761 ))) INHERITS (CHARTEVENTS_PARTITIONED); -- CREATE CHARTEVENTS_PARTITIONED TRIGGER CREATE OR REPLACE FUNCTION CHARTEVENTS_PARTITIONED_insert_trigger() @@ -137,16 +80,6 @@ IF ( NEW.itemid in -- SPO2, peripheral 646, 220277, - -- GLUCOSE, both lab and fingerstick - 807,-- Fingerstick Glucose - 811,-- Glucose (70-105) - 1529,-- Glucose - 3745,-- BloodGlucose - 3744,-- Blood Glucose - 225664,-- Glucose finger stick - 220621,-- Glucose (serum) - 226537,-- Glucose (whole blood) - -- TEMPERATURE 223762, -- "Temperature Celsius" 676, -- "Temperature C" @@ -154,15 +87,15 @@ IF ( NEW.itemid in 678 -- "Temperature F" ) ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_0 VALUES (NEW.*); -ELSIF ( NEW.itemid >= 1 AND NEW.itemid < 161 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_1 VALUES (NEW.*); -ELSIF ( NEW.itemid >= 161 AND NEW.itemid < 428 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_2 VALUES (NEW.*); -ELSIF ( NEW.itemid >= 428 AND NEW.itemid < 615 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_3 VALUES (NEW.*); -ELSIF ( NEW.itemid >= 615 AND NEW.itemid < 742 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_4 VALUES (NEW.*); -ELSIF ( NEW.itemid >= 742 AND NEW.itemid < 3338 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_5 VALUES (NEW.*); -ELSIF ( NEW.itemid >= 3338 AND NEW.itemid < 3723 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_6 VALUES (NEW.*); -ELSIF ( NEW.itemid >= 3723 AND NEW.itemid < 8523 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_7 VALUES (NEW.*); -ELSIF ( NEW.itemid >= 8523 AND NEW.itemid < 220074 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_8 VALUES (NEW.*); -ELSIF ( NEW.itemid >= 220074 AND NEW.itemid < 323769 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_9 VALUES (NEW.*); +ELSIF ( NEW.itemid >= 1 AND NEW.itemid < 161 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_1 VALUES (NEW.*); +ELSIF ( NEW.itemid >= 161 AND NEW.itemid < 428 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_2 VALUES (NEW.*); +ELSIF ( NEW.itemid >= 428 AND NEW.itemid < 615 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_3 VALUES (NEW.*); +ELSIF ( NEW.itemid >= 615 AND NEW.itemid < 742 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_4 VALUES (NEW.*); +ELSIF ( NEW.itemid >= 742 AND NEW.itemid < 3338 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_5 VALUES (NEW.*); +ELSIF ( NEW.itemid >= 3338 AND NEW.itemid < 3723 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_6 VALUES (NEW.*); +ELSIF ( NEW.itemid >= 3723 AND NEW.itemid < 8523 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_7 VALUES (NEW.*); +ELSIF ( NEW.itemid >= 8523 AND NEW.itemid < 220074 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_8 VALUES (NEW.*); +ELSIF ( NEW.itemid >= 220074 AND NEW.itemid < 323769 ) THEN INSERT INTO CHARTEVENTS_PARTITIONED_9 VALUES (NEW.*); ELSE INSERT INTO CHARTEVENTS_PARTITIONED_NULL VALUES (NEW.*); END IF;