Skip to content

Instantly share code, notes, and snippets.

@aelesbao
Last active January 4, 2017 17:04
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 aelesbao/8e3b3b8324c8aa26deeab4156b648a56 to your computer and use it in GitHub Desktop.
Save aelesbao/8e3b3b8324c8aa26deeab4156b648a56 to your computer and use it in GitHub Desktop.
Postgres Partitioning example
DROP TABLE IF EXISTS measurement CASCADE;
-- our master table
CREATE TABLE measurement (
id bigserial PRIMARY KEY NOT NULL,
logdate date NOT NULL
);
-- create the partitions
CREATE TABLE measurement_2016_12 (
CHECK ( logdate >= DATE '2016-12-01' AND logdate < DATE '2017-01-01' )
) INHERITS (measurement);
CREATE TABLE measurement_2017_01 (
CHECK ( logdate >= DATE '2017-01-01' AND logdate < DATE '2017-02-01' )
) INHERITS (measurement);
CREATE TABLE measurement_2017_02 (
CHECK ( logdate >= DATE '2017-02-01' AND logdate < DATE '2017-03-01' )
) INHERITS (measurement);
-- route inserts to the correspondent partition
CREATE OR REPLACE FUNCTION measurement_insert_trigger()
RETURNS TRIGGER AS $$
BEGIN
IF ( NEW.logdate >= DATE '2016-12-01' AND
NEW.logdate < DATE '2017-01-01' ) THEN
INSERT INTO measurement_2016_12 VALUES (NEW.*);
ELSIF ( NEW.logdate >= DATE '2017-01-01' AND
NEW.logdate < DATE '2017-02-01' ) THEN
INSERT INTO measurement_2017_01 VALUES (NEW.*);
ELSIF ( NEW.logdate >= DATE '2017-02-01' AND
NEW.logdate < DATE '2017-03-01' ) THEN
INSERT INTO measurement_2017_02 VALUES (NEW.*);
ELSE
RAISE EXCEPTION 'Date out of range. Fix the measurement_insert_trigger() function!';
END IF;
RETURN NULL;
END;
$$
LANGUAGE plpgsql;
CREATE TRIGGER insert_measurement_trigger
BEFORE INSERT ON measurement
FOR EACH ROW EXECUTE PROCEDURE measurement_insert_trigger();
-- add new data
INSERT INTO measurement (logdate) VALUES ('2016-12-15');
INSERT INTO measurement (logdate) VALUES ('2017-01-15');
INSERT INTO measurement (logdate) VALUES ('2017-02-15');
-- how tables are scanned when we disable constraint_exclusion?
SET constraint_exclusion = off;
EXPLAIN SELECT * FROM measurement where logdate = '2016-12-15';
-- and when we enable it?
SET constraint_exclusion = on;
EXPLAIN SELECT * FROM measurement where logdate = '2016-12-15';
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment