Skip to content

Commit 1ec65d6

Browse files
authored
Annotating markdown snippets as SQL for easier reading (#591)
1 parent 14d117e commit 1ec65d6

File tree

6 files changed

+114
-114
lines changed

6 files changed

+114
-114
lines changed

doc/fix_missing_procedures.md

Lines changed: 5 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -13,26 +13,26 @@ The best way to fix this and ensure all PROCEDUREs have been installed is to dro
1313
## Update Steps
1414

1515
1. Perform a pg_dump of the data from the pg_partman configuration tables. Note that the contents of this dump will only contain the data and not the table definitions. The definitions are part of the CREATE EXTENSION step. This is just doing a plaintext dump to make it easier to review the contents if desired. Note the following command assumes pg_partman was installed in the `partman` schema.
16-
```
16+
```sh
1717
pg_dump -d mydbname -Fp -a -f partman_update_procedures.sql -t partman.part_config -t partman.part_config_sub
1818
```
1919
2. Drop the pg_partman extension. If it was installed in a specific schema make note of this and reinstall it to that same schema
20-
```
20+
```sql
2121
\dx pg_partman
2222
List of installed extensions
2323
Name | Version | Schema | Description
2424
------------+---------+---------+------------------------------------------------------
2525
pg_partman | 4.7.0 | partman | Extension to manage partitioned tables by time or ID
2626
```
27-
```
27+
```sql
2828
DROP EXTENSION pg_partman;
2929
```
3030
3. Reinstall pg_partman to the same schema
31-
```
31+
```sql
3232
CREATE EXTENSION pg_partman SCHEMA partman;
3333
```
3434
4. Reload the data back into the extension configuration tables
35-
```
35+
```sh
3636
psql -d mydbname -i partman_update_procedures.sql
3737
```
3838
5. Restore privileges to pg_partman objects if needed

doc/migrate_to_declarative.md

Lines changed: 13 additions & 13 deletions
Original file line numberDiff line numberDiff line change
@@ -8,7 +8,7 @@ As always, if you can first test this migration on a development system, it is h
88

99
This is how our partition set currently looks before migration:
1010

11-
```
11+
```sql
1212
\d+ partman_test.time_taptest_table
1313
Table "partman_test.time_taptest_table"
1414
Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
@@ -39,7 +39,7 @@ Access method: heap
3939
```
4040

4141
If your trigger-based partition set happens to be managed by pg_partman version prior to 5.0.0, it is best to remove it from partman management. This can be done by deleting it from the `part_config` and `part_config_sub` tables (if sub-partitioned, ensure all child tables are removed as well). After it has been migrated to native partitioning, see the Migrating to pg_partman document mentioned above to return it to being managed by partman.
42-
```
42+
```sql
4343
DELETE FROM partman.part_config WHERE parent_table = 'partman_test.time_taptest_table';
4444
```
4545

@@ -49,7 +49,7 @@ Next, we need to create a new parent table using native partitioning since you c
4949

5050
Please see the `Child Table Property Inheritance` section of `docs/pg_partman.md` for which properties can be set on the native parent and which must be managed via the template .
5151

52-
```
52+
```sql
5353
CREATE TABLE partman_test.time_taptest_table_native
5454
(col1 int, col2 text default 'stuff', col3 timestamptz NOT NULL DEFAULT now())
5555
PARTITION BY RANGE (col3);
@@ -58,7 +58,7 @@ CREATE INDEX ON partman_test.time_taptest_table_native (col3);
5858
```
5959

6060
Next check what the ownership and privileges on your original table were and ensure they exist on the new parent table. This will ensure all access to the table works the same after the migration. By default with native partitioning, privileges are no longer granted on child tables to provide direct access to them. If you'd like to keep that behavior, set the `inherit_privileges` column in `part_config` (and part_config_sub if needed) to true.
61-
```
61+
```sql
6262
\dt partman_test.time_taptest_table
6363
List of relations
6464
Schema | Name | Type | Owner
@@ -75,14 +75,14 @@ Next check what the ownership and privileges on your original table were and ens
7575
| | | testing=r/partman_owner | |
7676
(1 row)
7777
```
78-
```
78+
```sql
7979
ALTER TABLE partman_test.time_taptest_table_native OWNER TO partman_owner;
8080
GRANT SELECT, INSERT, UPDATE, DELETE ON partman_test.time_taptest_table_native TO partman_basic;
8181
GRANT SELECT ON partman_test.time_taptest_table_native TO testing;
8282
```
8383

8484
It is best to halt all activity on the original table during the migration process to avoid any issues. This can be done by either revoking all permissions to the table temporarily or by taking out an exclusive lock on the parent table and running all of these steps in a single transaction. The transactional method is highly recommended for the simple fact that if you run into any issues before you've completed the migration process, you can simply rollback and return to the state your database was in before the migration started.
85-
```
85+
```sql
8686
BEGIN;
8787
LOCK TABLE partman_test.time_taptest_table IN ACCESS EXCLUSIVE MODE NOWAIT;
8888
```
@@ -92,7 +92,7 @@ The first major step in this migration process is now to uninherit all the child
9292

9393
DO NOT RUN THE RESULTING STATEMENTS YET. A future query will not work if the child tables are no longer part of the inheritance set.
9494

95-
```
95+
```sql
9696
SELECT format('ALTER TABLE %s NO INHERIT %s;', inhrelid::regclass, inhparent::regclass)
9797
FROM pg_inherits
9898
WHERE inhparent::regclass = 'partman_test.time_taptest_table'::regclass;
@@ -123,7 +123,7 @@ For any partition sets, even those not managed by pg_partman, the next step is t
123123
If your child table names do not have a usable pattern like this, you'll have to figure out some method of determining each child table's boundaries.
124124

125125
Again, we can use some sql to generate statements to re-attach the children to the new parent:
126-
```
126+
```sql
127127
WITH child_tables AS (
128128
SELECT
129129
inhrelid::regclass::text AS child_tablename_safe
@@ -161,7 +161,7 @@ FROM child_tables x;
161161

162162
```
163163
We can now run these two sets of ALTER TABLE statements to first uninherit them from the old trigger-based parent and attach them to the new native parent. After doing so, the old trigger-based parent should have no longer have children:
164-
```
164+
```sql
165165
\d+ partman_test.time_taptest_table
166166

167167
Table "partman_test.time_taptest_table"
@@ -177,7 +177,7 @@ Triggers:
177177
Access method: heap
178178
```
179179
And our new native parent should have now adopted all its new children:
180-
```
180+
```sql
181181
\d+ partman_test.time_taptest_table_native
182182
Partitioned table "partman_test.time_taptest_table_native"
183183
Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
@@ -206,20 +206,20 @@ Partitions: partman_test.time_taptest_table_p2023_03_26 FOR VALUES FROM ('2023-0
206206

207207
```
208208
Next is to swap the names of your old trigger-based parent and the new native parent.
209-
```
209+
```sql
210210
ALTER TABLE partman_test.time_taptest_table RENAME TO time_taptest_table_old;
211211
ALTER TABLE partman_test.time_taptest_table_native RENAME TO time_taptest_table;
212212
```
213213
PG11+ supports the feature of a default partition to catch any data that doesn't have a matching child. If your table names are particularly long, ensure that adding the `_default` suffix doesn't get truncated unexpectedly. The suffix isn't required for functionality, but provides good context for what the table is for, so it's better to shorten the table name itself to fit the suffix.
214-
```
214+
```sql
215215
CREATE TABLE partman_test.time_taptest_table_default (LIKE partman_test.time_taptest_table INCLUDING ALL);
216216
ALTER TABLE partman_test.time_taptest_table ATTACH PARTITION partman_test.time_taptest_table_default DEFAULT;
217217
```
218218

219219
There was a primary key on the original parent table, but that is not possible with native partitioning unless the primary key also includes the partition key. This is typically not practical in time-based partitioning. You can place a primary key on each individual child table, but that only enforces the constraint for that child table, not across the entire partition set. You can add a primary key to each individual table using similar SQL generation above, but if you'd like a method to manage adding these to any new child tables, please see the features available in pg_partman.
220220

221221
If you've run this process inside a transaction, be sure to commit your work now:
222-
```
222+
```sql
223223
COMMIT;
224224
```
225225
This should complete the migration process. If you'd like to migrate your partition set to be managed by pg_partman, please see the `migrate_to_partman.md` documentation file.

doc/migrate_to_partman.md

Lines changed: 13 additions & 13 deletions
Original file line numberDiff line numberDiff line change
@@ -7,7 +7,7 @@ As always, if you can first test this migration on a development system, it is h
77

88
The following are the example tables we will be using:
99

10-
```
10+
```sql
1111
CREATE TABLE tracking.hits_time (id int GENERATED BY DEFAULT AS IDENTITY NOT NULL, start timestamptz DEFAULT now() NOT NULL) PARTITION BY RANGE (start);
1212
CREATE INDEX ON tracking.hits_time (start);
1313
CREATE TABLE tracking.hits_time2023_02_26 partition of tracking.hits_time FOR VALUES FROM ('2023-02-26'::timestamptz) TO ('2023-03-05'::timestamptz);
@@ -32,7 +32,7 @@ Partitions: tracking.hits_time20230226 FOR VALUES FROM ('2023-02-26 00:00:00-05'
3232
tracking.hits_time20230312 FOR VALUES FROM ('2023-03-12 00:00:00-05') TO ('2023-03-19 00:00:00-04')
3333

3434
```
35-
```
35+
```sql
3636
CREATE TABLE tracking.hits_id (id int GENERATED BY DEFAULT AS IDENTITY NOT NULL, start timestamptz DEFAULT now() NOT NULL) PARTITION BY RANGE (id);
3737
CREATE INDEX ON tracking.hits_id (id);
3838
CREATE TABLE tracking.hits_id1000 partition of tracking.hits_id FOR VALUES FROM (1000) TO (2000);
@@ -56,7 +56,7 @@ Partitions: tracking.hits_id1000 FOR VALUES FROM (1000) TO (2000),
5656
tracking.hits_id2000 FOR VALUES FROM (2000) TO (3000),
5757
tracking.hits_id3000 FOR VALUES FROM (3000) TO (4000)
5858
```
59-
```
59+
```sql
6060
CREATE TABLE tracking.hits_stufftime (id int GENERATED BY DEFAULT AS IDENTITY NOT NULL, start timestamptz DEFAULT now() NOT NULL) PARTITION BY RANGE (start);
6161
CREATE INDEX ON tracking.hits_stufftime (start);
6262
CREATE TABLE tracking.hits_stufftimeaa partition of tracking.hits_stufftime FOR VALUES FROM ('2023-01-01'::timestamptz) TO ('2023-01-08'::timestamptz);
@@ -80,7 +80,7 @@ Partitions: tracking.hits_stufftimeaa FOR VALUES FROM ('2023-01-01 00:00:00-05')
8080
tracking.hits_stufftimebb FOR VALUES FROM ('2023-01-08 00:00:00-05') TO ('2023-01-15 00:00:00-05'),
8181
tracking.hits_stufftimecc FOR VALUES FROM ('2023-01-15 00:00:00-05') TO ('2023-01-22 00:00:00-05')
8282
```
83-
```
83+
```sql
8484
CREATE TABLE tracking.hits_stuffid (id int GENERATED BY DEFAULT AS IDENTITY NOT NULL, start timestamptz DEFAULT now() NOT NULL) PARTITION BY RANGE (id);
8585
CREATE INDEX ON tracking.hits_stuffid (id);
8686
CREATE TABLE tracking.hits_stuffidaa partition of tracking.hits_stuffid FOR VALUES FROM (1000) TO (2000);
@@ -130,7 +130,7 @@ For converting either time or serial based partition sets, if you have the lower
130130

131131
So a query like the following which first extracts the original name then reformats the suffix would work. It doesn't actually do the renaming, it just generates all the ALTER TABLE statements for you for all the child tables in the set. If all of them don't quite have the same pattern for some reason, you can easily just re-run this, editing things as needed, and filter the resulting list of ALTER TABLE statements accordingly. Note the `to_timestamp()` function is given the old datetime string pattern and the `to_char()` function is given the new string pattern.
132132

133-
```
133+
```sql
134134
SELECT format(
135135
'ALTER TABLE %I.%I RENAME TO %I;'
136136
, n.nspname
@@ -162,7 +162,7 @@ Running that should rename your tables to look like this now:
162162

163163
If you're migrating a serial/id based partition set, and also have the naming convention with the lowest possible value, you'd do something very similar. Everything would be the same as the time-series one above except the renaming would be slightly different. Using my second example table above, it would be something like this.
164164

165-
```
165+
```sql
166166
SELECT format(
167167
'ALTER TABLE %I.%I RENAME TO %I;'
168168
, n.nspname
@@ -196,7 +196,7 @@ If your partitioned sets are named in a manner that relates differently to the d
196196
We'll be using the the `hits_stufftime` table in the first example here which has child tables that don't relate at all to the data contained.
197197

198198
This next step takes advantage of anonymous code blocks. It's basically writing pl/pgsql function code without creating an actual function. Just run this block of code, adjusting values as needed, right inside a psql session. Note that in PostgreSQL, weeks start on Monday's by default for the date_trunc function. However, say we wanted them to start on Sundays like they did for our other time partitioning example to keep things consistent. In that case we have to do a little extra date math to get that result.
199-
```
199+
```sql
200200
DO $rename$
201201
DECLARE
202202
v_min_val timestamp;
@@ -237,21 +237,21 @@ END
237237
$rename$;
238238
```
239239
This will output something like this:
240-
```
240+
```sql
241241
NOTICE: ALTER TABLE tracking.hits_stufftimeaa RENAME TO hits_stufftime_p20230101
242242
NOTICE: ALTER TABLE tracking.hits_stufftimebb RENAME TO hits_stufftime_p20230108
243243
NOTICE: ALTER TABLE tracking.hits_stufftimecc RENAME TO hits_stufftime_p20230115
244244
```
245245
I'd recommend running it at least once with the final EXECUTE commented out to review what it generates. If it looks good, you can uncomment the EXECUTE and rename your tables!
246246

247247
If you've got a serial/id partition set, calculating the proper suffix value can be done by taking advantage of modulus arithmetic. Assume the following values in the tracking.hits_stuffid table:
248-
```
248+
```sql
249249
INSERT INTO tracking.hits_stuffid VALUES (generate_series(1100,1294), now());
250250
INSERT INTO tracking.hits_stuffid VALUES (generate_series(2400,2991), now());
251251
INSERT INTO tracking.hits_stuffid VALUES (generate_series(3602,3843), now());
252252
```
253253
We'll be partitioning by 1000 again and you can see none of the minimum values are that even.
254-
```
254+
```sql
255255
DO $rename$
256256
DECLARE
257257
v_min_val bigint;
@@ -290,7 +290,7 @@ END
290290
$rename$;
291291
```
292292
You can see this makes nice even partition names:
293-
```
293+
```sql
294294
NOTICE: ALTER TABLE tracking.hits_stuffidaa RENAME TO hits_stuffid_p1000
295295
NOTICE: ALTER TABLE tracking.hits_stuffidbb RENAME TO hits_stuffid_p2000
296296
NOTICE: ALTER TABLE tracking.hits_stuffidcc RENAME TO hits_stuffid_p3000
@@ -306,13 +306,13 @@ Note that we're doing weekly partitioning, but pg_partman only knows that interv
306306

307307
You may or may not need to set the starting partition parameter. It all depends on the interval you are using, so please test things to see if they work as expected before running on production.
308308

309-
```
309+
```sql
310310
SELECT partman.create_parent('tracking.hits_time', 'start', '1 week', p_start_partition := '2023-03-26 00:00:00');
311311
COMMIT;
312312
```
313313
This single function call will add your old partition set into pg_partman's configuration and possibly create some new child tables as well. pg_partman always keeps a minimum number of future partitions premade (based on the *premake* value in the config table or as a parameter to the create_parent() function), so if you don't have those yet, this step will take care of that as well. Adjust the parameters as needed and see the documentation for additional options that are available. This call matches the time partition used in the example so far.
314314

315-
```
315+
```sql
316316
\d+ tracking.hits_time
317317
Partitioned table "tracking.hits_time"
318318
Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description

0 commit comments

Comments
 (0)