Permalink
Browse files

Initial commit.

  • Loading branch information...
0 parents commit 9be71d479446506b4488b6e6bd2baa5cedced2f6 @grzm grzm committed Oct 18, 2010
430 README.md
@@ -0,0 +1,430 @@
+partmanteau
+===========
+PostgreSQL Partition Management Tool
+
+partmanteau is a set of tables and functions to simplify creation and deletion
+of partitions in PostgreSQL databases. It is most definitely not a complete
+solution, nor is it intended to be.
+
+Background
+----------
+There are many different ways to partition a table: range, list, and hash are
+three common ones. Each of these ways in turn has different tactics:
+
+ * What is the type of the column in the range partition?
+ Is it a timestamp, an integer, or some other type?
+ * What hashing function is used to partition values? Which columns are arguments
+ to the hashing function?
+ * What columns contribute to the list items? How do the partitions correspond
+ to the list items? Is it one-to-one or are some list items included in the
+ same partition?
+ * How often are partitions added? Timestamp-ranged partitions often add new
+ partitions on a regular schedule. List partitions often have a fixed number
+ of partitions corresponding to the list items and rarely changes.
+
+More complex partitioning strategies can be implemented by combining different
+tactics: partition the table by list and then partition each of list item
+partitions by range.
+
+Rather than try to solve the general problem of accomodating the large number
+of partitioning tactics, partmanteau leaves the partitioning function up to the
+developer.
+
+So, what *does* partmanteau do?
+-------------------------------
+partmanteau provides two functions and a (mental) framework for developing a partitioning
+strategy. The framework consists of clear steps which make partitioning
+formulaic rather than a process reinvented each time it's needed.
+
+partmanteau API
+---------------
+The two functions provided by the partmanteau API are
+
+* `partmanteau.create_table_partition`
+* `partmanteau.drop_table_partition_older_than`
+* `partmanteau.insert_statement`
+
+The `partmanteau.create_table_partition` function creates a new table,
+including appropriate indexes (including key constraints), check constraints,
+permissions and ownership, and table attributes such as `FILLFACTOR`. It does
+*not* include foreign keys as these may (or may not) reference tables which are
+themselves partitioned: determining the appropriate referenced partition
+is left to the developer. It also does not include comments as the easiest
+solution (copying the comment from the parent table) does not seem to add
+anything to the database schema.
+
+ CREATE FUNCTION
+ partmanteau.create_table_partition(in_schema_name text,
+ in_table_name text,
+ in_partition_name text,
+ in_constraints text[],
+ in_additional_commands text[],
+ in_effective_at timestamp with time zone,
+ OUT command TEXT)
+ RETURNS SETOF text AS
+ $BODY$
+ /**
+ *
+ * This function provides a wrapper for common partition creation use cases.
+ * It executes the partition definition returned from
+ * partmanteau.table_partition_definition and performs the requisite
+ * bookkeeping on the partition metadata tables.
+ *
+ * @author Michael Glaesemann <michael.glaesemann@myyearbook.com>
+ *
+ * @param[IN] in_schema_name schema of the partitioned (parent) table
+ * @param[IN] in_table_name name of the partitioned (parent) table
+ * @param[IN] in_partition_name name for the table partition to be created
+ * @param[IN] in_constraints Additional constraints (including the
+ * partitioning constraint) to be added to the
+ * table partition
+ * @param[IN] in_additional_commands Additional commands to be run (such as
+ * trigger creation statements)
+ * @param[IN] in_effective_at Timestamp for
+ * @param[OUT] command
+ * @return
+ *
+ */
+
+ CREATE FUNCTION
+ partmanteau.drop_table_partition_older_than(in_schema_name text,
+ in_table_name text,
+ in_age interval)
+ RETURNS boolean AS
+ $BODY$
+ /**
+ *
+ * This function drops the oldest partition for the given partitioned table that
+ * has an effective_at age equal to or older than the given age. This is
+ * primarily useful for timestamp-based range partitioned tables. It takes into
+ * account effectve_at rather than the sort_key as the sort_key currently tracks
+ * the order in which the partitions were created. The create_table_partition
+ * code should probably be changed to update the sort_key to take into account
+ * a set effective_at timestamp, but it does not currently do so.
+ *
+ * @author Michael Glaesemann <michael.glaesemann@myyearbook.com>
+ *
+ * @param[IN] in_schema_name the schema of the partitioned table
+ * @param[IN] in_table_name the name of the partitioned table
+ * @param[IN] in_age the minimum age of the partition to drop
+ * @param[OUT]
+ * @return TRUE upon successful delete from the partmanteau
+ * partition metadata tables
+ *
+ */
+
+As of now, here's no general `partmanteau.drop_table_partition` function
+corresponding to `partmanteau.create_table_partition`. I haven't needed to use
+such a function yet as I rarely drop partitions unless they're ranged by a
+timestamp column and we're aging out old partitions.
+
+Partitioning Framework
+----------------------
+ 1. List all table constraints as separate commands rather than as
+ part of the `CREATE TABLE` statement. This makes it easier to
+ determine which statements need to be included in the *create_partition*
+ function.
+
+ 2. Name your indexes prefixed with the table name. partmanteau munges the index
+ names when creating the indexes for the partitions and relies on the table name
+ to be included in the index name.
+
+ 3. Decide on a naming strategy for partition tables. Ecapsulate this
+ strategy in a function so you can easily derive a particular
+ partition's name by the partitioning criteria. For example, if you're
+ partitioning by a timestamp range, create a `partition_name(timestamp)`
+ function returns the appropriate partition name for a value given
+ timestamp. The partition name is needed in at least two places (the
+ *create_partition* function and the *partition* function, so keeping
+ this logic in one place (the *partition_name* function) is good
+ practice.
+
+ 4. Define a *create_partition* function for the partitioned table
+ that takes into account the partitioning strategy.
+ This function should include:
+ * the partitioning constraint (used in constraint exclusion)
+ and any other table constraints.
+ * foreign key constraints and any additional commands necessary
+ to support the database schema.
+
+ 5. Define a *partition* function that is used to insert data into the
+ appropriate table. Depending on the implementation, this function can be
+ used as a trigger or as part of an insert function. If the database schema
+ involves moving data between partitions, update operations may also need
+ to take into account the *partition* function.
+
+Under the covers
+----------------
+While the partmaneau API consists of just a handful of functions, there are
+a number of other support functions and a couple of tables used to store
+partitioned table metadata. These private (i.e., shouldn't be called by
+user-developed functions) encapsulate the creation of statements used to
+create and drop partitions as well as update the
+`partmanteau.partitioned_tables` and `partmanteau.table_partitions` tables
+which hold the partition metadata.
+
+Example
+=======
+
+We have a set of monitors that each track a number of sensors which
+provide temperature readings over time. This example is pulled from a
+hobby project of mine to track home electricity usage using a
+[Current Cost](http://www.currentcost.net/) Envi unit.
+
+ CREATE TABLE current_cost.monitors
+ (
+ monitor_id UUID PRIMARY KEY,
+ monitor_label TEXT NOT NULL
+ );
+
+ CREATE TABLE current_cost.readings
+ (
+ monitor_id UUID NOT NULL,
+ sensor_radio_id INT NOT NULL,
+ sensor INT NOT NULL,
+ reading_id UUID NOT NULL,
+ read_at TIMESTAMP WITH TIME ZONE NOT NULL,
+ fahrenheit REAL NOT NULL
+ );
+
+ CREATE UNIQUE INDEX readings_key ON current_cost.readings (reading_id);
+ CREATE UNIQUE INDEX readings_reading_id_read_at_key
+ ON current_cost.readings (reading_id, read_at);
+ COMMENT ON INDEX current_cost.readings_reading_id_read_at_key IS
+ 'Over-constrained including read_at to allow foreign key references.';
+
+ CREATE INDEX readings_read_at_key ON current_cost.readings (read_at);
+ ALTER TABLE current_cost.readings ADD FOREIGN KEY (monitor_id)
+ REFERENCES current_cost.monitors (monitor_id)
+ ON DELETE CASCADE;
+
+In keeping with the framework, the index and foreign key statements are listed
+separately, and the index names are prefixed with the table name.
+
+As the table grows, we want to drop off the oldest partitions,
+keeping only the most recent data. Therefore, we'll partition the
+`current_cost.readings` table by the `read_at` timestamp. We decide
+to partition readings by month. We're ready to write our
+*partition_name* function.
+
+ CREATE FUNCTION
+ current_cost.readings_partition_name(in_timestamp timestamp with time zone)
+ RETURNS text AS
+ $BODY$
+ /**
+ *
+ * Returns a normalized recent readings partition name for the
+ * given timestamp. Readings are partitioned by week.
+ *
+ * @private
+ *
+ * @param[IN] in_timestamp
+ * @param[OUT]
+ * @return
+ *
+ */
+ SELECT 'readings_' || to_char(date_trunc('month', $1), 'YYYYMMDD')
+ $BODY$
+ LANGUAGE sql IMMUTABLE STRICT;
+
+The `current_cost.readings_partition_name` function allows us to
+derive the partition name for any given reading value.
+
+Note that this partition name function returns names that are dependent on the
+time zone of the server. If it's likely that the database will be moved to
+another server in a different time zone, it would be wise to normalize this
+further, perhaps determining the name based on the timestamp UTC. Such an
+implemention is left as an exercise for the reader.
+
+Now we're ready to write the *create_partition* function. This encapsulates the
+logic that's particular to the partitioning strategy, providing the arguments to
+the `partmanteau.create_table_partition` function.
+
+ CREATE FUNCTION
+ current_cost.create_readings_partition(in_timestamp timestamp with time zone)
+ RETURNS SETOF text AS
+ $BODY$
+ /**
+ *
+ * Creates a partition for a month's worth of readings for the month
+ * containing the given timestamp.
+ *
+ * @param[IN] in_timestamp
+ * @return
+ *
+ */
+ DECLARE
+ k_schema_name TEXT := 'current_cost';
+ k_base_table_name TEXT := 'readings';
+ k_partition_column TEXT := 'read_at';
+ v_commands TEXT[];
+ v_partition_name TEXT := current_cost.readings_partition_name(in_timestamp);
+ v_qualified_partition_name TEXT := quote_ident(k_schema_name) || '.'
+ || quote_ident(v_partition_name);
+ k_width INTERVAL := '1 month';
+ v_lower_bound TIMESTAMP WITH TIME ZONE := date_trunc('month', in_timestamp);
+ v_upper_bound TIMESTAMP WITH TIME ZONE := v_lower_bound + k_width;
+ v_partition_constraint TEXT := array_to_string(
+ ARRAY[quote_ident(k_partition_column),
+ '>=', quote_literal(v_lower_bound),
+ 'AND', quote_ident(k_partition_column),
+ '<', quote_literal(v_upper_bound)], ' ');
+ v_additional_commands TEXT[];
+ BEGIN
+ v_additional_commands := ARRAY[
+ array_to_string(ARRAY['ALTER TABLE',
+ v_qualified_partition_name,
+ 'ADD FOREIGN KEY (monitor_id)',
+ 'REFERENCES current_cost.monitors (monitor_id)'], ' ')];
+ RETURN QUERY
+ SELECT command
+ FROM partmanteau.create_table_partition(
+ k_schema_name, k_base_table_name,
+ v_partition_name,
+ ARRAY[v_partition_constraint],
+ v_additional_commands,
+ v_lower_bound) AS the (command);
+ RETURN;
+ END
+ $BODY$
+ LANGUAGE plpgsql VOLATILE STRICT;
+
+As we're partitioning by timestamp, `current_cost.create_readings_partition`
+takes a timestamp argument. The partition name is derived using the
+`current_cost.readings_partition_name` function we already defined.
+
+As per the framework, the partition exclusion constraint is explicitly defined
+and foreign keys are included in the `partmanteau.create_table_partition`
+`additional_commands` argument.
+
+We do have a little bit of duplicated logic: when deriving the lower bound we
+use `date_trunc('month', timestamp)` just like we do in the *partition_name*
+function. I haven't found a good solution to eliminating this redundancy but as
+the perfect is the enemy of the good, I've accepted this. Even better,
+partmanteau doesn't preclude such a solution. Some clever soul will figure it out.
+
+I also define a number of constants and variables:
+
+ * `k_schema_name`
+ * `k_base_table_name`
+ * `k_partition_column`
+ * `v_commands`
+ * `v_partition_name`
+ * `v_qualified_partition_name`
+ * `k_width`, `v_lower_bound`, and `v_upper_bound`
+ * `v_partition_constraint`
+ * `v_additional_commands`
+
+I find that factoring out the literals in this way makes the logic of the
+function easier to see. Having implemented many partition strategies using this
+framework also exposes these as the key elements in the partitioning strategy:
+the logic remains largely the same. A more mature framework could store these
+elements as configuration parameters in tables, further simplifying the
+interface.
+
+As an aside, I prefer the `array_to_string(expression_parts, ' ')` approach to
+creating dynamic SQL statements rather than using string concatenation. It
+eliminates the need to make sure I've remembered to include spaces between
+elements I find there's less visual noise than having `||` peppered throughout
+the statement.
+
+I like to return the commands used to create the partition (returned by
+`partmanteau.create_table_partition` as another way to see if everything is
+working as expected.
+
+We're ready to define the *partition* function. We're going to create this as a
+trigger so we can issue arbitrary `INSERT` commands against the
+`current_cost.readings` table. The table is also insert-only, so we don't need
+to worry about `UPDATE` or `DELETE` cases.
+
+ CREATE FUNCTION current_cost.partition_readings()
+ RETURNS trigger AS
+ $BODY$
+ /**
+ *
+ * This trigger function partitions inserts on current_cost.readings into
+ * the appropriate current_cost.readings partition.
+ *
+ */
+ DECLARE
+ k_schema CONSTANT TEXT := 'current_cost';
+ k_columns CONSTANT TEXT[] := ARRAY['monitor_id',
+ 'sensor_radio_id',
+ 'sensor',
+ 'reading_id',
+ 'read_at',
+ 'fahrenheit'];
+ v_values TEXT[];
+ v_partition_name TEXT;
+ v_sql TEXT;
+ BEGIN
+ IF TG_OP = 'INSERT' THEN
+ v_partition_name := current_cost.readings_partition_name(NEW.read_at);
+ v_values := ARRAY[quote_literal(NEW.monitor_id),
+ quote_literal(NEW.sensor_radio_id),
+ quote_literal(NEW.sensor),
+ quote_literal(NEW.reading_id),
+ quote_literal(NEW.read_at),
+ quote_literal(NEW.fahrenheit)];
+ v_sql := partmanteau.insert_statement(k_schema, v_partition_name,
+ k_columns, v_values);
+ EXECUTE v_sql;
+ RETURN NULL;
+ END IF;
+ RETURN NEW;
+ END
+ $BODY$
+ LANGUAGE plpgsql VOLATILE STRICT;
+
+ CREATE TRIGGER partition_readings
+ BEFORE INSERT ON current_cost.readings
+ FOR EACH ROW
+ EXECUTE PROCEDURE current_cost.partition_readings();
+
+The *partition* function is straightforward. After writing dynamic `INSERT`
+statements enough times, I factored this out into `partmanteau.insert_statement`.
+Column names are quoted as neccessary the function. To take into account the
+varied column types, the values are wrapped in `quote_literal`.
+
+Now that the partitioning strategy is set up, all that's left is to schedule the
+creation and dropping of partitions. This can be as simple as setting a cron to
+execute `SELECT * FROM current_cost.create_readings_partition(CURRENT_DATE + 4)`
+once a month. Note the `CURRENT_DATE + 4`: to make sure the necessary partition
+is in place before it's needed, we execute the command on the 28th of the month
+prior to the month of the partition as `current_cost.create_readings_partition`
+creates a partition based on the provided timestamp rather than on when it's
+executed.
+
+Author
+------
+Michael Glaesemann michael.glaesemann at myyearbook.com
+
+Copyright and License
+=====================
+Copyright (c) 2010, Insider Guides, Inc.
+All rights reserved.
+
+Redistribution and use in source and binary forms, with or without modification,
+are permitted provided that the following conditions are met:
+
+ * Redistributions of source code must retain the above copyright notice,
+ this list of conditions and the following disclaimer.
+
+ * Redistributions in binary form must reproduce the above copyright notice,
+ this list of conditions and the following disclaimer in the documentation
+ and/or other materials provided with the distribution.
+
+ * Neither the name of Insider Guides, Inc., its website properties nor the
+ names of its contributors may be used to endorse or promote products derived
+ from this software without specific prior written permission.
+
+THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND
+ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED
+WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE
+DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE FOR
+ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES
+(INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES;
+LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON
+ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT
+(INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS
+SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
739 partmanteau.sql
@@ -0,0 +1,739 @@
+BEGIN;
+
+CREATE SCHEMA partmanteau;
+
+CREATE FUNCTION
+partmanteau.create_language_plpgsql()
+RETURNS BOOLEAN
+STRICT LANGUAGE sql AS $body$
+/**
+ *
+ * Helper for CREATE LANGUAGE IF NOT EXISTS functionality for
+ * systems which don't have this command.
+ *
+ * @author Michael Glaesemann <michael.glaesemann@myyearbook.com>
+ *
+ * @private
+ *
+ */
+ CREATE LANGUAGE PLPGSQL;
+ SELECT TRUE;
+$body$;
+SELECT partmanteau.create_language_plpgsql()
+ WHERE NOT EXISTS (SELECT TRUE
+ FROM pg_catalog.pg_language
+ WHERE lanname = 'plpgsql');
+DROP FUNCTION partmanteau.create_language_plpgsql();
+
+CREATE TABLE partmanteau.partitioned_tables
+(
+ partitioned_table_id serial NOT NULL,
+ schema_name text NOT NULL,
+ table_name text NOT NULL
+);
+COMMENT ON TABLE partmanteau.partitioned_tables IS
+'Lists partitioned tables which are managed through the partmanteau schema.';
+
+CREATE UNIQUE INDEX partitioned_tables_partitioned_table_id_key
+ ON partmanteau.partitioned_tables
+ USING btree
+ (partitioned_table_id);
+
+CREATE UNIQUE INDEX partitioned_tables_table_name_schema_name_key
+ ON partmanteau.partitioned_tables
+ USING btree
+ (schema_name, table_name);
+
+CREATE TABLE partmanteau.table_partitions
+(
+ table_partition_id serial NOT NULL,
+ partitioned_table_id integer NOT NULL,
+ created_at timestamp with time zone NOT NULL DEFAULT CURRENT_TIMESTAMP,
+ effective_at timestamp with time zone NOT NULL DEFAULT CURRENT_TIMESTAMP,
+ sort_key integer NOT NULL,
+ table_partition_name text NOT NULL,
+ CONSTRAINT table_partitions_partitioned_table_id_fkey
+ FOREIGN KEY (partitioned_table_id)
+ REFERENCES partmanteau.partitioned_tables (partitioned_table_id) MATCH SIMPLE
+ ON UPDATE NO ACTION ON DELETE NO ACTION
+);
+COMMENT ON TABLE partmanteau.table_partitions IS
+'Lists partitions of tables which are managed through the partmanteau schema.';
+COMMENT ON COLUMN partmanteau.table_partitions.created_at IS
+'When the table partition was created.';
+COMMENT ON COLUMN partmanteau.table_partitions.effective_at IS
+'When the table partition is expected to take effect. '
+'Used primarily to determine age of a partition for tables partitioned by some time range.';
+COMMENT ON COLUMN partmanteau.table_partitions.sort_key IS
+'Logical ordering of the partitions.';
+
+CREATE UNIQUE INDEX table_partitions_partitioned_table_id_table_partition_name_key
+ ON partmanteau.table_partitions
+ USING btree
+ (partitioned_table_id, table_partition_name);
+
+CREATE UNIQUE INDEX table_partitions_table_partition_id_key
+ ON partmanteau.table_partitions
+ USING btree
+ (table_partition_id);
+
+CREATE FUNCTION
+partmanteau.create_table_partition(in_schema_name text,
+ in_table_name text,
+ in_partition_name text,
+ in_constraints text[],
+ in_additional_commands text[],
+ in_effective_at timestamp with time zone,
+ OUT command TEXT)
+ RETURNS SETOF text AS
+$BODY$
+/**
+ *
+ * This function provides a wrapper for common partition creation use cases.
+ * It executes the partition definition returned from
+ * partmanteau.table_partition_definition and performs the requisite
+ * bookkeeping on the partition metadata tables.
+ *
+ * @author Michael Glaesemann <michael.glaesemann@myyearbook.com>
+ *
+ * @param[IN] in_schema_name schema of the partitioned (parent) table
+ * @param[IN] in_table_name name of the partitioned (parent) table
+ * @param[IN] in_partition_name name for the table partition to be created
+ * @param[IN] in_constraints Additional constraints (including the
+ * partitioning constraint) to be added to the
+ * table partition
+ * @param[IN] in_additional_commands Additional commands to be run (such as
+ * trigger creation statements)
+ * @param[IN] in_effective_at Timestamp for
+ * @param[OUT] command
+ * @return
+ *
+ */
+DECLARE
+ k_create_if_necessary CONSTANT BOOLEAN := TRUE;
+ v_partitioned_table_oid OID := partmanteau.table_oid(in_schema_name, in_table_name);
+ v_partitioned_table_id partmanteau.partitioned_tables.partitioned_table_id%TYPE
+ := partmanteau.partitioned_table_id(in_schema_name, in_table_name,
+ k_create_if_necessary);
+ v_sort_key integer;
+ v_command text;
+BEGIN
+ FOR v_command IN
+ SELECT the.cmd
+ FROM partmanteau.table_partition_definition(
+ v_partitioned_table_oid, in_partition_name,
+ in_constraints, in_additional_commands) AS the (cmd)
+ LOOP
+ EXECUTE v_command;
+ command := v_command || ';';
+ RETURN NEXT;
+ END LOOP;
+ v_sort_key := COALESCE(
+ (SELECT MAX(tp.sort_key)
+ FROM partmanteau.table_partitions tp
+ WHERE tp.partitioned_table_id = v_partitioned_table_id), 0) + 1;
+ INSERT INTO partmanteau.table_partitions
+ (partitioned_table_id,
+ table_partition_name, effective_at, sort_key)
+ VALUES (v_partitioned_table_id,
+ in_partition_name, in_effective_at, v_sort_key);
+ RETURN;
+END
+$BODY$
+ LANGUAGE plpgsql VOLATILE STRICT;
+
+CREATE FUNCTION
+partmanteau.create_table_partition(in_schema_name text,
+ in_table_name text,
+ in_partition_name text,
+ in_constraints text[],
+ in_additional_commands text[],
+ OUT command TEXT)
+ RETURNS SETOF text AS
+$BODY$
+/**
+ *
+ * This function provides a wrapper for partmanteau.create_table_partition
+ * supplying CURRENT_TIMESTAMP as in_effective_at
+ *
+ * @author Michael Glaesemann <michael.glaesemann@myyearbook.com>
+ *
+ * @see partmanteau.create_table_partition(text, text, text, text[], text[],
+ * timestamp with time zone)
+ *
+ * @param[IN] in_schema_name
+ * @param[IN] in_table_name
+ * @param[IN] in_partition_name
+ * @param[IN] in_constraints
+ * @param[IN] in_additional_commands
+ * @param[OUT] command
+ * @return
+ *
+ */
+ SELECT ctp.command
+ FROM partmanteau.create_table_partition($1, $2, $3, $4, $5,
+ CURRENT_TIMESTAMP) AS ctp (command)
+$BODY$
+ LANGUAGE sql VOLATILE STRICT;
+
+CREATE FUNCTION
+partmanteau.delete_table_partition(in_partitioned_table_id bigint,
+ in_table_partition_name text)
+ RETURNS boolean AS
+$BODY$
+/**
+ *
+ * This function performs the required bookkeeping on the partmanteau
+ * partition metadata tables when a partition is dropped. Does not actually
+ * drop any tables.
+ *
+ * @author Michael Glaesemann <michael.glaesemann@myyearbook.com>
+ *
+ * @private
+ *
+ * @param[IN] in_partitioned_table_id the oid of the partitioned table
+ * @param[IN] in_table_partition_name the name of the partition deleted.
+ * @param[OUT]
+ * @return TRUE if a delete occurred on partmanteau.table_partitions
+ *
+ */
+DECLARE
+ v_partition RECORD;
+ v_did_delete BOOLEAN;
+BEGIN
+ DELETE FROM partmanteau.table_partitions
+ WHERE (partitioned_table_id, table_partition_name)
+ = (in_partitioned_table_id,
+ in_table_partition_name)
+ RETURNING * INTO v_partition;
+ v_did_delete := FOUND;
+ UPDATE partmanteau.table_partitions
+ SET sort_key = -1 * (sort_key - 1)
+ WHERE partitioned_table_id = v_partition.partitioned_table_id
+ AND sort_key > v_partition.sort_key;
+ UPDATE partmanteau.table_partitions
+ SET sort_key = -1 * sort_key
+ WHERE partitioned_table_id = v_partition.partitioned_table_id
+ AND sort_key < 0;
+ RETURN v_did_delete;
+END
+$BODY$
+ LANGUAGE plpgsql VOLATILE STRICT;
+
+CREATE FUNCTION partmanteau.table_oid(in_schema_name text, in_table_name text)
+ RETURNS oid AS
+$BODY$
+/**
+ *
+ * Returns the OID for the given table. This is primarily a convenience
+ * function for casting.
+ *
+ * @author Michael Glaesemann <michael.glaesemann@myyearbook.com>
+ *
+ * @private
+ *
+ * @param[IN] in_schema_name
+ * @param[IN] in_table_name
+ * @return
+ *
+ */
+ SELECT CAST(CAST($1 || '.' || $2 AS regclass) AS oid)
+$BODY$
+ LANGUAGE sql VOLATILE STRICT;
+
+CREATE FUNCTION
+partmanteau.drop_table_partition_older_than(in_schema_name text,
+ in_table_name text,
+ in_age interval)
+ RETURNS boolean AS
+$BODY$
+/**
+ *
+ * This function drops the oldest partition for the given partitioned table that
+ * has an effective_at age equal to or older than the given age. This is
+ * primarily useful for timestamp-based range partitioned tables. It takes into
+ * account effectve_at rather than the sort_key as the sort_key currently tracks
+ * the order in which the partitions were created. The create_table_partition
+ * code should probably be changed to update the sort_key to take into account
+ * a set effective_at timestamp, but it does not currently do so.
+ *
+ * @author Michael Glaesemann <michael.glaesemann@myyearbook.com>
+ *
+ * @param[IN] in_schema_name the schema of the partitioned table
+ * @param[IN] in_table_name the name of the partitioned table
+ * @param[IN] in_age the minimum age of the partition to drop
+ * @param[OUT]
+ * @return TRUE upon successful delete from the partmanteau
+ * partition metadata tables
+ *
+ */
+DECLARE
+ v_partition RECORD;
+ v_sql TEXT;
+BEGIN
+ SELECT INTO v_partition
+ tp.*
+ FROM partmanteau.table_partitions tp
+ WHERE tp.partitioned_table_id
+ = partmanteau.partitioned_table_id(in_schema_name, in_table_name)
+ AND tp.effective_at <= CURRENT_TIMESTAMP - in_age
+ ORDER BY tp.effective_at
+ LIMIT 1;
+ IF NOT FOUND THEN
+ RAISE EXCEPTION 'No partitions found for table %.% older than %',
+ in_schema_name, in_table_name, in_age;
+ END IF;
+ v_sql := 'DROP TABLE '
+ || quote_ident(in_schema_name)
+ || '.' || quote_ident(v_partition.table_partition_name);
+ RAISE DEBUG E'DROP statement:\n%', v_sql;
+ EXECUTE v_sql;
+ RETURN partmanteau.delete_table_partition(v_partition.partitioned_table_id,
+ v_partition.table_partition_name);
+END
+$BODY$
+ LANGUAGE plpgsql VOLATILE STRICT;
+
+CREATE FUNCTION
+partmanteau.partitioned_table_id(IN in_schema_name text,
+ IN in_table_name text,
+ IN in_create_if_necessary boolean,
+ OUT partitioned_table_id bigint)
+ RETURNS bigint AS
+$BODY$
+/**
+ *
+ * This function returns the partitioned_table_id associated with the
+ * given table (identified by schema_name and table_name). If a corresponding
+ * row in partmanteau.partitioned_tables does not exist, one is created if
+ * in_create_if_necessary is TRUE, and an exception is raise otherwise.
+ *
+ * @author Michael Glaesemann <michael.glaesemann@myyearbook.com>
+ *
+ * @private
+ *
+ * @param[IN] in_schema_name
+ * @param[IN] in_table_name
+ * @param[IN] in_create_if_necessary
+ * @param[OUT] partitioned_table_id
+ * @return
+ *
+ */
+BEGIN
+ SELECT INTO partitioned_table_id
+ pt.partitioned_table_id
+ FROM partmanteau.partitioned_tables pt
+ WHERE (pt.schema_name, pt.table_name) = (in_schema_name, in_table_name);
+ IF NOT FOUND THEN
+ IF in_create_if_necessary THEN
+ INSERT INTO partmanteau.partitioned_tables (schema_name, table_name)
+ VALUES (in_schema_name, in_table_name)
+ RETURNING partitioned_tables.partitioned_table_id
+ INTO partitioned_table_id;
+ ELSE
+ RAISE EXCEPTION 'Unknown partitioned table (schema_name, table_name) = (%, %)',
+ quote_literal(in_schema_name), quote_literal(in_table_name);
+ END IF;
+ END IF;
+ RETURN;
+END;
+$BODY$
+ LANGUAGE plpgsql VOLATILE STRICT;
+
+CREATE FUNCTION
+partmanteau.partitioned_table_id(in_schema_name text, in_table_name text)
+ RETURNS bigint AS
+$BODY$
+/**
+ *
+ * This function returns the partitioned_table_id associated with the
+ * given table (identified by schema_name and table_name). An exception
+ * is raised if no corresponding partitioned table is found.
+ *
+ * @author Michael Glaesemann <michael.glaesemann@myyearbook.com>
+ *
+ * @private
+ *
+ * @param[IN] in_schema_name
+ * @param[IN] in_table_name
+ * @param[OUT] partitioned_table_id
+ * @return
+ *
+ */
+ SELECT partmanteau.partitioned_table_id($1, $2, FALSE);
+$BODY$
+ LANGUAGE sql VOLATILE STRICT;
+
+CREATE FUNCTION
+partmanteau.table_acl_commands(IN in_rel_id oid,
+ OUT grantor text,
+ OUT acl_command text)
+ RETURNS SETOF record AS
+$BODY$
+/**
+ *
+ * Returns ACL commands to apply the appropriate access to the given table.
+ *
+ * @author Michael Glaesemann <michael.glaesemann@myyearbook.com>
+ *
+ * @private
+ *
+ * @param[IN] in_rel_id
+ * @param[OUT] grantor
+ * @param[OUT] acl_command
+ * @return
+ *
+ */
+SELECT grantor,
+ array_to_string(CASE WHEN is_grantable
+ THEN array_append(str_parts, 'WITH GRANT OPTION')
+ ELSE str_parts END, ' ') AS acl_command
+ FROM (
+ SELECT grantor,
+ ARRAY['GRANT', array_to_string(privilege_types, ', '),
+ 'ON', table_name, 'TO', quote_ident(grantee)] AS str_parts,
+ is_grantable
+ FROM (SELECT u_grantor.rolname::information_schema.sql_identifier AS grantor,
+ grantee.rolname::information_schema.sql_identifier AS grantee,
+ quote_ident(nspname) || '.' || quote_ident(relname) AS table_name,
+ array_agg(privilege_type) as privilege_types,
+ aclcontains(c.relacl,
+ makeaclitem(grantee.oid,
+ u_grantor.oid,
+ privilege_type, true)) AS is_grantable
+ FROM pg_class c
+ JOIN pg_namespace nc ON c.relnamespace = nc.oid
+ JOIN (SELECT pg_authid.oid, pg_authid.rolname
+ FROM pg_authid
+ UNION ALL
+ SELECT 0::oid AS oid, 'PUBLIC') grantee(oid, rolname)
+ ON grantee.oid <> c.relowner
+ CROSS JOIN pg_authid u_grantor
+ CROSS JOIN (VALUES ('SELECT'), ('DELETE'),
+ ('INSERT'), ('UPDATE'),
+ ('REFERENCES'), ('TRIGGER')) AS pr(privilege_type)
+ WHERE c.oid = $1
+ AND aclcontains(c.relacl,
+ makeaclitem(grantee.oid,
+ u_grantor.oid,
+ privilege_type, false))
+ AND (pg_has_role(u_grantor.oid, 'USAGE'::text)
+ OR pg_has_role(grantee.oid, 'USAGE'::text)
+ OR grantee.rolname = 'PUBLIC'::name)
+ GROUP BY u_grantor.rolname,
+ grantee.rolname,
+ table_name,
+ is_grantable) AS privs) AS cmds;
+$BODY$
+ LANGUAGE sql STABLE;
+
+CREATE FUNCTION partmanteau.table_constraint_index_definitions(in_rel_id oid)
+ RETURNS SETOF text AS
+$BODY$
+/**
+ *
+ * Returns the index definitions associated with table constraints
+ * on the table with the given oid.
+ *
+ * @author Michael Glaesemann <michael.glaesemann@myyearbook.com>
+ *
+ * @private
+ *
+ * @param[IN] in_rel_id
+ *
+ */
+ SELECT pg_get_indexdef(indexrelid)
+ FROM pg_index i
+ LEFT JOIN pg_depend d
+ ON i.indexrelid = d.objid
+ AND d.classid = CAST('pg_catalog.pg_class' AS regclass)
+ AND d.refclassid = CAST('pg_catalog.pg_constraint' AS regclass)
+ AND d.deptype = 'i'
+ WHERE i.indrelid = $1
+ AND d.objid IS NULL;
+$BODY$
+ LANGUAGE sql STABLE STRICT;
+
+CREATE FUNCTION
+partmanteau.table_index_definitions(IN in_rel_id oid,
+ IN in_exclude_constraints boolean,
+ OUT index_name text,
+ OUT index_definition text)
+ RETURNS SETOF record AS
+$BODY$
+/**
+ *
+ * Returns index names and definitions on the table with the given oid.
+ *
+ * @author Michael Glaesemann <michael.glaesemann@myyearbook.com>
+ *
+ * @private
+ *
+ * @param[IN] in_rel_id
+ * @param[IN] in_exclude_constraints whether to exclude indexes defined
+ * to support UNIQUE and PRIMARY KEY constraints
+ * @param[OUT]
+ * @return
+ *
+ */
+ SELECT CAST(relname AS TEXT), pg_get_indexdef(indexrelid)
+ FROM pg_index i
+ JOIN pg_class c ON i.indexrelid = c.oid
+ LEFT JOIN pg_depend d
+ ON i.indexrelid = d.objid
+ AND d.classid = CAST('pg_catalog.pg_class' AS regclass)
+ AND d.refclassid = CAST('pg_catalog.pg_constraint' AS regclass)
+ AND d.deptype = 'i'
+ WHERE i.indrelid = $1
+ AND i.indisvalid
+ AND CASE WHEN $2 THEN d.objid IS NULL ELSE TRUE END
+$BODY$
+ LANGUAGE sql STABLE STRICT;
+
+CREATE FUNCTION
+partmanteau.table_index_definitions(IN in_rel_id oid,
+ OUT index_name text,
+ OUT index_definition text)
+ RETURNS SETOF record AS
+$BODY$
+/**
+ *
+ * Returns all index names and definitions on the table with the given oid.
+ *
+ * @author Michael Glaesemann <michael.glaesemann@myyearbook.com>
+ *
+ * @private
+ *
+ * @param[IN] in_rel_id
+ * @param[OUT] index_name
+ * @param[OUT] index_definition
+ * @return
+ *
+ */
+ SELECT index_name, index_definition
+ FROM partmanteau.table_index_definitions($1, FALSE)
+$BODY$
+ LANGUAGE sql STABLE STRICT;
+
+CREATE FUNCTION
+partmanteau.table_partition_definition(in_rel_oid oid,
+ in_partition_name text,
+ in_partition_constraints text[],
+ in_additional_commands text[])
+ RETURNS text AS
+$BODY$
+/**
+ *
+ * This function returns the commands necessary to create a new partition
+ * for the given table. In addition to the inherited table creation statement,
+ * it returns commands to
+ * - create primary key and unique constraints
+ * - create indexes
+ * - set appropriate ownership
+ * - grant required permissions
+ * - set table attributes (such as FILLFACTOR)
+ *
+ * These settings are based on those of the parent table.
+ * It does not generate foreign key DDL or comments.
+ *
+ * Index creation statements assume that the given indexes are prepended
+ * with the table name. This should probably be changed to generate a logical
+ * index name based on the definition, but does not currently do so.
+ *
+ * @author Michael Glaesemann <michael.glaesemann@myyearbook.com>
+ *
+ * @private
+ *
+ * @param[IN] in_rel_oid oid of the table to partition
+ * @param[IN] in_partition_name name of the partition to create
+ * @param[IN] in_partition_constraints constraints added to the partition
+ * @param[IN] in_additional_commands arbitrary commands to run after the
+ * partition creation
+ * @param[OUT]
+ * @return
+ *
+ */
+DECLARE
+ k_primary_key_contype constant "char" := 'p';
+ k_unique_contype constant "char" := 'u';
+ -- k_check_contype constant "char" := 'c';
+ -- Sometimes foreign keys are going to be to partitioned tables,
+ -- and sometimes not, so we leave this up to the additional_commands argument.
+ -- k_foreign_key_contype constant "char" := 'f';
+ k_exclude_contraint_indexes constant BOOLEAN := TRUE;
+ k_empty_text_array constant TEXT[] := '{}';
+ v_rel record;
+ v_qualified_table_name text;
+ v_qualified_partition_name text;
+ v_cmds text[];
+ v_cmd_parts text[];
+ v_cmd_subparts text[];
+ v_constraint record;
+ v_partition_name text := in_partition_name;
+ v_owner RECORD;
+ v_constraint_name text;
+ v_constraint_definition text;
+ v_index RECORD;
+ v_index_definition text;
+BEGIN
+ SELECT INTO v_rel
+ rel.*, nspname
+ FROM pg_class rel
+ JOIN pg_namespace nsp ON nsp.oid = rel.relnamespace
+ WHERE rel.oid = in_rel_oid;
+ IF NOT FOUND THEN
+ RAISE EXCEPTION $msg$Relation with oid % not found.$msg$, in_rel_oid;
+ END IF;
+ RAISE DEBUG $msg$v_rel: %$msg$, v_rel;
+ v_qualified_partition_name := quote_ident(v_rel.nspname)
+ || '.' || quote_ident(v_partition_name);
+ v_qualified_table_name := quote_ident(v_rel.nspname)
+ || '.' || quote_ident(v_rel.relname);
+ v_cmd_parts := array_append(v_cmd_parts, 'CREATE TABLE');
+ v_cmd_parts := array_append(v_cmd_parts, v_qualified_partition_name);
+ v_cmd_parts := array_append(v_cmd_parts, E'(\n');
+
+ -- add primary key and unique constraints,
+ -- which aren't inherited by default in 8.3
+ v_cmd_subparts := NULL;
+ FOR v_constraint IN
+ SELECT c.*
+ FROM pg_constraint c
+ WHERE c.conrelid = in_rel_oid
+ AND c.contype IN (k_unique_contype,
+ k_primary_key_contype)
+ LOOP
+ RAISE DEBUG $msg$v_constraint: %$msg$, v_constraint;
+ RAISE DEBUG $msg$v_constraint.conname: %$msg$, v_constraint.conname;
+ v_constraint_name := v_constraint.conname;
+ IF v_constraint.contype IN (k_unique_contype,
+ k_primary_key_contype) THEN
+ -- Let Postres name primary keys and unique constraints to ensure
+ -- uniqueness of the underlying index name.
+ v_constraint_definition := pg_get_constraintdef(v_constraint.oid);
+ ELSE
+ v_constraint_definition := array_to_string(
+ ARRAY['CONSTRAINT',
+ quote_ident(v_constraint_name),
+ pg_get_constraintdef(v_constraint.oid)], ' ');
+ END IF;
+ v_cmd_subparts := array_append(v_cmd_subparts, v_constraint_definition);
+ END LOOP;
+ -- Add partition constraint
+ IF in_partition_constraints <> k_empty_text_array THEN
+ FOR v_idx IN 1..array_upper(in_partition_constraints, 1) LOOP
+ v_cmd_subparts := array_append(v_cmd_subparts,
+ 'CHECK (' || in_partition_constraints[v_idx] || ')');
+ END LOOP;
+ v_cmd_parts := array_append(v_cmd_parts,
+ array_to_string(v_cmd_subparts, E',\n '));
+ END IF;
+ -- add FOREIGN KEY constraints
+ -- FIXME not implemented
+ v_cmd_parts := array_append(v_cmd_parts, E'\n)');
+ v_cmd_parts := array_append(v_cmd_parts, 'INHERITS (');
+ v_cmd_parts := array_append(v_cmd_parts, CAST(CAST(in_rel_oid AS regclass) AS TEXT));
+ v_cmd_parts := array_append(v_cmd_parts, ')');
+ IF v_rel.reloptions IS NOT NULL THEN
+ v_cmd_parts := array_append(v_cmd_parts,
+ 'WITH (' || array_to_string(v_rel.reloptions, ', ') || ')');
+ END IF;
+
+ v_cmds := array_append(v_cmds, array_to_string(v_cmd_parts, ' '));
+ FOR v_index IN
+ SELECT index_name, index_definition
+ FROM partmanteau.table_index_definitions(in_rel_oid, k_exclude_contraint_indexes)
+ LOOP
+ -- FIXME: regexp replace doesn't catch case where index name doesn't include
+ -- current table name.
+ -- perhaps we should just rename the index?
+ v_index_definition := replace(v_index.index_definition,
+ 'INDEX ' || v_rel.relname,
+ 'INDEX ' || in_partition_name);
+ v_index_definition := replace(v_index_definition,
+ 'ON ' || quote_ident(v_rel.nspname)
+ || '.' || quote_ident(v_rel.relname),
+ 'ON ' || v_qualified_partition_name);
+ v_cmds := array_append(v_cmds, v_index_definition);
+ END LOOP;
+ -- set ownership
+ SELECT INTO v_owner
+ *
+ FROM pg_authid
+ WHERE oid = v_rel.relowner;
+ v_cmds := array_append(v_cmds,
+ array_to_string(
+ ARRAY['ALTER TABLE', v_qualified_partition_name,
+ 'OWNER TO', quote_ident(v_owner.rolname)], ' '));
+ -- add grants
+ v_cmds := array_cat(v_cmds,
+ ARRAY(SELECT replace(acl_command,
+ 'ON ' || v_qualified_table_name,
+ 'ON ' || v_qualified_partition_name)
+ FROM partmanteau.table_acl_commands(in_rel_oid)));
+ -- add comment
+ -- FIXME not implemented
+ v_cmds := array_cat(v_cmds, in_additional_commands);
+ RAISE DEBUG $msg$v_cmds: %$msg$, v_cmds;
+ RETURN array_to_string(ARRAY(SELECT v_cmds[idx] || ';'
+ FROM generate_series(1,
+ array_upper(v_cmds, 1)) AS the (idx)), E'\n');
+END
+$BODY$
+ LANGUAGE plpgsql VOLATILE STRICT;
+
+CREATE FUNCTION partmanteau.quote_ident(text[])
+ RETURNS text[] AS
+$BODY$
+/**
+ *
+ * Returns a text array equivalent to the argument with
+ * quote_ident applied to each element.
+ *
+ * @author Michael Glaesemann <michael.glaesemann@myyearbook.com>
+ *
+ * @private
+ *
+ * @param[IN] text[]
+ * @param[OUT]
+ * @return
+ *
+ */
+ SELECT ARRAY(SELECT quote_ident($1[idx])
+ FROM generate_series(1, array_upper($1, 1)) AS the (idx));
+$BODY$
+ LANGUAGE sql IMMUTABLE STRICT;
+
+CREATE FUNCTION
+partmanteau.insert_statement(in_schema_name text,
+ in_table_name text,
+ in_columns text[],
+ in_values text[])
+ RETURNS text AS
+$BODY$
+/**
+ *
+ * Returns an INSERT statement for the given table, columns, and values.
+ * The columns are processed within the function with quote_ident().
+ * The values need to be processed with quote_literal *prior* to calling
+ * this function if necessary.
+ *
+ * @author Michael Glaesemann <michael.glaesemann@myyearbook.com>
+ *
+ * @param[IN] in_schema_name
+ * @param[IN] in_table_name
+ * @param[IN] in_columns array of text represenation of columns
+ * @param[IN] in_values array of text represention of values
+ * (pre-processed with quote_ident)
+ * @param[OUT]
+ * @return
+ *
+ */
+ SELECT array_to_string(ARRAY['INSERT INTO',
+ quote_ident($1) || '.' || quote_ident($2),
+ '(', array_to_string(partmanteau.quote_ident($3), ','), ')',
+ 'VALUES (', array_to_string($4, ','), ')'], ' ');
+$BODY$
+ LANGUAGE sql IMMUTABLE STRICT;
+
+COMMIT;
120 rakefile
@@ -0,0 +1,120 @@
+@db = {}
+@db[:host] = ENV['PGTAP_HOST'] || ENV['PGHOST']
+@db[:port] = ENV['PGTAP_PORT'] || ENV['PGPORT']
+@db[:user] = ENV['PGTAP_USER'] || ENV['PGUSER']
+@db[:name] = ENV['PGTAP_DBNAME']
+@db[:test_user] = ENV['PGTAP_TEST_USER'] || 'postgres'
+
+@test_schema = 'partmanteau'
+
+PSQL = 'psql'
+def psql(options={})
+ defaults = {
+ :dbname => @db[:name],
+ :user => @db[:user],
+ :port => @db[:port],
+ :host => @db[:host] }
+ options = defaults.merge(options)
+ opts = %w( -qtAX
+ --set ON_ERROR_ROLLBACK=1
+ --set ON_ERROR_STOP=1 )
+ opt_string = opts.join " "
+ cmd = %(#{PSQL} #{opt_string})
+ { :host => '-h',
+ :port => '-p',
+ :user => '-U',
+ :dbname => '-d',
+ :file => '-f',
+ :command => '-c'
+ }.each do |k,v|
+ if options[k]
+ opt = options[k].gsub('"', '\"')
+ cmd << %( #{v} "#{opt}")
+ end
+ end
+ sh cmd
+end
+
+EXCLUDED_SQL_REGEXP = /^xxx_/
+def load_sql(dir)
+ chdir(dir) do
+ FileList['[0123456789]*.sql'].sort.each do |sql|
+ verbose(true) do
+ psql({ :file => sql }) unless EXCLUDED_SQL_REGEXP.match(sql)
+ end
+ end
+ end
+end
+
+def run_tests(do_drop=true)
+ psql :command => %(CREATE DATABASE "#{@db[:name]}" WITH ENCODING 'UTF8'), :dbname => 'postgres'
+ priv_dirs = []
+ begin
+ verbose(false) do
+ load_sql File.join(File.dirname(__FILE__), 'test', 'schema')
+ psql :file => 'partmanteau.sql'
+ load_sql File.join(File.dirname(__FILE__))
+ %w(lib fixtures).each do |d|
+ load_sql File.join(File.dirname(__FILE__), 'test', d)
+ end
+ test_dir = File.join(File.dirname(__FILE__), 'test', 'tests')
+ load_sql test_dir
+ priv_dirs = Dir["#{test_dir}/*/"].map { |a| File.basename(a) }
+ priv_dirs.each do |dir|
+ load_sql File.join(File.dirname(__FILE__), 'test', 'tests', dir)
+ end
+ end
+ # do basic tests
+ psql({ :user => @db[:test_user],
+ :command => %(SET search_path TO pgtap, public; SELECT * FROM pgtap.runtests('#{@test_schema}', '^test_');) })
+ # do tests with specific users
+ priv_dirs.each do |dir|
+ psql({ :user => dir,
+ :command => %(SET search_path TO pgtap, public; SELECT * FROM pgtap.runtests('#{@test_schema}', '^#{dir}_test_');) })
+ end
+ rescue
+ ensure
+ drop_test_database if do_drop
+ end
+end
+
+def run_tests_no_drop
+ run_tests(false)
+end
+
+def run_remote_tests
+ chdir('test/remote') do
+ sh %(./test.sh &> results/remote.out)
+ sh %(diff expected/remote.out results/remote.out > results/remote.diff) do |ok, res|
+ if ! ok
+ puts 'remote test FAILED. results differ from expected. See test/remote/results/remote.diff for details'
+ else
+ puts 'remote test PASSED.'
+ end
+ end
+ end
+end
+
+desc "Run tests, but don't drop test database"
+task :test_no_drop do
+ run_tests_no_drop
+end
+
+desc "Run tests"
+task :test do
+ run_tests
+end
+
+desc 'Drop test db'
+task :dropdb do
+ drop_test_database
+end
+
+def drop_test_database
+ psql :command => %(DROP DATABASE "#{@db[:name]}"), :dbname => 'postgres'
+end
+
+desc 'Run remote tests'
+task :test_remote do
+ run_remote_tests
+end
12 test/lib/000_create_language_plpgsql_unless_exists.sql
@@ -0,0 +1,12 @@
+CREATE FUNCTION
+public.create_language_plpgsql()
+RETURNS BOOLEAN
+STRICT LANGUAGE sql AS $body$
+ CREATE LANGUAGE PLPGSQL;
+ SELECT TRUE;
+$body$;
+SELECT public.create_language_plpgsql()
+ WHERE NOT EXISTS (SELECT TRUE
+ FROM pg_catalog.pg_language
+ WHERE lanname = 'plpgsql');
+DROP FUNCTION public.create_language_plpgsql();
7,327 test/lib/001_pgtap.sql
7,327 additions, 0 deletions not shown because the diff is too large. Please use a local Git client to view these changes.
1 test/lib/002_grant_usage_on_pgtap.sql
@@ -0,0 +1 @@
+GRANT USAGE ON SCHEMA pgtap TO public;
2 test/schema/001_create_language_plpgsql.sql
@@ -0,0 +1,2 @@
+CREATE LANGUAGE PLPGSQL;
+
10 test/tests/001_test_truth.sql
@@ -0,0 +1,10 @@
+CREATE FUNCTION
+partmanteau.test_truth()
+RETURNS SETOF TEXT
+LANGUAGE PLPGSQL AS $body$
+DECLARE
+BEGIN
+ RETURN NEXT ok(TRUE, 'testing truth');
+ RETURN;
+END
+$body$;
227 test/tests/002_time_range_partitioning.sql
@@ -0,0 +1,227 @@
+CREATE FUNCTION
+partmanteau.test_timestamp_range_partition()
+RETURNS SETOF TEXT
+LANGUAGE PLPGSQL AS $body$
+DECLARE
+ k_schema_name CONSTANT TEXT := 'current_cost';
+ k_partitioned_table_name CONSTANT TEXT := 'readings';
+ v_sql TEXT;
+ v_commands TEXT[];
+ v_first_partition_timestamp TIMESTAMP WITH TIME ZONE := '2010-02-15';
+ v_second_partition_timestamp TIMESTAMP WITH TIME ZONE := '2010-03-15';
+ v_third_partition_timestamp TIMESTAMP WITH TIME ZONE := '2010-04-15';
+ v_first_partition_table_name TEXT;
+BEGIN
+ v_sql := $ddl$
+ CREATE SCHEMA current_cost;
+
+ CREATE TABLE current_cost.monitors
+ (
+ monitor_id UUID PRIMARY KEY,
+ monitor_label TEXT NOT NULL
+ );
+
+ CREATE TABLE current_cost.readings
+ (
+ monitor_id UUID NOT NULL,
+ sensor_radio_id INT NOT NULL,
+ sensor INT NOT NULL,
+ reading_id UUID NOT NULL,
+ read_at TIMESTAMP WITH TIME ZONE NOT NULL,
+ fahrenheit REAL NOT NULL
+ );
+
+ CREATE UNIQUE INDEX readings_key ON current_cost.readings (reading_id);
+ CREATE UNIQUE INDEX readings_reading_id_read_at_key
+ ON current_cost.readings (reading_id, read_at);
+ COMMENT ON INDEX current_cost.readings_reading_id_read_at_key IS
+ 'Over-constrained including read_at to allow foreign key references.';
+
+ CREATE INDEX readings_read_at_key ON current_cost.readings (read_at);
+ ALTER TABLE current_cost.readings ADD FOREIGN KEY (monitor_id)
+ REFERENCES current_cost.monitors (monitor_id)
+ ON DELETE CASCADE;
+
+ CREATE FUNCTION
+ current_cost.readings_partition_name(in_timestamp timestamp with time zone)
+ RETURNS text AS
+ $BODY$
+ /**
+ *
+ * Returns a normalized recent readings partition name for the
+ * given timestamp. Readings are partitioned by week.
+ *
+ * @private
+ *
+ * @param[IN] in_timestamp
+ * @param[OUT]
+ * @return
+ *
+ */
+ SELECT 'readings_' || to_char(date_trunc('month', $1), 'YYYYMMDD')
+ $BODY$
+ LANGUAGE sql IMMUTABLE STRICT;
+
+ CREATE FUNCTION
+ current_cost.create_readings_partition(in_timestamp timestamp with time zone)
+ RETURNS SETOF text AS
+ $BODY$
+ /**
+ *
+ * Creates a partition for a month's worth of readings for the month
+ * containing the given timestamp.
+ *
+ * @param[IN] in_timestamp
+ * @return
+ *
+ */
+ DECLARE
+ k_schema_name TEXT := 'current_cost';
+ k_base_table_name TEXT := 'readings';
+ k_partition_column TEXT := 'read_at';
+ v_commands TEXT[];
+ v_partition_name TEXT := current_cost.readings_partition_name(in_timestamp);
+ v_qualified_partition_name TEXT := quote_ident(k_schema_name) || '.'
+ || quote_ident(v_partition_name);
+ k_width INTERVAL := '1 month';
+ v_lower_bound TIMESTAMP WITH TIME ZONE := date_trunc('month', in_timestamp);
+ v_upper_bound TIMESTAMP WITH TIME ZONE := v_lower_bound + k_width;
+ v_partition_constraint TEXT := array_to_string(
+ ARRAY[quote_ident(k_partition_column),
+ '>=', quote_literal(v_lower_bound),
+ 'AND', quote_ident(k_partition_column),
+ '<', quote_literal(v_upper_bound)], ' ');
+ v_additional_commands TEXT[];
+ BEGIN
+ v_additional_commands := ARRAY[
+ array_to_string(ARRAY['ALTER TABLE',
+ v_qualified_partition_name,
+ 'ADD FOREIGN KEY (monitor_id)',
+ 'REFERENCES current_cost.monitors (monitor_id)'], ' ')];
+ RETURN QUERY
+ SELECT command
+ FROM partmanteau.create_table_partition(
+ k_schema_name, k_base_table_name,
+ v_partition_name,
+ ARRAY[v_partition_constraint],
+ v_additional_commands,
+ v_lower_bound) AS the (command);
+ RETURN;
+ END
+ $BODY$
+ LANGUAGE plpgsql VOLATILE STRICT;
+
+ CREATE FUNCTION current_cost.partition_readings()
+ RETURNS trigger AS
+ $BODY$
+ /**
+ *
+ * This trigger function partitions inserts on current_cost.readings into
+ * the appropriate current_cost.readings partition.
+ *
+ */
+ DECLARE
+ k_schema CONSTANT TEXT := 'current_cost';
+ k_columns CONSTANT TEXT[] := ARRAY['monitor_id',
+ 'sensor_radio_id',
+ 'sensor',
+ 'reading_id',
+ 'read_at',
+ 'fahrenheit'];
+ v_values TEXT[];
+ v_partition_name TEXT;
+ v_sql TEXT;
+ BEGIN
+ IF TG_OP = 'INSERT' THEN
+ v_partition_name := current_cost.readings_partition_name(NEW.read_at);
+ v_values := ARRAY[quote_literal(NEW.monitor_id),
+ quote_literal(NEW.sensor_radio_id),
+ quote_literal(NEW.sensor),
+ quote_literal(NEW.reading_id),
+ quote_literal(NEW.read_at),
+ quote_literal(NEW.fahrenheit)];
+ v_sql := partmanteau.insert_statement(k_schema, v_partition_name,
+ k_columns, v_values);
+ EXECUTE v_sql;
+ RETURN NULL;
+ END IF;
+ RETURN NEW;
+ END
+ $BODY$
+ LANGUAGE plpgsql VOLATILE STRICT;
+
+ CREATE TRIGGER partition_readings
+ BEFORE INSERT ON current_cost.readings
+ FOR EACH ROW
+ EXECUTE PROCEDURE current_cost.partition_readings();
+$ddl$;
+ RETURN NEXT lives_ok(v_sql, 'created basic schema and partitioning functions.');
+
+ RETURN NEXT ok(NOT EXISTS (SELECT TRUE FROM partmanteau.partitioned_tables),
+ 'have no partitioned tables records before creating partitions');
+ RETURN NEXT ok(NOT EXISTS (SELECT TRUE FROM partmanteau.table_partitions),
+ 'have no table partition records before creating partitions');
+ v_commands := ARRAY(SELECT cmd
+ FROM current_cost.create_readings_partition(
+ v_first_partition_timestamp) AS the (cmd));
+
+ v_first_partition_table_name
+ := current_cost.readings_partition_name(v_first_partition_timestamp);
+ RETURN NEXT is(COUNT(*), CAST(1 AS BIGINT),
+ 'have a single partitioned table record after creating first partition')
+ FROM partmanteau.partitioned_tables;
+
+ RETURN NEXT is(COUNT(*), CAST(1 AS BIGINT),
+ 'have a single table partition record after creating first partition')
+ FROM partmanteau.table_partitions;
+
+
+ RETURN NEXT ok(EXISTS (SELECT TRUE
+ FROM partmanteau.table_partitions
+ WHERE table_partition_name = v_first_partition_table_name),
+ 'first partition exists in table_partitions after dropping oldest partition');
+
+ v_commands := ARRAY(SELECT cmd
+ FROM current_cost.create_readings_partition(
+ v_second_partition_timestamp) AS the (cmd));
+
+ RETURN NEXT is(COUNT(*), CAST(1 AS BIGINT),
+ 'have a single partitioned table record after creating second partition')
+ FROM partmanteau.partitioned_tables;
+
+ RETURN NEXT is(COUNT(*), CAST(2 AS BIGINT),
+ 'have two table partition records after creating second partition')
+ FROM partmanteau.table_partitions;
+
+ v_commands := ARRAY(SELECT cmd
+ FROM current_cost.create_readings_partition(
+ v_third_partition_timestamp) AS the (cmd));
+
+ RETURN NEXT is(COUNT(*), CAST(1 AS BIGINT),
+ 'have a single partitioned table record after creating third partition')
+ FROM partmanteau.partitioned_tables;
+
+ RETURN NEXT is(COUNT(*), CAST(3 AS BIGINT),
+ 'have three table partition records after creating third partition')
+ FROM partmanteau.table_partitions;
+
+ RETURN NEXT lives_ok('SELECT partmanteau.drop_table_partition_older_than('
+ || array_to_string(ARRAY[quote_literal(k_schema_name),
+ quote_literal(k_partitioned_table_name),
+ quote_literal('1 month')], ',') || ')',
+ 'partmanteau.drop_table_partition_older_than throws no error');
+
+ RETURN NEXT is(COUNT(*), CAST(2 AS BIGINT),
+ 'have two table partition records after dropping oldest partition')
+ FROM partmanteau.table_partitions;
+
+ RETURN NEXT ok(NOT EXISTS (SELECT TRUE
+ FROM partmanteau.table_partitions
+ WHERE table_partition_name = v_first_partition_table_name),
+ 'first partition does not exist in table_partitions after dropping oldest partition');
+
+ RETURN;
+END
+$body$;
+
+

0 comments on commit 9be71d4

Please sign in to comment.