Re: [EXTERNAL] Re: Need help with slow query - postgres 12 on linux RHEL 8

Поиск
Список
Период
Сортировка
От hubert depesz lubaczewski
Тема Re: [EXTERNAL] Re: Need help with slow query - postgres 12 on linux RHEL 8
Дата
Msg-id ZY6EBG8WhPi8LFUd@depesz.com
обсуждение исходный текст
Ответ на Re: [EXTERNAL] Re: Need help with slow query - postgres 12 on linux RHEL 8  ("Wilson, Maria Louise (LARC-E301)[RSES]" <m.l.wilson@nasa.gov>)
Список pgsql-admin
On Thu, Dec 28, 2023 at 08:16:46PM +0000, Wilson, Maria Louise (LARC-E301)[RSES] wrote:
> https://explain.depesz.com/s/kyl1#html
>
> that last index ---(CREATE INDEX ON granule_file(granule_uuid);
>
> seemed to make the biggest difference!!  Thank you!!
>
> Working on getting this into our production database!!

With this in place, you could also use trigram index on file.name

Details:
https://www.postgresql.org/docs/current/pgtrgm.html#PGTRGM-INDEX

*BUT*

The query that you once showed, didn't have any where condition on
file.name. So either this is different query, or you are using some
view.

Please, pretty please, when putting explains on explain.depesz.com
always include query it came from, as it makes understanding much
easier.

Condition in the explain can be seen in node #9 (Parallel Seq Scan on
file, with filter: name ~~

Also, as a side benefit, the site does pretty-printing queries, so they
don't look like:

#v+
SELECT anon_1.granule_collection_id AS anon_1_granule_collection_id, anon_1.granule_create_date AS
anon_1_granule_create_date,anon_1.granule_delete_date AS anon_1_granule_delete_date,
ST_AsGeoJSON(anon_1.granule_geography)AS anon_1_granule_geography, ST_AsGeoJSON(anon_1.granule_geometry) AS
anon_1_granule_geometry,anon_1.granule_is_active AS anon_1_granule_is_active, anon_1.granule_properties AS
anon_1_granule_properties,anon_1.granule_update_date AS anon_1_granule_update_date, anon_1.granule_uuid AS
anon_1_granule_uuid,anon_1.granule_visibility_last_update_date AS anon_1_granule_visibility_last_update_date,
anon_1.granule_visibility_idAS anon_1_granule_visibility_id, collection_1.id AS collection_1_id, collection_1.entry_id
AScollection_1_entry_id, collection_1.short_name AS collection_1_short_name, collection_1.version AS
collection_1_version,file_1.id AS file_1_id, file_1.location AS file_1_location, file_1.md5 AS file_1_md5, file_1.name
ASfile_1_name, file_1.size AS file_1_size, file_1.type AS file_1_type, visibility_1.id AS visibility_1_id,
visibility_1.nameAS visibility_1_name, visibility_1.value AS visibility_1_value 
    FROM (SELECT granule.collection_id AS granule_collection_id, granule.create_date AS granule_create_date,
granule.delete_dateAS granule_delete_date, granule.geography AS granule_geography, granule.geometry AS
granule_geometry,granule.is_active AS granule_is_active, granule.properties AS granule_properties, granule.update_date
ASgranule_update_date, granule.uuid AS granule_uuid, granule.visibility_last_update_date AS
granule_visibility_last_update_date,granule.visibility_id AS granule_visibility_id 
    FROM granule JOIN collection ON collection.id = granule.collection_id
    WHERE granule.is_active = true AND (collection.entry_id LIKE 'AJAX_CO2_CH4_1' OR collection.entry_id LIKE
'AJAX_O3_1'OR collection.entry_id LIKE 'AJAX_CH2O_1' OR collection.entry_id LIKE 'AJAX_MMS_1') AND ((granule.properties
#>>'{temporal_extent, range_date_times, 0, beginning_date_time}') > '2015-10-06T23:59:59+00:00' OR (granule.properties
#>>'{temporal_extent, single_date_times, 0}') > '2015-10-06T23:59:59+00:00' OR (granule.properties #>>
'{temporal_extent,periodic_date_times, 0, start_date}') > '2015-10-06T23:59:59+00:00') AND ((granule.properties #>>
'{temporal_extent,range_date_times, 0, end_date_time}') < '2015-10-09T00:00:00+00:00' OR (granule.properties #>>
'{temporal_extent,single_date_times, 0}') < '2015-10-09T00:00:00+00:00' OR (granule.properties #>> '{temporal_extent,
periodic_date_times,0, end_date}') < '2015-10-09T00:00:00+00:00') ORDER BY granule.uuid 
    LIMIT 26) AS anon_1 LEFT OUTER JOIN collection AS collection_1 ON collection_1.id = anon_1.granule_collection_id
LEFTOUTER JOIN (granule_file AS granule_file_1 JOIN file AS file_1 ON file_1.id = granule_file_1.file_id) ON
anon_1.granule_uuid= granule_file_1.granule_uuid LEFT OUTER JOIN visibility AS visibility_1 ON visibility_1.id =
anon_1.granule_visibility_idORDER BY anon_1.granule_uuid 
#v-

But rather:

#v+
SELECT
    anon_1.granule_collection_id AS anon_1_granule_collection_id,
    anon_1.granule_create_date AS anon_1_granule_create_date,
    anon_1.granule_delete_date AS anon_1_granule_delete_date,
    st_asgeojson( anon_1.granule_geography ) AS anon_1_granule_geography,
    st_asgeojson( anon_1.granule_geometry ) AS anon_1_granule_geometry,
    anon_1.granule_is_active AS anon_1_granule_is_active,
    anon_1.granule_properties AS anon_1_granule_properties,
    anon_1.granule_update_date AS anon_1_granule_update_date,
    anon_1.granule_uuid AS anon_1_granule_uuid,
    anon_1.granule_visibility_last_update_date AS anon_1_granule_visibility_last_update_date,
    anon_1.granule_visibility_id AS anon_1_granule_visibility_id,
    collection_1.id AS collection_1_id,
    collection_1.entry_id AS collection_1_entry_id,
    collection_1.short_name AS collection_1_short_name,
    collection_1.version AS collection_1_version,
    file_1.id AS file_1_id,
    file_1.location AS file_1_location,
    file_1.md5 AS file_1_md5,
    file_1.name AS file_1_name,
    file_1.size AS file_1_size,
    file_1.type AS file_1_type,
    visibility_1.id AS visibility_1_id,
    visibility_1.name AS visibility_1_name,
    visibility_1.value AS visibility_1_value
FROM
    (
        SELECT
            granule.collection_id AS granule_collection_id,
            granule.create_date AS granule_create_date,
            granule.delete_date AS granule_delete_date,
            granule.geography AS granule_geography,
            granule.geometry AS granule_geometry,
            granule.is_active AS granule_is_active,
            granule.properties AS granule_properties,
            granule.update_date AS granule_update_date,
            granule.uuid AS granule_uuid,
            granule.visibility_last_update_date AS granule_visibility_last_update_date,
            granule.visibility_id AS granule_visibility_id
        FROM
            granule
            JOIN collection ON collection.id = granule.collection_id
        WHERE
            granule.is_active = true AND
            (
                collection.entry_id LIKE 'AJAX_CO2_CH4_1' OR
                collection.entry_id LIKE 'AJAX_O3_1' OR
                collection.entry_id LIKE 'AJAX_CH2O_1' OR
                collection.entry_id LIKE 'AJAX_MMS_1'
            ) AND
            (
                ( granule.properties #>> '{temporal_extent, range_date_times, 0, beginning_date_time}' ) >
'2015-10-06T23:59:59+00:00'OR 
                ( granule.properties #>> '{temporal_extent, single_date_times, 0}' ) > '2015-10-06T23:59:59+00:00' OR
                ( granule.properties #>> '{temporal_extent, periodic_date_times, 0, start_date}' ) >
'2015-10-06T23:59:59+00:00'
            ) AND
            (
                ( granule.properties #>> '{temporal_extent, range_date_times, 0, end_date_time}' ) <
'2015-10-09T00:00:00+00:00'OR 
                ( granule.properties #>> '{temporal_extent, single_date_times, 0}' ) < '2015-10-09T00:00:00+00:00' OR
                ( granule.properties #>> '{temporal_extent, periodic_date_times, 0, end_date}' ) <
'2015-10-09T00:00:00+00:00'
            )
        ORDER BY
            granule.uuid
        LIMIT 26
    ) AS anon_1
    LEFT JOIN collection AS collection_1 ON collection_1.id = anon_1.granule_collection_id
    LEFT JOIN granule_file AS granule_file_1
    JOIN file AS file_1 ON file_1.id = granule_file_1.file_id ON anon_1.granule_uuid = granule_file_1.granule_uuid
    LEFT JOIN visibility AS visibility_1 ON visibility_1.id = anon_1.granule_visibility_id
ORDER BY
    anon_1.granule_uuid;
#v-

Best regards,

depesz




В списке pgsql-admin по дате отправления:

Предыдущее
От: Matheus de Oliveira
Дата:
Сообщение: Re: [EXTERNAL] Re: Need help with slow query - postgres 12 on linux RHEL 8
Следующее
От: Holger Jakobs
Дата:
Сообщение: Domain checks not always working when used in compound type