|
| 1 | +<!-- |
| 2 | +SPDX-FileCopyrightText: 2025 ash_postgres contributors |
| 3 | +
|
| 4 | +SPDX-License-Identifier: MIT |
| 5 | +--> |
| 6 | + |
| 7 | +# Partitioned Tables |
| 8 | + |
| 9 | +PostgreSQL supports table partitioning, which allows you to split a large table into smaller, more manageable pieces. Partitioning can improve query performance, simplify maintenance, and enable better data management strategies. |
| 10 | + |
| 11 | +For more information on PostgreSQL partitioning, see the [PostgreSQL partitioning documentation](https://www.postgresql.org/docs/current/ddl-partitioning.html). |
| 12 | + |
| 13 | +> ### Multitenancy and Partitioning {: .info} |
| 14 | +> |
| 15 | +> If you're interested in using partitions for multitenancy, start with AshPostgres's [Schema Based Multitenancy](schema-based-multitenancy.html) feature, which uses PostgreSQL schemas to separate tenant data. Schema-based multitenancy is generally the recommended approach for multitenancy in AshPostgres. |
| 16 | +
|
| 17 | +## Setting Up a Partitioned Table |
| 18 | + |
| 19 | +To create a partitioned table in AshPostgres, you'll use the `create_table_options` DSL option to specify the partitioning strategy. This option passes configuration directly to Ecto's `create table/2` function. |
| 20 | + |
| 21 | +### Range Partitioning Example |
| 22 | + |
| 23 | +Here's an example of setting up a range-partitioned table by date: |
| 24 | + |
| 25 | +```elixir |
| 26 | +defmodule MyApp.SensorReading do |
| 27 | + use Ash.Resource, |
| 28 | + domain: MyApp.Domain, |
| 29 | + data_layer: AshPostgres.DataLayer |
| 30 | + |
| 31 | + attributes do |
| 32 | + uuid_primary_key :id |
| 33 | + attribute :sensor_id, :integer |
| 34 | + attribute :reading_value, :float |
| 35 | + create_timestamp :inserted_at |
| 36 | + end |
| 37 | + |
| 38 | + postgres do |
| 39 | + table "sensor_readings" |
| 40 | + repo MyApp.Repo |
| 41 | + |
| 42 | + # Configure the table as a partitioned table |
| 43 | + create_table_options "PARTITION BY RANGE (inserted_at)" |
| 44 | + |
| 45 | + # Create a default partition to catch any data that doesn't fit into specific partitions |
| 46 | + custom_statements do |
| 47 | + statement :default_partition do |
| 48 | + up """ |
| 49 | + CREATE TABLE IF NOT EXISTS sensor_readings_default |
| 50 | + PARTITION OF sensor_readings DEFAULT; |
| 51 | + """ |
| 52 | + down """ |
| 53 | + DROP TABLE IF EXISTS sensor_readings_default; |
| 54 | + """ |
| 55 | + end |
| 56 | + end |
| 57 | + end |
| 58 | +end |
| 59 | +``` |
| 60 | + |
| 61 | +### List Partitioning Example |
| 62 | + |
| 63 | +Here's an example of list partitioning by region: |
| 64 | + |
| 65 | +```elixir |
| 66 | +defmodule MyApp.Order do |
| 67 | + use Ash.Resource, |
| 68 | + domain: MyApp.Domain, |
| 69 | + data_layer: AshPostgres.DataLayer |
| 70 | + |
| 71 | + attributes do |
| 72 | + uuid_primary_key :id |
| 73 | + attribute :order_number, :string |
| 74 | + attribute :region, :string |
| 75 | + attribute :total, :decimal |
| 76 | + create_timestamp :inserted_at |
| 77 | + end |
| 78 | + |
| 79 | + postgres do |
| 80 | + table "orders" |
| 81 | + repo MyApp.Repo |
| 82 | + |
| 83 | + # Configure the table as a list-partitioned table |
| 84 | + create_table_options "PARTITION BY LIST (region)" |
| 85 | + |
| 86 | + # Create a default partition |
| 87 | + custom_statements do |
| 88 | + statement :default_partition do |
| 89 | + up """ |
| 90 | + CREATE TABLE IF NOT EXISTS orders_default |
| 91 | + PARTITION OF orders DEFAULT; |
| 92 | + """ |
| 93 | + down """ |
| 94 | + DROP TABLE IF EXISTS orders_default; |
| 95 | + """ |
| 96 | + end |
| 97 | + end |
| 98 | + end |
| 99 | +end |
| 100 | +``` |
| 101 | + |
| 102 | +### Hash Partitioning Example |
| 103 | + |
| 104 | +Here's an example of hash partitioning: |
| 105 | + |
| 106 | +```elixir |
| 107 | +defmodule MyApp.LogEntry do |
| 108 | + use Ash.Resource, |
| 109 | + domain: MyApp.Domain, |
| 110 | + data_layer: AshPostgres.DataLayer |
| 111 | + |
| 112 | + attributes do |
| 113 | + uuid_primary_key :id |
| 114 | + attribute :user_id, :integer |
| 115 | + attribute :message, :string |
| 116 | + create_timestamp :inserted_at |
| 117 | + end |
| 118 | + |
| 119 | + postgres do |
| 120 | + table "log_entries" |
| 121 | + repo MyApp.Repo |
| 122 | + |
| 123 | + # Configure the table as a hash-partitioned table |
| 124 | + create_table_options "PARTITION BY HASH (user_id)" |
| 125 | + |
| 126 | + # Create a default partition |
| 127 | + custom_statements do |
| 128 | + statement :default_partition do |
| 129 | + up """ |
| 130 | + CREATE TABLE IF NOT EXISTS log_entries_default |
| 131 | + PARTITION OF log_entries DEFAULT; |
| 132 | + """ |
| 133 | + down """ |
| 134 | + DROP TABLE IF EXISTS log_entries_default; |
| 135 | + """ |
| 136 | + end |
| 137 | + end |
| 138 | + end |
| 139 | +end |
| 140 | +``` |
| 141 | + |
| 142 | +## Creating Additional Partitions |
| 143 | + |
| 144 | +After the initial migration, you can create additional partitions as needed using custom statements. For example, to create monthly partitions for a range-partitioned table: |
| 145 | + |
| 146 | +```elixir |
| 147 | +postgres do |
| 148 | + table "sensor_readings" |
| 149 | + repo MyApp.Repo |
| 150 | + |
| 151 | + create_table_options "PARTITION BY RANGE (inserted_at)" |
| 152 | + |
| 153 | + custom_statements do |
| 154 | + statement :default_partition do |
| 155 | + up """ |
| 156 | + CREATE TABLE IF NOT EXISTS sensor_readings_default |
| 157 | + PARTITION OF sensor_readings DEFAULT; |
| 158 | + """ |
| 159 | + down """ |
| 160 | + DROP TABLE IF EXISTS sensor_readings_default; |
| 161 | + """ |
| 162 | + end |
| 163 | + |
| 164 | + # Example: Create a partition for January 2024 |
| 165 | + statement :january_2024_partition do |
| 166 | + up """ |
| 167 | + CREATE TABLE IF NOT EXISTS sensor_readings_2024_01 |
| 168 | + PARTITION OF sensor_readings |
| 169 | + FOR VALUES FROM ('2024-01-01') TO ('2024-02-01'); |
| 170 | + """ |
| 171 | + down """ |
| 172 | + DROP TABLE IF EXISTS sensor_readings_2024_01; |
| 173 | + """ |
| 174 | + end |
| 175 | + |
| 176 | + # Example: Create a partition for February 2024 |
| 177 | + statement :february_2024_partition do |
| 178 | + up """ |
| 179 | + CREATE TABLE IF NOT EXISTS sensor_readings_2024_02 |
| 180 | + PARTITION OF sensor_readings |
| 181 | + FOR VALUES FROM ('2024-02-01') TO ('2024-03-01'); |
| 182 | + """ |
| 183 | + down """ |
| 184 | + DROP TABLE IF EXISTS sensor_readings_2024_02; |
| 185 | + """ |
| 186 | + end |
| 187 | + end |
| 188 | +end |
| 189 | +``` |
| 190 | + |
| 191 | +## Dynamically Creating Partitions |
| 192 | + |
| 193 | +For list-partitioned tables, you may want to create partitions dynamically as part of a action. Here's an example helper function for creating partitions: |
| 194 | + |
| 195 | +```elixir |
| 196 | +def create_partition(resource, partition_name, list_value) do |
| 197 | + repo = AshPostgres.DataLayer.Info.repo(resource) |
| 198 | + table_name = AshPostgres.DataLayer.Info.table(resource) |
| 199 | + schema = AshPostgres.DataLayer.Info.schema(resource) || "public" |
| 200 | + |
| 201 | + sql = """ |
| 202 | + CREATE TABLE IF NOT EXISTS "#{schema}"."#{partition_name}" |
| 203 | + PARTITION OF "#{schema}"."#{table_name}" |
| 204 | + FOR VALUES IN ('#{list_value}') |
| 205 | + """ |
| 206 | + |
| 207 | + case Ecto.Adapters.SQL.query(repo, sql, []) do |
| 208 | + {:ok, _} -> |
| 209 | + :ok |
| 210 | + |
| 211 | + {:error, %{postgres: %{code: :duplicate_table}}} -> |
| 212 | + :ok |
| 213 | + |
| 214 | + {:error, error} -> |
| 215 | + {:error, "Failed to create partition for #{table_name}: #{inspect(error)}"} |
| 216 | + end |
| 217 | +end |
| 218 | +``` |
| 219 | + |
| 220 | +Similarly, you'll want to dynamically drop partitions when they're no longer needed. |
| 221 | + |
| 222 | + |
| 223 | + |
| 224 | +> ### Partitioning is Complex {: .warning} |
| 225 | +> |
| 226 | +> Table partitioning is a complex topic with many considerations around performance, maintenance, foreign keys, and data management. This guide shows how to configure partitioned tables in AshPostgres, but it is not a comprehensive primer on PostgreSQL partitioning. For detailed information on partitioning strategies, best practices, and limitations, please refer to the [PostgreSQL partitioning documentation](https://www.postgresql.org/docs/current/ddl-partitioning.html). |
| 227 | +
|
| 228 | +## See Also |
| 229 | + |
| 230 | +- [Ecto.Migration.table/2 documentation](https://hexdocs.pm/ecto_sql/Ecto.Migration.html#table/2) for more information on table options |
| 231 | +- [PostgreSQL Partitioning documentation](https://www.postgresql.org/docs/current/ddl-partitioning.html) for detailed information on partitioning strategies |
| 232 | +- [Custom Statements documentation](https://hexdocs.pm/ash_postgres/dsl-ashpostgres-datalayer.html#postgres-custom_statements) for more information on using custom statements in migrations |
0 commit comments