RE: BUG #17525: Range partition by date won't allow the use of a date that is the upper bound

From: Allen Sutton <Allen(dot)Sutton(at)valocityglobal(dot)com>
To: Allen Sutton <Allen(dot)Sutton(at)valocityglobal(dot)com>, "pgsql-bugs(at)lists(dot)postgresql(dot)org" <pgsql-bugs(at)lists(dot)postgresql(dot)org>
Subject: RE: BUG #17525: Range partition by date won't allow the use of a date that is the upper bound
Date: 2022-06-21 23:31:04
Message-ID: SY4PR01MB802017FAD8EBD753207A5438EEB39@SY4PR01MB8020.ausprd01.prod.outlook.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-bugs

I have found the secret! I need to specify the upper bound to be the 1st of the next month as the partition constraint is a < not <= check

So my former definition

partition=> \d+ avm.avm_history_201704
Table "avm.avm_history_201704"
Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
--------------+-----------------------+-----------+----------+-------------------------------------------------------+----------+-------------+--------------+-------------
model_type | character varying(4) | | | | extended | | |
model_id | integer | | | | plain | | |
est_date | date | | not null | | plain | | |
address_id | integer | | | | plain | | |
est | integer | | | | plain | | |
conf | numeric(8,4) | | | | main | | |
comps_used | bigint | | | | plain | | |
last | smallint | | | 0 | plain | | |
est_id | integer | | not null | nextval('avm.avm_history_part_est_id_seq1'::regclass) | plain | | |
est_smoothed | integer | | | | plain | | |
dipid | character varying(20) | | | | extended | | |
fsd | numeric(4,1) | | | | main | | |
Partition of: avm.avm_history_part FOR VALUES FROM ('2017-04-01') TO ('2017-04-30')
Partition constraint: ((est_date IS NOT NULL) AND (est_date >= '2017-04-01'::date) AND (est_date < '2017-04-30'::date))
Indexes:
"avm_history_201704_est_date_idx" btree (est_date)
"avm_history_201704_est_date_idx1" btree (est_date)
"avm_history_201704_est_id_est_date_idx" UNIQUE, btree (est_id, est_date)
"avm_history_201704_model_id_est_date_dipid_idx" UNIQUE, btree (model_id, est_date, dipid)
Access method: heap

Becomes

partition=> \d+ avm.avm_history_201704
Table "avm.avm_history_201704"
Column | Type | Collation | Nullable | Default | Storage | Compression | Stats target | Description
--------------+-----------------------+-----------+----------+-------------------------------------------------------+----------+-------------+--------------+-------------
model_type | character varying(4) | | | | extended | | |
model_id | integer | | | | plain | | |
est_date | date | | not null | | plain | | |
address_id | integer | | | | plain | | |
est | integer | | | | plain | | |
conf | numeric(8,4) | | | | main | | |
comps_used | bigint | | | | plain | | |
last | smallint | | | 0 | plain | | |
est_id | integer | | not null | nextval('avm.avm_history_part_est_id_seq1'::regclass) | plain | | |
est_smoothed | integer | | | | plain | | |
dipid | character varying(20) | | | | extended | | |
fsd | numeric(4,1) | | | | main | | |
Partition of: avm.avm_history_part FOR VALUES FROM ('2017-04-01') TO ('2017-05-01')
Partition constraint: ((est_date IS NOT NULL) AND (est_date >= '2017-04-01'::date) AND (est_date < '2017-05-01'::date)) <----- This will work
Indexes:
"avm_history_201704_est_date_idx" btree (est_date)
"avm_history_201704_est_date_idx1" btree (est_date)
"avm_history_201704_est_id_est_date_idx" UNIQUE, btree (est_id, est_date)
"avm_history_201704_model_id_est_date_dipid_idx" UNIQUE, btree (model_id, est_date, dipid)
Access method: heap

Please close this bug.

Regards,
Allen Sutton
Allen Sutton
Senior Data Analyst
m: +64 27 272 8886 w: valocityglobal.com
Wellington, New Zealand







The material in this email is confidential to the person or organisation to whom it is addressed and may be protected by legal privilege. If you are not the intended recipient of this email can you please notify the sender by return immediately then delete this email and any copies made. Communications sent by email can be corrupted or intercepted by third parties. For this reason Valocity Limited does not accept any responsibility for any breach of confidence arising through use of this medium.

-----Original Message-----
From: PG Bug reporting form <noreply(at)postgresql(dot)org>
Sent: Wednesday, 22 June 2022 11:12 am
To: pgsql-bugs(at)lists(dot)postgresql(dot)org
Cc: Allen Sutton <Allen(dot)Sutton(at)valocityglobal(dot)com>
Subject: BUG #17525: Range partition by date won't allow the use of a date that is the upper bound

Caution: This email originated from outside the organization. Do not click links or open attachments unless you recognize the sender and know the content is safe. When in doubt, contact your IT Department.

The following bug has been logged on the website:

Bug reference: 17525
Logged by: Allen Sutton
Email address: allen(dot)sutton(at)valocityglobal(dot)com
PostgreSQL version: 14.4
Operating system: Ubuntu 22.04LTS
Description:

I have a table that I have partitioned by a field est_date (date).

CREATE TABLE IF NOT EXISTS avm.avm_history_part (
model_type character varying(4) COLLATE pg_catalog."default",
model_id integer,
est_date date NOT NULL,
address_id integer,
est integer,
conf numeric(8,4),
comps_used bigint,
last smallint DEFAULT 0,
est_id integer NOT NULL DEFAULT
nextval('avm.avm_history_part_est_id_seq1'::regclass),
est_smoothed integer,
dipid character varying(20) COLLATE pg_catalog."default",
fsd numeric(4,1)
) PARTITION BY RANGE (est_date);

The partitions of this table are created with a range of a month.

e.g. CREATE TABLE avm.avm_history_201704 PARTITION OF avm.avm_history_part
FOR VALUES FROM ('2017-04-01') TO ('2017-04-30');

This seems to be causing issues in two ways: - 1. When I prepare a table and then add it as a partition with a date range and est_date in rows equal to the upper bound of the range, Postgres gives me an error that it can't find a partition for the date 2. When I try update a row and set the value of est_date to the upper range, I get an update error such as

ERROR: new row for relation "avm_history_201704" violates partition constraint
DETAIL: Failing row contains (A, 11, 2017-04-30, 46846, 1270000, 0.2647, 7, 0, 26563523, 1246000, NZ82047105, 39.9).
SQL state: 23514

I need assistance to work out what I have done wrong if anything and how to resolve this issue

In response to

Browse pgsql-bugs by date

  From Date Subject
Next Message Christophe Pettus 2022-06-21 23:33:38 Re: BUG #17525: Range partition by date won't allow the use of a date that is the upper bound
Previous Message PG Bug reporting form 2022-06-21 23:11:53 BUG #17525: Range partition by date won't allow the use of a date that is the upper bound