├── .gitignore ├── .travis.yml ├── Gemfile ├── Gemfile.lock ├── LICENSE.txt ├── README.md ├── Rakefile ├── lib ├── pg_partition_manager.rb └── pg_partition_manager │ └── version.rb ├── pg_partition_manager.gemspec └── test ├── pg_partition_manager_test.rb └── test_helper.rb /.gitignore: -------------------------------------------------------------------------------- 1 | /.bundle/ 2 | /.yardoc 3 | /_yardoc/ 4 | /coverage/ 5 | /doc/ 6 | /pkg/ 7 | /spec/reports/ 8 | /tmp/ 9 | -------------------------------------------------------------------------------- /.travis.yml: -------------------------------------------------------------------------------- 1 | --- 2 | sudo: false 3 | language: ruby 4 | cache: bundler 5 | rvm: 6 | - 2.6.5 7 | before_install: gem install bundler -v 2.0.2 8 | -------------------------------------------------------------------------------- /Gemfile: -------------------------------------------------------------------------------- 1 | source "https://rubygems.org" 2 | 3 | # Specify your gem's dependencies in pg_partition_manager.gemspec 4 | gemspec 5 | -------------------------------------------------------------------------------- /Gemfile.lock: -------------------------------------------------------------------------------- 1 | PATH 2 | remote: . 3 | specs: 4 | pg_partition_manager (0.1.0) 5 | pg (~> 1.0) 6 | ulid (~> 1.3) 7 | 8 | GEM 9 | remote: https://rubygems.org/ 10 | specs: 11 | ast (2.4.0) 12 | jaro_winkler (1.5.3) 13 | minitest (5.12.2) 14 | parallel (1.18.0) 15 | parser (2.6.5.0) 16 | ast (~> 2.4.0) 17 | pg (1.1.4) 18 | rainbow (3.0.0) 19 | rake (13.0.6) 20 | rubocop (0.72.0) 21 | jaro_winkler (~> 1.5.1) 22 | parallel (~> 1.10) 23 | parser (>= 2.6) 24 | rainbow (>= 2.2.2, < 4.0) 25 | ruby-progressbar (~> 1.7) 26 | unicode-display_width (>= 1.4.0, < 1.7) 27 | rubocop-performance (1.4.1) 28 | rubocop (>= 0.71.0) 29 | ruby-progressbar (1.10.1) 30 | standard (0.1.4) 31 | rubocop (~> 0.72.0) 32 | rubocop-performance (~> 1.4.0) 33 | ulid (1.3.0) 34 | unicode-display_width (1.6.0) 35 | 36 | PLATFORMS 37 | ruby 38 | 39 | DEPENDENCIES 40 | bundler (~> 2.0) 41 | minitest (~> 5.0) 42 | pg_partition_manager! 43 | rake (~> 13.0) 44 | standard 45 | 46 | BUNDLED WITH 47 | 2.0.2 48 | -------------------------------------------------------------------------------- /LICENSE.txt: -------------------------------------------------------------------------------- 1 | The MIT License (MIT) 2 | 3 | Copyright (c) 2019 Honeybadger Industries, LLC 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in 13 | all copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN 21 | THE SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # PgPartitionManager 2 | 3 | Inspired by [pg_partman][1], this gem helps you manage [partitioned tables][2] in PostgreSQL >= 10. 4 | 5 | ## Installation 6 | 7 | Add this line to your application's Gemfile: 8 | 9 | ```ruby 10 | gem 'pg_partition_manager' 11 | ``` 12 | 13 | And then execute: 14 | 15 | ```shell 16 | bundle 17 | ``` 18 | 19 | Or install it yourself as: 20 | 21 | ```shell 22 | gem install pg_partition_manager 23 | ``` 24 | 25 | ## Usage 26 | 27 | This is meant to be used via a daily cron job, to ensure that new tables are created before they are needed, and old tables are dropped when they aren't needed anymore. 28 | 29 | Imagine a cron job like this: 30 | 31 | ```shell 32 | @daily cd /app && ./bin/bundle exec ./script/make_partitions.rb 33 | ``` 34 | 35 | And a Ruby script like this: 36 | 37 | ```ruby 38 | #!/usr/bin/env/ruby 39 | 40 | require "pg_partition_manager" 41 | 42 | PgPartitionManager::Time.process([ 43 | {parent_table: "public.events", period: "month", premake: 1, retain: 3}, 44 | {parent_table: "public.stats", period: "week", premake: 4, retain: 4}, 45 | {parent_table: "public.observations", period: "day", retain: 7, ulid: true, cascade: true}, 46 | # self referencing comment table (parent_id) so we can have comments on other comments 47 | {parent_table: "public.comments", period: "day", retain: 7, ulid: true, cascade: true, truncate: true}, 48 | ]) 49 | ``` 50 | 51 | If the cron job runs on Monday, September 30th, 2019, and you had created the `events`, `stats`, and `observations` tables in your public schema, the following tables would be created: 52 | * `public.events_p2019_09_01` 53 | * `public.events_p2019_10_01` 54 | * `public.stats_p2019_09_30` 55 | * `public.stats_p2019_10_07` 56 | * `public.stats_p2019_10_14` 57 | * `public.stats_p2019_10_21` 58 | * `public.observations_p2019_09_30` 59 | * `public.observations_p2019_10_01` 60 | * `public.observations_p2019_10_02` 61 | * `public.observations_p2019_10_03` 62 | * `public.observations_p2019_10_04` 63 | 64 | The `premake` option specifies how many tables to create for dates after the current period, and the `retain` option specifies how many tables to keep for dates before the current period. You can additionally add the ulid flag if your database uses [ULID](https://github.com/rafaelsales/ulid)s for primary keys (see [Starr's article](https://www.honeybadger.io/blog/uuids-and-ulids/) for a good overview on "web-scale" ids). 65 | 66 | A couple of notes regarding the `cascade` and `truncate` flags. Use the `cascade` option if you have dependent views or foreign key contraints (see [details on the drop table command](https://www.postgresql.org/docs/current/sql-droptable.html)). Use the `truncate` if you have dependent tables that are not partitioned can afford a truncate table (cleans out any forign key dependent rows) before the drop (see [details on the pg truncate command](https://www.postgresql.org/docs/current/sql-truncate.html)). The `truncate` option might also be useful if you have self referencing tables (clean out dependent rows). If using `truncate` it must be used in conjucation with the `cascade` flag. 67 | 68 | This gem uses the [pg gem][3] to connect to your database, and it assumes the DATABASE\_URL environment variable is populated with connection info. If this environment variable isn't defined, a connection to the server running on localhost will be attempted. 69 | 70 | 71 | ## Development 72 | 73 | After checking out the repo, run `bin/setup` to install dependencies. Then, run `rake test` to run the tests. You can also run `bin/console` for an interactive prompt that will allow you to experiment. 74 | 75 | To install this gem onto your local machine, run `bundle exec rake install`. To release a new version, update the version number in `version.rb`, and then run `bundle exec rake release`, which will create a git tag for the version, push git commits and tags, and push the `.gem` file to [rubygems.org](https://rubygems.org). 76 | 77 | ## Contributing 78 | 79 | Bug reports and pull requests are welcome on GitHub at https://github.com/honeybadger-io/pg_partition_manager. 80 | 81 | ## License 82 | 83 | The gem is available as open source under the terms of the [MIT License](https://opensource.org/licenses/MIT). 84 | 85 | [1]: https://github.com/pgpartman/pg_partman 86 | [2]: https://www.postgresql.org/docs/current/ddl-partitioning.html 87 | [3]: https://rubygems.org/gems/pg 88 | -------------------------------------------------------------------------------- /Rakefile: -------------------------------------------------------------------------------- 1 | require "bundler/gem_tasks" 2 | require "rake/testtask" 3 | require "standard/rake" 4 | 5 | Rake::TestTask.new(:test) do |t| 6 | t.libs << "test" 7 | t.libs << "lib" 8 | t.test_files = FileList["test/**/*_test.rb"] 9 | end 10 | 11 | task default: [:standard, :test] 12 | -------------------------------------------------------------------------------- /lib/pg_partition_manager.rb: -------------------------------------------------------------------------------- 1 | require "pg_partition_manager/version" 2 | require "date" 3 | require "pg" 4 | require "ulid" 5 | 6 | module PgPartitionManager 7 | class Error < StandardError; end 8 | 9 | class Time 10 | def initialize(partition, start: Date.today, db: nil) 11 | raise ArgumentError, "Period must be 'month', 'week', or 'day'" unless ["month", "week", "day"].include?(partition[:period]) 12 | 13 | @partition = partition 14 | @start = 15 | case partition[:period] 16 | when "month" 17 | start - start.day + 1 # First day of the current month 18 | when "week" 19 | start - (start.cwday - 1) # First calendar day of the current week 20 | when "day" 21 | start 22 | end 23 | @db = db || PG.connect(ENV["DATABASE_URL"]) 24 | end 25 | 26 | # Drop the tables that contain data that should be expired based on the 27 | # retention period 28 | def drop_tables 29 | schema, table = @partition[:parent_table].split(".") 30 | table_suffix = retention.to_s.tr("-", "_") 31 | 32 | result = @db.exec("select nspname, relname from pg_class c inner join pg_namespace n on n.oid = c.relnamespace where nspname = '#{schema}' and relname like '#{table}_p%' and relkind = 'r' and relname < '#{table}_p#{table_suffix}' order by 1, 2") 33 | result.map do |row| 34 | child_table = "#{row["nspname"]}.#{row["relname"]}" 35 | 36 | # set a default statement 37 | statement = "drop table if exists #{child_table}" 38 | 39 | # update the statement if they want the cascade or the truncate option 40 | if @partition[:cascade] == true 41 | statements = [] 42 | # If desired, drops all dependent ROWS. Likely if this table is being partitioned, so will its dependents. But there are cases of self referencing tables (think parent/child relationships). 43 | # Leave this an option for the operator to decide. Schemas can get pretty unwieldy if you are holding data for a while. 44 | statements << "truncate table #{child_table} cascade" if @partition[:truncate] == true 45 | # Drops table with dropping other constraints (views, foreign keys, etc). Note the cascade on the drop table only removes the fk constraint, not rows. So if you are not partitioning 46 | # dependent tables too, you can get orphaned rows (use the truncate option above to remove them), else make sure you are managing the dependent tables too. 47 | statements << "drop table if exists #{child_table} cascade" 48 | statement = statements.join("; ") 49 | end 50 | 51 | @db.exec(statement) 52 | child_table 53 | end 54 | end 55 | 56 | # Create tables to hold future data 57 | def create_tables 58 | schema, table = @partition[:parent_table].split(".") 59 | start = @start 60 | stop = period_end(start) 61 | 62 | # Note that this starts in the *current* period, so we start at 0 rather 63 | # than 1 for the range, to be sure the current period gets a table *and* 64 | # we make the number of desired future tables 65 | (0..(@partition[:premake] || 4)).map do |month| 66 | child_table = "#{schema}.#{table}_p#{start.to_s.tr("-", "_")}" 67 | 68 | if @partition[:ulid] == true 69 | # ULID is lexographic https://github.com/rafaelsales/ulid 70 | # First 10 chars are timestamp, next 16 are random. Alphabet starts with 0 and ends with Z 71 | pg_start = ULID.generate(start.to_time).first(10) + ("0" * 16) # pin to start 72 | pg_stop = ULID.generate(stop.to_time - 1).first(10) + ("Z" * 16) # pin to end 73 | else 74 | pg_start = start 75 | pg_stop = stop 76 | end 77 | @db.exec("create table if not exists #{child_table} partition of #{schema}.#{table} for values from ('#{pg_start}') to ('#{pg_stop}')") 78 | start = stop 79 | stop = period_end(start) 80 | child_table 81 | end 82 | end 83 | 84 | # Return the date for the oldest table to keep, based on the retention setting 85 | def retention 86 | case @partition[:period] 87 | when "month" 88 | @start << @partition[:retain] || 6 # Default to 6 months 89 | when "week" 90 | @start - ((@partition[:retain] || 4) * 7) # Default to 4 weeks 91 | when "day" 92 | @start - (@partition[:retain] || 7) # Default to 7 days 93 | end 94 | end 95 | 96 | # Return the begin and end dates for the next partition range 97 | def period_end(start) 98 | case @partition[:period] 99 | when "month" 100 | start >> 1 101 | when "week" 102 | start + 7 103 | when "day" 104 | start + 1 105 | end 106 | end 107 | 108 | # A convenience method for doing all the maintenance for a list of partitions. 109 | # opts are passed directly to the initialize method. 110 | def self.process(partitions, **opts) 111 | partitions.each do |part| 112 | pm = new(part, **opts) 113 | pm.drop_tables 114 | pm.create_tables 115 | end 116 | end 117 | end 118 | end 119 | -------------------------------------------------------------------------------- /lib/pg_partition_manager/version.rb: -------------------------------------------------------------------------------- 1 | module PgPartitionManager 2 | VERSION = "0.1.0" 3 | end 4 | -------------------------------------------------------------------------------- /pg_partition_manager.gemspec: -------------------------------------------------------------------------------- 1 | lib = File.expand_path("lib", __dir__) 2 | $LOAD_PATH.unshift(lib) unless $LOAD_PATH.include?(lib) 3 | require "pg_partition_manager/version" 4 | 5 | Gem::Specification.new do |spec| 6 | spec.name = "pg_partition_manager" 7 | spec.version = PgPartitionManager::VERSION 8 | spec.authors = ["Benjamin Curtis"] 9 | spec.email = ["ben@honeybadger.io"] 10 | 11 | spec.summary = "Manage PostgreSQL table partitions" 12 | # spec.description = %q{TODO: Write a longer description or delete this line.} 13 | spec.homepage = "https://github.com/honeybadger-io/pg_partition_manager" 14 | spec.license = "MIT" 15 | 16 | spec.metadata["homepage_uri"] = spec.homepage 17 | spec.metadata["source_code_uri"] = "https://github.com/honeybadger-io/pg_partition_manager" 18 | # spec.metadata["changelog_uri"] = "TODO: Put your gem's CHANGELOG.md URL here." 19 | 20 | # Specify which files should be added to the gem when it is released. 21 | # The `git ls-files -z` loads the files in the RubyGem that have been added into git. 22 | spec.files = Dir.chdir(File.expand_path("..", __FILE__)) do 23 | `git ls-files -z`.split("\x0").reject { |f| f.match(%r{^(test|spec|features)/}) } 24 | end 25 | spec.bindir = "exe" 26 | spec.executables = spec.files.grep(%r{^exe/}) { |f| File.basename(f) } 27 | spec.require_paths = ["lib"] 28 | 29 | spec.add_development_dependency "bundler", "~> 2.0" 30 | spec.add_development_dependency "rake", "~> 13.0" 31 | spec.add_development_dependency "minitest", "~> 5.0" 32 | spec.add_development_dependency "standard" 33 | 34 | spec.add_dependency "pg", "~> 1.0" 35 | spec.add_dependency "ulid", "~> 1.3" 36 | end 37 | -------------------------------------------------------------------------------- /test/pg_partition_manager_test.rb: -------------------------------------------------------------------------------- 1 | require "test_helper" 2 | 3 | class PgPartitionManagerTest < Minitest::Test 4 | def test_that_it_has_a_version_number 5 | refute_nil ::PgPartitionManager::VERSION 6 | end 7 | 8 | def test_it_bails_when_passed_an_invalid_period 9 | assert_raises ArgumentError do 10 | PgPartitionManager::Time.new({parent_table: "public.events", period: "hour"}) 11 | end 12 | end 13 | 14 | def test_it_bails_when_passed_no_period 15 | assert_raises ArgumentError do 16 | PgPartitionManager::Time.new({parent_table: "public.events"}) 17 | end 18 | end 19 | 20 | def test_it_creates_daily_tables_starting_today 21 | PG.stub :connect, db do 22 | Date.stub :today, Date.new(2019, 10, 11) do 23 | pm = PgPartitionManager::Time.new({parent_table: "public.events", period: "day"}) 24 | (11..15).each do |d| 25 | db.expect(:exec, true, ["create table if not exists public.events_p2019_10_#{d} partition of public.events for values from ('2019-10-#{d}') to ('2019-10-#{d + 1}')"]) 26 | end 27 | pm.create_tables 28 | end 29 | end 30 | db.verify 31 | end 32 | 33 | def test_it_creates_weekly_tables_starting_this_week 34 | PG.stub :connect, db do 35 | Date.stub :today, Date.new(2019, 10, 7) do 36 | pm = PgPartitionManager::Time.new({parent_table: "public.events", period: "week", premake: 2}) 37 | [7, 14, 21].each do |d| 38 | db.expect(:exec, true, ["create table if not exists public.events_p2019_10_#{"%02d" % d} partition of public.events for values from ('2019-10-#{"%02d" % d}') to ('2019-10-#{d + 7}')"]) 39 | end 40 | pm.create_tables 41 | end 42 | end 43 | db.verify 44 | end 45 | 46 | def test_it_creates_monthly_tables_starting_this_month 47 | PG.stub :connect, db do 48 | Date.stub :today, Date.new(2019, 10, 1) do 49 | pm = PgPartitionManager::Time.new({parent_table: "public.events", period: "month", premake: 2}) 50 | [10, 11, 12].each do |d| 51 | this_month = Date.new(2019, d, 1) 52 | db.expect(:exec, true, ["create table if not exists public.events_p2019_#{d}_01 partition of public.events for values from ('#{this_month}') to ('#{this_month.next_month}')"]) 53 | end 54 | pm.create_tables 55 | end 56 | end 57 | db.verify 58 | end 59 | 60 | def test_it_drops_old_daily_tables 61 | PG.stub :connect, db do 62 | Date.stub :today, Date.new(2019, 10, 20) do 63 | pm = PgPartitionManager::Time.new({parent_table: "public.events", period: "day", retain: 2}) 64 | db.expect(:exec, [{"nspname" => "public", "relname" => "events_p2019_10_17"}], ["select nspname, relname from pg_class c inner join pg_namespace n on n.oid = c.relnamespace where nspname = 'public' and relname like 'events_p%' and relkind = 'r' and relname < 'events_p2019_10_18' order by 1, 2"]) 65 | db.expect(:exec, true, ["drop table if exists public.events_p2019_10_17"]) 66 | pm.drop_tables 67 | end 68 | end 69 | db.verify 70 | end 71 | 72 | def test_it_drops_old_weekly_tables 73 | PG.stub :connect, db do 74 | Date.stub :today, Date.new(2019, 10, 14) do 75 | pm = PgPartitionManager::Time.new({parent_table: "public.events", period: "week", retain: 2}) 76 | db.expect(:exec, [{"nspname" => "public", "relname" => "events_p2019_09_23"}], ["select nspname, relname from pg_class c inner join pg_namespace n on n.oid = c.relnamespace where nspname = 'public' and relname like 'events_p%' and relkind = 'r' and relname < 'events_p2019_09_30' order by 1, 2"]) 77 | db.expect(:exec, true, ["drop table if exists public.events_p2019_09_23"]) 78 | pm.drop_tables 79 | end 80 | end 81 | db.verify 82 | end 83 | 84 | def test_it_drops_old_monthly_tables 85 | PG.stub :connect, db do 86 | Date.stub :today, Date.new(2019, 10, 1) do 87 | pm = PgPartitionManager::Time.new({parent_table: "public.events", period: "month", retain: 2}) 88 | db.expect(:exec, [{"nspname" => "public", "relname" => "events_p2019_07_01"}], ["select nspname, relname from pg_class c inner join pg_namespace n on n.oid = c.relnamespace where nspname = 'public' and relname like 'events_p%' and relkind = 'r' and relname < 'events_p2019_08_01' order by 1, 2"]) 89 | db.expect(:exec, true, ["drop table if exists public.events_p2019_07_01"]) 90 | pm.drop_tables 91 | end 92 | end 93 | db.verify 94 | end 95 | 96 | def db 97 | @db ||= Minitest::Mock.new 98 | end 99 | end 100 | -------------------------------------------------------------------------------- /test/test_helper.rb: -------------------------------------------------------------------------------- 1 | $LOAD_PATH.unshift File.expand_path("../lib", __dir__) 2 | require "pg_partition_manager" 3 | 4 | require "minitest/autorun" 5 | --------------------------------------------------------------------------------