After looking at your statistics in the set explain I agree with
Art. Please make sure that the tables have good statistics
and distributions.
John F. Miller III
STSM, Embedability Architect
miller3@us.ibm.com
503-578-5645
IBM Informix Dynamic Server (IDS)
ids-bounces@iiug.org wrote on 05/26/2011 10:08:54 AM:
> [image removed]
>
> Re: queries slow after migration [23847]
>
> Art Kagel
>
> to:
>
> ids
>
> 05/26/2011 10:10 AM
>
> Sent by:
>
> ids-bounces@iiug.org
>
> Please respond to ids
>
> The estimated rows versus actual rows produced in the explain details are
> WAY OFF. That means that your update statistics levels are too low and
the
> optimizer does not have enough information to make good decisions. You
need
> to rerun the update statistics using the full protocol of commands
> recommended in the Performance Guide or just get my dostats utility (in
the
> utils2_ak package in the IIUG Software Repository) and run it.
>
> Art
>
> Art S. Kagel
> Advanced DataTools (www.advancedatatools.com)
> Blog: http://informix-myview.blogspot.com/
>
> Disclaimer: Please keep in mind that my own opinions are my own opinions
and
> do not reflect on my employer, Advanced DataTools, the IIUG, nor any
other
> organization with which I am associated either explicitly, implicitly, or
by
> inference. Neither do those opinions reflect those of other individuals
> affiliated with any entity with which I am affiliated nor those of the
> entities themselves.
>
> On Thu, May 26, 2011 at 12:41 PM, ROGER VILCA
<rvilca@luzdelsur.com.pe>wrote:
>
> > Thanks. This is the explain with no ORDERED (+4 min) and with ORDERED
> > (aprox.
> > 2 sec.)
> >
> > QUERY: (OPTIMIZATION TIMESTAMP: 05-26-2011 10:50:08)
> > ------
> > select
> > e.ano,e.mes,
> > sum(nvl(m.debe_ingreso,0)),sum(nvl(m.haber_ingreso,0))
> > from proyectos_de_inver p,inver_de_capital i,
> > con_combin b, con_movcom m, con_enccom e
> > where p.empresa = '7'
> > and p.proyecto_inversion = '001884'
> > and i.empresa = p.empresa
> > and i.proyecto_inver = p.proyecto_inversion
> > and b.empresa = i.empresa
> > and i.inversion_capital is not null
> > and i.inversion_capital <> ''
> > and b.aux_valor6 = i.inversion_capital
> > and m.empresa = b.empresa
> > and m.combinatoria = b.combinatoria
> > and m.tipo_comprobante not in ('A3001','A3008')
> > and e.empresa = m.empresa
> > and e.fecha = m.fecha
> > and e.tipo_comprobante = m.tipo_comprobante
> > and e.correlativo = m.correlativo
> > and e.estado = 'A'
> > and e.ano = 2011
> > and e.mes <= 4
> > group by 1,2
> > order by 1,2
> >
> > Estimated Cost: 3187
> > Estimated # of Rows Returned: 1
> > Temporary Files Required For: Order By
> >
> > 1) informix.e: INDEX PATH
> >
> > Filters: (informix.e.estado = 'A' AND informix.e.tipo_comprobante NOT
IN
> > ('A3001' , 'A3008' ))
> >
> > (1) Index Name: xsic.i3_con_enccom
> >
> > Index Keys: mes ano empresa (Key-First) (Serial, fragments: ALL)
> >
> > Upper Index Filter: informix.e.mes <= 4
> >
> > Index Key Filters: (informix.e.ano = 2011 ) AND
> >
> > (informix.e.empresa = '7' )
> >
> > INDEX_NAME = i3_con_enccom
> >
> > 2) informix.m: INDEX PATH
> >
> > (1) Index Name: xsic.i3_con_movcom
> >
> > Index Keys: correlativo tipo_comprobante fecha ano cuenta origen
> > combinatoria
> > empresa (Key-First) (Serial, fragments: ALL)
> >
> > Lower Index Filter: ((informix.e.correlativo = informix.m.correlativo
AND
> > informix.e.fecha = informix.m.fecha ) AND informix.e.tipo_comprobante =
> > informix.m.tipo_comprobante )
> >
> > Index Key Filters: (informix.m.empresa = '7' )
> >
> > INDEX_NAME = i3_con_movcom
> > NESTED LOOP JOIN
> >
> > 3) informix.p: INDEX PATH
> >
> > (1) Index Name: xsic.i_ep_proy_inver
> >
> > Index Keys: proyecto_inversion empresa (Key-Only) (Serial, fragments:
ALL)
> >
> > Lower Index Filter: (informix.p.empresa = informix.m.empresa AND
> > informix.p.proyecto_inversion = '001884' )
> >
> > INDEX_NAME = i_ep_proy_inver
> > NESTED LOOP JOIN
> >
> > 4) informix.b: INDEX PATH
> >
> > Filters: informix.b.aux_valor6 != ''
> >
> > (1) Index Name: xsic.i100_con_combin
> >
> > Index Keys: combinatoria empresa (Serial, fragments: ALL)
> >
> > Lower Index Filter: (informix.m.combinatoria = informix.b.combinatoria
AND
> > informix.m.empresa = informix.b.empresa )
> >
> > INDEX_NAME = i100_con_combin
> > NESTED LOOP JOIN
> >
> > 5) informix.i: INDEX PATH
> >
> > Filters: (informix.b.aux_valor6 = informix.i.inversion_capital AND
> > informix.i.inversion_capital != '' )
> >
> > (1) Index Name: xsic.proyecto_inver
> >
> > Index Keys: proyecto_inver empresa (Serial, fragments: ALL)
> >
> > Lower Index Filter: (informix.i.proyecto_inver =
> > informix.p.proyecto_inversion
> > AND informix.i.empresa = informix.e.empresa )
> >
> > INDEX_NAME = proyecto_inver
> > NESTED LOOP JOIN
> >
> > DB_LOCALE = en_US.819
> > SESSION COLLATION = es_ES.819
> >
> > Query statistics:
> > -----------------
> >
> > Table map :
> > ----------------------------
> > Internal name Table name
> > ----------------------------
> > t1 e
> > t2 m
> > t3 p
> > t4 b
> > t5 i
> >
> > type table rows_prod est_rows rows_scan time est_cost
> > -------------------------------------------------------------------
> > scan t1 2768 1020 58414 00:02.46 2253
> >
> > type table rows_prod est_rows rows_scan time est_cost
> > -------------------------------------------------------------------
> > scan t2 256959 8077986 257749 02:28.46 1
> >
> > type rows_prod est_rows time est_cost
> > -------------------------------------------------
> > nljoin 256959 7 02:31.28 2934
> >
> > type table rows_prod est_rows rows_scan time est_cost
> > -------------------------------------------------------------------
> > scan t3 256959 1 256959 00:09.86 0
> >
> > type rows_prod est_rows time est_cost
> > -------------------------------------------------
> > nljoin 256959 7 02:42.07 2950
> >
> > type table rows_prod est_rows rows_scan time est_cost
> > -------------------------------------------------------------------
> > scan t4 20366 149874 256959 00:36.15 1
> >
> > type rows_prod est_rows time est_cost
> > -------------------------------------------------
> > nljoin 20366 6 03:18.80 2957
> >
> > type table rows_prod est_rows rows_scan time est_cost
> > -------------------------------------------------------------------
> > scan t5 1170 134 2830874 00:42.98 37
> >
> > type rows_prod est_rows time est_cost
> > -------------------------------------------------
> > nljoin 1170 12 04:01.84 3187
> >
> > type rows_prod est_rows rows_cons time est_cost
> > ------------------------------------------------------------
> > group 4 1 1170 04:01.88 15
> >
> > type rows_sort est_rows rows_cons time est_cost
> > ------------------------------------------------------------
> > sort 4 1 4 04:01.88 0
> >
> > QUERY: (OPTIMIZATION TIMESTAMP: 05-26-2011 11:37:11)
> > ------
> > select {+ORDERED}
> > e.ano,e.mes,
> > sum(nvl(m.debe_ingreso,0)),sum(nvl(m.haber_ingreso,0))
> > from proyectos_de_inver p,inver_de_capital i,
> > con_combin b, con_movcom m, con_enccom e
> > where p.empresa = '7'
> > and p.proyecto_inversion = '001884'
> > and i.empresa = p.empresa
> > and i.proyecto_inver = p.proyecto_inversion
> > and b.empresa = i.empresa
> > and i.inversion_capital is not null
> > and i.inversion_capital <> ''
> > and b.aux_valor6 = i.inversion_capital
> > and m.empresa = b.empresa
> > and m.combinatoria = b.combinatoria
> > and m.tipo_comprobante not in ('A3001','A3008')
> > and e.empresa = m.empresa
> > and e.fecha = m.fecha
> > and e.tipo_comprobante = m.tipo_comprobante
> > and e.correlativo = m.correlativo
> > and e.estado = 'A'
> > and e.ano = 2011
> > and e.mes <= 4
> > group by 1,2
> > order by 1,2
> >
> > DIRECTIVES FOLLOWED:
> > ORDERED
> > DIRECTIVES NOT FOLLOWED:
> >
> > Estimated Cost: 21930910
> > Estimated # of Rows Returned: 1
> > Temporary Files Required For: Order By Group By
> >
> > 1) informix.p: INDEX PATH
> >
> > (1) Index Name: xsic.i_ep_proy_inver
> >
> > Index Keys: proyecto_inversion empresa (Key-Only) (Serial, fragments:
ALL)
> >
> > Lower Index Filter: (informix.p.proyecto_inversion = '001884' AND
> > informix.p.empresa = '7' )
> >
> > INDEX_NAME = i_ep_proy_inver
> >
> > 2) informix.i: INDEX PATH
> >
> > Filters: informix.i.inversion_capital != ''
> >
> > (1) Index Name: xsic.proyecto_inver
> >
> > Index Keys: proyecto_inver empresa (Serial, fragments: ALL)
> >
> > Lower Index Filter: (informix.i.proyecto_inver =
> > informix.p.proyecto_inversion
> > AND informix.i.empresa = informix.p.empresa )
> >
> > INDEX_NAME = proyecto_inver
> > NESTED LOOP JOIN
> >
> > 3) informix.b: INDEX PATH
> >
> > (1) Index Name: xsic.i6_con_combin
> >
> > Index Keys: aux_valor6 empresa (Serial, fragments: ALL)
> >
> > Lower Index Filter: (informix.b.aux_valor6 =
informix.i.inversion_capital
> > AND
> > informix.p.empresa = informix.b.empresa )
> >
> > INDEX_NAME = i6_con_combin
> > NESTED LOOP JOIN
> >
> > 4) informix.m: INDEX PATH
> >
> > Filters: informix.m.tipo_comprobante NOT IN ('A3001' , 'A3008' )
> >
> > (1) Index Name: xsic.i2_con_movcom
> >
> > Index Keys: combinatoria empresa (Serial, fragments: ALL)
> >
> > Lower Index Filter: (informix.m.combinatoria = informix.b.combinatoria
AND
> > informix.m.empresa = informix.b.empresa )
> >
> > INDEX_NAME = i2_con_movcom
> > NESTED LOOP JOIN
> >
> > 5) informix.e: INDEX PATH
> >
> > Filters: ((informix.e.ano = 2011 AND informix.e.mes <= 4 ) AND
> > informix.e.estado = 'A' )
> >
> > (1) Index Name: xsic.i5_con_enccom
> >
> > Index Keys: fecha correlativo tipo_comprobante empresa (Serial,
fragments:
> > ALL)
> >
> > Lower Index Filter: (((informix.e.correlativo = informix.m.correlativo
AND
> > informix.e.fecha = informix.m.fecha ) AND informix.e.tipo_comprobante =
> > informix.m.tipo_comprobante ) AND informix.e.empresa =
informix.m.empresa )
> >
> > INDEX_NAME = i5_con_enccom
> > NESTED LOOP JOIN
> >
> > DB_LOCALE = en_US.819
> > SESSION COLLATION = es_ES.819
> >
> > Query statistics:
> > -----------------
> >
> > Table map :
> > ----------------------------
> > Internal name Table name
> > ----------------------------
> > t1 p
> > t2 i
> > t3 b
> > t4 m
> > t5 e
> >
> > type table rows_prod est_rows rows_scan time est_cost
> > -------------------------------------------------------------------
> > scan t1 1 1 1 00:00.00 1
> >
> > type table rows_prod est_rows rows_scan time est_cost
> > -------------------------------------------------------------------
> > scan t2 136 134 139 00:00.00 37
> >
> > type rows_prod est_rows time est_cost
> > -------------------------------------------------
> > nljoin 136 134 00:00.00 40
> >
> > type table rows_prod est_rows rows_scan time est_cost
> > -------------------------------------------------------------------
> > scan t3 571 149874 571 00:00.10 1251
> >
> > type rows_prod est_rows time est_cost
> > -------------------------------------------------
> > nljoin 571 299542 00:00.11 168289
> >
> > type table rows_prod est_rows rows_scan time est_cost
> > -------------------------------------------------------------------
> > scan t4 1170 8077986 1310 00:03.29 43
> >
> > type rows_prod est_rows time est_cost
> > -------------------------------------------------
> > nljoin 1170 14279158 00:03.41 13071795
> >
> > type table rows_prod est_rows rows_scan time est_cost
> > -------------------------------------------------------------------
> > scan t5 1170 1020 1170 00:00.50 1
> >
> > type rows_prod est_rows time est_cost
> > -------------------------------------------------
> > nljoin 1170 11 00:03.92 21930894
> >
> > type rows_prod est_rows rows_cons time est_cost
> > ------------------------------------------------------------
> > group 4 1 1170 00:03.95 15
> >
> > type rows_sort est_rows rows_cons time est_cost
> > ------------------------------------------------------------
> > sort 4 1 4 00:03.95 0
> >
> >
> >
> >
>
*******************************************************************************
> > Forum Note: Use "Reply" to post a response in the discussion forum.
> >
> >
>
> --bcaec50166b7de6fff04a430dff4
>
>
>
*******************************************************************************
> Forum Note: Use "Reply" to post a response in the discussion forum.
>