Обсуждение: Separate 100 M spatial data in 100 tables VS one big table

Поиск
Список
Период
Сортировка

Separate 100 M spatial data in 100 tables VS one big table

От
kimaidou
Дата:
Hi list,

In France, the total number of cadastral parcels is around 10 000 000

The data can be heavy, because each parcel stores a geometry (PostGIS geometry data type inside a geom column).
Indexes must be created to increase performance of day-to-day requests:

* GIST index on geom for spatial filtering and intersection with other geometries (other tables)
* Primary key and probably another unique code to index
* one index on the "department" field. There are around 100 "departments" (admin boundaries) in France, and the parcels are homogeneously distributed (~ 1M parcel per "department")

The initial import of this data is made one department by one department (the data source is distributed by department by French authorities). And each year, data must be deleted and reimported (data change each year), and this is also often done one department at a time.

* Sometimes requests are made with a department filter (for example WHERE department IN ('2A', '34', '30', '48') )
* Sometimes other client database clients must be able to get data from the whole dataset ( for example get the parcels for a list of known IDs)

I would like to question the list about  the following 2 strategies to maintain such data:

1/ Put the whole dataset into one big table
2/ Create one table per department, and create a VIEW with 100 UNION ALL to gather all the parcels

1/ Seems simpler for the database clients, but it seems to me this can be a pain to maintain. For example, each time we will need to replace last year data for one department with the upcoming new data, we will need to delete 1M lines, reimport the new 1M lines and VACUUM FULL to regain space. Indexes will be huge, and I can suffer questions like :
I often need to use pg_repack to regain spaces on this kind of table. VACUUM FULL cannot be used because it locks the table, and it takes times (!)

2/ Seems more kiss, but only if queries on the UNION VIEW will be able to use the tables indexes (geom, department) and perform as well as the big table.


Any hint appreciated !
Regards

Kimaidou


Re: Separate 100 M spatial data in 100 tables VS one big table

От
Marc Millas
Дата:
Salut Kimaidou,
why not a partitioned table with the department a partitioning Key ?
each year just detach the obsolete data, department by department (ie.detach the partition, almost instantaneous) and drop or keep the obsolete data.
No delete, quite easy to maintain. For each global index, Postgres will create one index per each partition. and detach them when you detach a department partition.
so when importing, first create an appropriate table, load the data, and attach it to the main partitioned table. Postgres will automatically recreate all necessary indexes.

Marc MILLAS
Senior Architect
+33607850334



On Tue, Mar 5, 2024 at 8:45 AM kimaidou <kimaidou@gmail.com> wrote:
Hi list,

In France, the total number of cadastral parcels is around 10 000 000

The data can be heavy, because each parcel stores a geometry (PostGIS geometry data type inside a geom column).
Indexes must be created to increase performance of day-to-day requests:

* GIST index on geom for spatial filtering and intersection with other geometries (other tables)
* Primary key and probably another unique code to index
* one index on the "department" field. There are around 100 "departments" (admin boundaries) in France, and the parcels are homogeneously distributed (~ 1M parcel per "department")

The initial import of this data is made one department by one department (the data source is distributed by department by French authorities). And each year, data must be deleted and reimported (data change each year), and this is also often done one department at a time.

* Sometimes requests are made with a department filter (for example WHERE department IN ('2A', '34', '30', '48') )
* Sometimes other client database clients must be able to get data from the whole dataset ( for example get the parcels for a list of known IDs)

I would like to question the list about  the following 2 strategies to maintain such data:

1/ Put the whole dataset into one big table
2/ Create one table per department, and create a VIEW with 100 UNION ALL to gather all the parcels

1/ Seems simpler for the database clients, but it seems to me this can be a pain to maintain. For example, each time we will need to replace last year data for one department with the upcoming new data, we will need to delete 1M lines, reimport the new 1M lines and VACUUM FULL to regain space. Indexes will be huge, and I can suffer questions like :
I often need to use pg_repack to regain spaces on this kind of table. VACUUM FULL cannot be used because it locks the table, and it takes times (!)

2/ Seems more kiss, but only if queries on the UNION VIEW will be able to use the tables indexes (geom, department) and perform as well as the big table.


