RE: Query NOt In para optimizar

From: Edwin Quijada <listas_quijada(at)hotmail(dot)com>
To: Martín Marqués <martin(at)2ndquadrant(dot)com>, Hellmuth Vargas <hivs77(at)gmail(dot)com>
Cc: "pgsql-es-ayuda(at)postgresql(dot)org" <pgsql-es-ayuda(at)postgresql(dot)org>
Subject: RE: Query NOt In para optimizar
Date: 2014-12-16 15:37:30
Message-ID: BAY168-W1349D97DF23A7B5E6901715E36C0@phx.gbl
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-es-ayuda

Aqui esta el seelect con NOT IN, hice una vista para el primer select
explain analyze select *,getserietk(tk) from v_tk_ganados where banca=1 AND tk not IN ( SELECT c.f_ticket FROM public.t_tickets_pagados c ); QUERY PLAN-------------------------------------------------------------------------------------------------------------------------------------------- Subquery Scan on v_tk_ganados (cost=1556.33..2868703.42 rows=1786 width=52) (actual time=518.040..40231.410 rows=129 loops=1) Filter: (NOT (SubPlan 1)) Rows Removed by Filter: 3387 -> HashAggregate (cost=1556.33..1592.04 rows=3571 width=21) (actual time=49.562..61.026 rows=3516 loops=1) -> Seq Scan on t_detalle_tickets_ganadores (cost=0.00..1500.00 rows=4506 width=21) (actual time=0.019..42.658 rows=4457 loops=1) Filter: (f_idbanca = 1) Rows Removed by Filter: 59240 SubPlan 1 -> Materialize (cost=0.00..1475.00 rows=52200 width=4) (actual time=0.002..6.003 rows=25425 loops=3516) -> Seq Scan on t_tickets_pagados c (cost=0.00..1010.00 rows=52200 width=4) (actual time=0.005..40.605 rows=52159 loops=1) Total runtime: 40231.917 ms(11 rows)

> Date: Tue, 16 Dec 2014 10:20:02 -0300
> From: martin(at)2ndquadrant(dot)com
> To: hivs77(at)gmail(dot)com
> CC: listas_quijada(at)hotmail(dot)com; pgsql-es-ayuda(at)postgresql(dot)org
> Subject: Re: [pgsql-es-ayuda] Query NOt In para optimizar
>
> El 16/12/14 a las 10:07, Hellmuth Vargas escribió:
> > Hola lista
> >
> > Martín disculpe la ignorancia, pero tengo entendido que si se coloca una
> > condición filtró en el where de la tabla B, el left outer se convierte en
> > inner join y se pierde el efecto. Por favor corrijame si me equivoco
>
> Te corrijo! ;)
>
> Prueba con un EXPLAIN ANALYZE para ver como PostgreSQL planifica la
> consulta.
>
> explain analyze select * from personas where codigo NOT IN (SELECT
> persona FROM usuarios);
> QUERY PLAN
>
> ------------------------------------------------------------------------------------------------------------------------
> Seq Scan on personas (cost=3084.72..6036.51 rows=62552 width=46)
> (actual time=111.600..162.448 rows=15 loops=1)
> Filter: (NOT (hashed SubPlan 1))
> Rows Removed by Filter: 125088
> SubPlan 1
> -> Seq Scan on usuarios (cost=0.00..2714.98 rows=147898 width=4)
> (actual time=0.011..31.877 rows=147898 loops=1)
> Total runtime: 162.520 ms
>
>
> explain analyze select * from personas p LEFT OUTER JOIN usuarios u ON
> (p.codigo=u.persona) where u.persona IS NULL;
> QUERY PLAN
>
> -------------------------------------------------------------------------------------------------------------------------------
> Hash Anti Join (cost=5719.70..18174.42 rows=13388 width=83) (actual
> time=74.550..195.594 rows=15 loops=1)
> Hash Cond: (p.codigo = u.persona)
> -> Seq Scan on personas p (cost=0.00..2639.03 rows=125103 width=46)
> (actual time=0.004..19.270 rows=125103 loops=1)
> -> Hash (cost=2714.98..2714.98 rows=147898 width=37) (actual
> time=70.090..70.090 rows=147898 loops=1)
> Buckets: 16384 Batches: 2 Memory Usage: 4749kB
> -> Seq Scan on usuarios u (cost=0.00..2714.98 rows=147898
> width=37) (actual time=0.003..23.560 rows=147898 loops=1)
> Total runtime: 195.660 ms
>
> En este caso, anduvo más rápido con el NOT IN (), pero eso depende mucho
> de cuantos datos se esten filtrando, cuantos datos totales haya en cada
> tabla, etc.
>
> 200k no es una gran tabla, IMO.
>
> Saludos,
>
> --
> Martín Marqués http://www.2ndQuadrant.com/
> PostgreSQL Development, 24x7 Support, Training & Services

In response to

Browse pgsql-es-ayuda by date

  From Date Subject
Next Message Eduardo Arenas C. 2014-12-16 15:49:31 Re: AYUDA
Previous Message Guillermo E. Villanueva 2014-12-16 15:32:05 Re: AYUDA