Re: Poor performance on simple queries compared to sql server express

Поиск
Список
Период
Сортировка
От Adam Ma'ruf
Тема Re: Poor performance on simple queries compared to sql server express
Дата
Msg-id CAOy5j_P73Eb2q_XS+kHEGyWNSXMyKk0dkqgdXHCpjeF4CtPjvw@mail.gmail.com
обсуждение исходный текст
Ответ на Re: Poor performance on simple queries compared to sql server express  ("Tomas Vondra" <tv@fuzzy.cz>)
Ответы Re: Poor performance on simple queries compared to sql server express
Список pgsql-performance
Hi

Thanks for the response.  I reran the query but first ran the statement you provided and set working mem to 2gb.  It ended up taking 133s and group aggregate was still used

Here are the values you asked for:
# - Planner Method Configuration -

#enable_bitmapscan = on
#enable_hashagg = on
#enable_hashjoin = on
#enable_indexscan = on
#enable_indexonlyscan = on
#enable_material = on
#enable_mergejoin = on
#enable_nestloop = on
#enable_seqscan = on
#enable_sort = on
#enable_tidscan = on

# - Planner Cost Constants -

#seq_page_cost = 1.0 # measured on an arbitrary scale
#random_page_cost = 4.0 # same scale as above
#cpu_tuple_cost = 0.01 # same scale as above
#cpu_index_tuple_cost = 0.005 # same scale as above
#cpu_operator_cost = 0.0025 # same scale as above
#effective_cache_size = 6000MB


The output of select * from pg_statistics is large...should I attach it as a separate file (not sure if that's allowed on these mailing lists)

The data is ~2.5gb, I can't think of any place I can upload it.  I can provide the columns and data type.  it's a subset of public data from usaspending.gov

column_name,                                       datatype,  ordinal position, nullable?
idxinteger1YES
obligatedamountdouble precision2YES
baseandexercisedoptionsvaluedouble precision3YES
baseandalloptionsvaluedouble precision4YES
maj_fund_agency_catcharacter varying5YES
contractingofficeagencyidcharacter varying6YES
contractingofficeidcharacter varying7YES
fundingrequestingagencyidcharacter varying8YES
fundingrequestingofficeidcharacter varying9YES
signeddatedate10YES
effectivedatedate11YES
currentcompletiondatedate12YES
ultimatecompletiondatedate13YES
lastdatetoordercharacter varying14YES
typeofcontractpricingcharacter varying15YES
multiyearcontractcharacter varying16YES
vendornamecharacter varying17YES
dunsnumbercharacter varying18YES
parentdunsnumbercharacter varying19YES
psc_catcharacter varying20YES
productorservicecodecharacter varying21YES
principalnaicscodecharacter varying22YES
piidcharacter varying23YES
modnumbercharacter varying24YES
fiscal_yearcharacter varying25YES
idvpiidcharacter varying26YES
extentcompetedcharacter varying27YES
numberofoffersreceiveddouble precision28YES
competitiveprocedurescharacter varying29YES
solicitationprocedurescharacter varying30YES
evaluatedpreferencecharacter varying31YES
firm8aflagcharacter varying32YES
sdbflagcharacter varying33YES
issbacertifiedsmalldisadvantagedbusinesscharacter varying34YES
womenownedflagcharacter varying35YES
veteranownedflagcharacter varying36YES
minorityownedbusinessflagcharacter varying37YES
data_sourcetext38YES
psc_cd character varying39YES




On Mon, Aug 26, 2013 at 9:40 AM, Tomas Vondra <tv@fuzzy.cz> wrote:
On 26 Srpen 2013, 15:02, Adam Ma'ruf wrote:
> Sure
>
> I just upgraded to 9.2.4.  The query is:
> SELECT        quebec_four
>             , sierra
>             , SUM(dollaramount) as dollaramount
>   FROM alpha_quebec_echo
>   GROUP BY   quebec_four
>              , sierra
>
> alpha_quebec_echo has 5,409,743 rows and 39 columns.  Quebec_four and
> sierra are both varchar, dollar amount is a floating point field.  It has
> no indexes (but neither did the mssql express table).  Any other details
> you need?
>
> Thanks,
> A

Hi,

It's quite clear why the query is so slow - the plan is using on-disk sort
with ~5M rows, and that's consuming a lot of time (almost 120 seconds).

I'm wondering why it chose the sort in the first place. I'd guess it'll
choose hash aggregate, which does not require sorted input.

Can you try running "set enable_sort = false" and then explain of the query?

If that does not change the plan to "HashAggregate" instead of
"GroupAggregate", please check and post values of enable_* and cost_*
variables.

Another question is why it's doing the sort on disk and not in memory. The
explain you've posted shows it requires ~430MB on disk, and in my
experience it usually requires ~3x that much to do the in-memory sort.

I see you've set work_mem=4GB, is that correct? Can you try with a lower
value - say, 1 or 2GB? I'm not sure how this works on Windows, though.
Maybe there's some other limit (and SQL Server is not hitting it, because
it's native Windows application).

Can you prepare a testcase (table structure + data) and post it somewhere?
Or at least the structure, if it's not possible to share the data.

Also, output from "select * from pg_settings" would be helpful.

Tomas



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

Предыдущее
От: "Tomas Vondra"
Дата:
Сообщение: Re: Poor performance on simple queries compared to sql server express
Следующее
От: Дмитрий Дегтярёв
Дата:
Сообщение: Cpu usage 100% on slave. s_lock problem.