Any hint appreciated !
Regards

Kimaidou


Re: Separate 100 M spatial data in 100 tables VS one big table

От
Tomas Vondra
Дата:
On 3/5/24 13:47, Marc Millas wrote:
> Salut Kimaidou,
> why not a partitioned table with the department a partitioning Key ?
> each year just detach the obsolete data, department by
> department (ie.detach the partition, almost instantaneous) and drop or keep
> the obsolete data.
> No delete, quite easy to maintain. For each global index, Postgres will
> create one index per each partition. and detach them when you detach a
> department partition.
> so when importing, first create an appropriate table, load the data, and
> attach it to the main partitioned table. Postgres will
> automatically recreate all necessary indexes.
> 

Yes, a table partitioned like this is certainly a valid option - and
it's much better than the view with a UNION of all the per-department
tables. The optimizer has very little insight into the view, which
limits how it can optimize queries. For example if the query has a
condition like

   WHERE department = 'X'

with the declarative partitioning the planner can eliminate all other
partitions (and just ignore them), while with the view it will have to
scan all of them.

But is partitioning a good choice? Who knows - it makes some operations
simpler (e.g. you can detach/drop a partition instead of deleting the
rows), but it also makes other operations less efficient. For example a
query that can't eliminate partitions has to do more stuff during execution.

So to answer this we'd need to know how often stuff like bulk deletes /
reloads happen, what queries will be executed, and so on. Both options
(non-partitioned and partitioned table) are valid, but you have to try.

Also, partitioned table may not support / allow some features - for
example unique keys that don't contain the partition key. We're
improving this in every release, but there will always be a gap.

I personally would start with non-partitioned table, because that's the
simplest option. And once I get a better idea how often the reloads
happen, I'd consider if that's something worth the extra complexity of
partitioning the data. If it happens only occasionally (a couple times a
year), it probably is not. You'll just delete the data and reuse the
space for new data.

regards

-- 
Tomas Vondra
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company



Re: Separate 100 M spatial data in 100 tables VS one big table

От
kimaidou
Дата:
Hi !

I would like to thank you all for your detailed answers and explanations.
I would give "partitioning" a try, by creating a dedicated new partition table, and insert a (big enough) extract of the source data in it.

You are right, the best would be to try in real life !

Best wishes
Kimaidou

Le mardi 5 mars 2024, Tomas Vondra <tomas.vondra@enterprisedb.com> a écrit :
On 3/5/24 13:47, Marc Millas wrote:
> Salut Kimaidou,
> why not a partitioned table with the department a partitioning Key ?
> each year just detach the obsolete data, department by
> department (ie.detach the partition, almost instantaneous) and drop or keep
> the obsolete data.
> No delete, quite easy to maintain. For each global index, Postgres will
> create one index per each partition. and detach them when you detach a
> department partition.
> so when importing, first create an appropriate table, load the data, and
> attach it to the main partitioned table. Postgres will
> automatically recreate all necessary indexes.
>

Yes, a table partitioned like this is certainly a valid option - and
it's much better than the view with a UNION of all the per-department
tables. The optimizer has very little insight into the view, which
limits how it can optimize queries. For example if the query has a
condition like

   WHERE department = 'X'

with the declarative partitioning the planner can eliminate all other
partitions (and just ignore them), while with the view it will have to
scan all of them.

But is partitioning a good choice? Who knows - it makes some operations
simpler (e.g. you can detach/drop a partition instead of deleting the
rows), but it also makes other operations less efficient. For example a
query that can't eliminate partitions has to do more stuff during execution.

So to answer this we'd need to know how often stuff like bulk deletes /
reloads happen, what queries will be executed, and so on. Both options
(non-partitioned and partitioned table) are valid, but you have to try.

Also, partitioned table may not support / allow some features - for
example unique keys that don't contain the partition key. We're
improving this in every release, but there will always be a gap.

I personally would start with non-partitioned table, because that's the
simplest option. And once I get a better idea how often the reloads
happen, I'd consider if that's something worth the extra complexity of
partitioning the data. If it happens only occasionally (a couple times a
year), it probably is not. You'll just delete the data and reuse the
space for new data.

regards

--
Tomas Vondra
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company