Thread: Speed up the query

Speed up the query

From
Hengky Liwandouw
Date:
Friends, i need help. 

I have query below that running well so far. it needs only 5.335 second to get data from 803.583 records. Here is the query :

with qry1 as 
(select tanggal, extract(month from tanggal) as bulan, tblsupplier.id, nama, kodebarang, namabarang, keluar, 
case when discount<=100 then
   keluar*(harga -(discount/100*harga))
when tbltransaksi.discount>100 then
keluar*(harga-discount)
end 
    as jumlah
from tbltransaksi 
join tblproduk on tbltransaksi.kodebarang=tblproduk.produkid
join tblsupplier on tblproduk.supplierid=tblsupplier.id
where jualid is not null 
and extract(year from tanggal)='2013')

select  
  id, nama, kodebarang, namabarang,
  sum(case when bulan = 1 then keluar else 0 end) as Jan,
  sum(case when bulan = 2 then keluar else 0 end) as Feb,
  sum(case when bulan = 3 then keluar else 0 end) as Maret,
  sum(case when bulan = 4 then keluar else 0 end) as April,
  sum(case when bulan = 5 then keluar else 0 end) as Mei,
  sum(case when bulan = 6 then keluar else 0 end) as Juni,
  sum(case when bulan = 7 then keluar else 0 end) as Juli,
  sum(case when bulan = 8 then keluar else 0 end) as Agust,
  sum(case when bulan = 9 then keluar else 0 end) as Sept,
  sum(case when bulan = 10 then keluar else 0 end) as Okt,
  sum(case when bulan = 11 then keluar else 0 end) as Nov,
  sum(case when bulan = 12 then keluar else 0 end) as Des,
  sum(coalesce(keluar,0)) as total
from qry1
group by id, nama, kodebarang, namabarang
order by total desc
limit 1000

But the problem is : when i change the where clause to :

where jualid is not null or returjualid is not null
and extract(year from tanggal)='2013')


(there is additional or returjualid is not null,) the query needs 56 second to display the result. 10 times longer.
Is there anyway to speed up the query ? My server is Dell PowerEdge T110II, Intel Xeon E1230 Sandy bridge 3.2GHZ, 4GB memory, 500GB Sata III HDD running on Ubuntu server 12.04, PostgreSql 9.3

Postgresqlconf :
max_connections=50
shared_buffers=1024MB
wall_buffers=16MB
max_prepared_transactions=0
work_mem=50MB
maintenance_work_mem=256MB

Analyze result :

Operation                        Operation Info                                       Start-up Cost                    Total Cost                       Number of Rows                   Row Width                       
Limit                              CTE qry1                                           28553.93                         28554.89                         384                              376                             
  |--Hash Join                     Hash Cond: ((tblproduk.supplierid)::text = (tblsup 3274.11                          28179.15                         3832                             84                              
    |--Hash Join                   Hash Cond: ((tbltransaksi.kodebarang)::text = (tbl 3252.43                          28008.98                         3832                             67                              
      |--Seq Scan on tbltransaks   Filter: ((jualid IS NOT NULL) AND (date_part('year 0.00                             24684.70                         3832                             29                              
      |--Hash                    null                                                 2188.30                          2188.30                          85130                            51                              
        |--Seq Scan on tblproduk null                                                 0.00                             2188.30                          85130                            51                              
    |--Hash                      null                                                 14.08                            14.08                            608                              26                              
      |--Seq Scan on tblsupplier null                                                 0.00                             14.08                            608                              26                              
Sort                               Sort Key: (sum(COALESCE(qry1.keluar, 0::numeric))) 374.78                           375.74                           384                              376                             
  |--HashAggregate               null                                                 354.46                           358.30                           384                              376                             
    |--CTE Scan on qry1          null                                                 0.00                             76.64                            3832                             376                             


the table transaksi :

CREATE TABLE public.tbltransaksi (
  id INTEGER NOT NULL,
  tanggal DATE,
  kodebarang VARCHAR(20),
  masuk NUMERIC(10,2) DEFAULT 0,
  keluar NUMERIC(10,2) DEFAULT 0,
  satuan VARCHAR(5),
  keterangan VARCHAR(30),
  jenis VARCHAR(5),
  harga NUMERIC(15,2) DEFAULT 0,
  discount NUMERIC(10,2) DEFAULT 0,
  jualid INTEGER,
  beliid INTEGER,
  mutasiid INTEGER,
  nobukti VARCHAR(20),
  customerid VARCHAR(20),
  modal NUMERIC(15,2) DEFAULT 0,
  awalid INTEGER,
  terimabrgid INTEGER,
  opnameid INTEGER,
  returjualid INTEGER,
  returbeliid INTEGER,
  CONSTRAINT tbltransaksi_pkey PRIMARY KEY(id),
  CONSTRAINT tbltransaksi_fk FOREIGN KEY (returjualid)
    REFERENCES public.tblreturjual(id)
    ON DELETE CASCADE
    ON UPDATE NO ACTION
    DEFERRABLE
    INITIALLY IMMEDIATE,
  CONSTRAINT tbltransaksi_fk1 FOREIGN KEY (jualid)
    REFERENCES public.tblpenjualan(id)
    ON DELETE CASCADE
    ON UPDATE NO ACTION
    NOT DEFERRABLE,
  CONSTRAINT tbltransaksi_fk2 FOREIGN KEY (beliid)
    REFERENCES public.tblpembelian(id)
    ON DELETE CASCADE
    ON UPDATE NO ACTION
    NOT DEFERRABLE,
  CONSTRAINT tbltransaksi_fk3 FOREIGN KEY (mutasiid)
    REFERENCES public.tblmutasi(id)
    ON DELETE CASCADE
    ON UPDATE NO ACTION
    NOT DEFERRABLE,
  CONSTRAINT tbltransaksi_fk4 FOREIGN KEY (returbeliid)
    REFERENCES public.tblreturbeli(id)
    ON DELETE CASCADE
    ON UPDATE NO ACTION
    NOT DEFERRABLE
WITH (oids = false);

CREATE INDEX tbltransaksi_idx ON public.tbltransaksi
  USING btree (tanggal);

CREATE INDEX tbltransaksi_idx1 ON public.tbltransaksi
  USING btree (kodebarang COLLATE pg_catalog."default");

CREATE INDEX tbltransaksi_idx2 ON public.tbltransaksi
  USING btree (customerid COLLATE pg_catalog."default");

CREATE INDEX tbltransaksi_idx3 ON public.tbltransaksi
  USING btree (awalid);

CREATE INDEX tbltransaksi_idx4 ON public.tbltransaksi
  USING btree (jualid);

CREATE INDEX tbltransaksi_idx5 ON public.tbltransaksi
  USING btree (beliid);

CREATE INDEX tbltransaksi_idx6 ON public.tbltransaksi
  USING btree (mutasiid);

CREATE INDEX tbltransaksi_idx7 ON public.tbltransaksi
  USING btree (opnameid);

CREATE INDEX tbltransaksi_idx8 ON public.tbltransaksi
  USING btree (returjualid);

CREATE INDEX tbltransaksi_idx9 ON public.tbltransaksi
  USING btree (returbeliid);



Hope i can get answer here. Thank you.

Re: Speed up the query

From
Andreas Kretschmer
Date:
Hengky Liwandouw <hengkyliwandouw@gmail.com> wrote:
>
> But the problem is : when i change the where clause to :
>
> where jualid is not null or returjualid is not null
> and extract(year from tanggal)='2013')

Try to create this index:

create index xxx on public.tbltransaksi((extract(year from tanggal)))
where jualid is not null or returjualid is not null;

an run the query again, and if this not helps show us explain analyse,
you can use explain.depesz.com to provide us the plan.


Andreas
--
Really, I'm not out to destroy Microsoft. That will just be a completely
unintentional side effect.                              (Linus Torvalds)
"If I was god, I would recompile penguin with --enable-fly."   (unknown)
Kaufbach, Saxony, Germany, Europe.              N 51.05082°, E 13.56889°


Re: Speed up the query

From
Hengky Liwandouw
Date:
Andreas, sorry this is the correct analyse for the query.

This is the index i created :

CREATE INDEX tbltransaksi_idx10 ON public.tbltransaksi
 USING btree ((date_part('year'::text, tanggal)));

This is the analyse of the query

"Limit  (cost=346377.92..346380.42 rows=1000 width=376)"
"  Output: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang, (sum(CASE WHEN (qry1.bulan = 1::double precision) THEN
qry1.keluarELSE 0::numeric END)), (sum(CASE WHEN (qry1.bulan = 2::double precision) THEN qry1.keluar ELSE 0::numeric
END)),(sum(CASE WH (...)" 
"  CTE qry1"
"    ->  Hash Join  (cost=4444.64..62681.16 rows=766491 width=84)"
"          Output: tbltransaksi.tanggal, date_part('month'::text, (tbltransaksi.tanggal)::timestamp without time zone),
tblsupplier.id,tblsupplier.nama, tbltransaksi.kodebarang, tblproduk.namabarang, tbltransaksi.keluar, CASE WHEN
(tbltransaksi.discount<= (...)" 
"          Hash Cond: ((tbltransaksi.kodebarang)::text = (tblproduk.produkid)::text)"
"          ->  Seq Scan on public.tbltransaksi  (cost=0.00..24702.53 rows=766491 width=29)"
"                Output: tbltransaksi.id, tbltransaksi.tanggal, tbltransaksi.kodebarang, tbltransaksi.masuk,
tbltransaksi.keluar,tbltransaksi.satuan, tbltransaksi.keterangan, tbltransaksi.jenis, tbltransaksi.harga,
tbltransaksi.discount,tbltransaksi.juali (...)" 
"                Filter: ((tbltransaksi.jualid IS NOT NULL) OR ((tbltransaksi.returjualid IS NOT NULL) AND
(date_part('year'::text,(tbltransaksi.tanggal)::timestamp without time zone) = 2013::double precision)))" 
"          ->  Hash  (cost=3380.52..3380.52 rows=85130 width=68)"
"                Output: tblproduk.namabarang, tblproduk.produkid, tblsupplier.id, tblsupplier.nama"
"                ->  Hash Join  (cost=21.68..3380.52 rows=85130 width=68)"
"                      Output: tblproduk.namabarang, tblproduk.produkid, tblsupplier.id, tblsupplier.nama"
"                      Hash Cond: ((tblproduk.supplierid)::text = (tblsupplier.id)::text)"
"                      ->  Seq Scan on public.tblproduk  (cost=0.00..2188.30 rows=85130 width=51)"
"                            Output: tblproduk.produkid, tblproduk.namabarang, tblproduk.hargajual,
tblproduk.subkategoriid,tblproduk.createby, tblproduk.kodepromo, tblproduk.satuan, tblproduk.foto, tblproduk.pajak,
tblproduk.listingfee,tblproduk.supplier (...)" 
"                      ->  Hash  (cost=14.08..14.08 rows=608 width=26)"
"                            Output: tblsupplier.id, tblsupplier.nama"
"                            ->  Seq Scan on public.tblsupplier  (cost=0.00..14.08 rows=608 width=26)"
"                                  Output: tblsupplier.id, tblsupplier.nama"
"  ->  Sort  (cost=283696.76..283888.39 rows=76650 width=376)"
"        Output: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang, (sum(CASE WHEN (qry1.bulan = 1::double
precision)THEN qry1.keluar ELSE 0::numeric END)), (sum(CASE WHEN (qry1.bulan = 2::double precision) THEN qry1.keluar
ELSE0::numeric END)), (sum(C (...)" 
"        Sort Key: (sum(COALESCE(qry1.keluar, 0::numeric)))"
"        ->  GroupAggregate  (cost=221240.80..279494.13 rows=76650 width=376)"
"              Output: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang, sum(CASE WHEN (qry1.bulan = 1::double
precision)THEN qry1.keluar ELSE 0::numeric END), sum(CASE WHEN (qry1.bulan = 2::double precision) THEN qry1.keluar ELSE
0::numericEND), sum( (...)" 
"              ->  Sort  (cost=221240.80..223157.03 rows=766491 width=376)"
"                    Output: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang, qry1.bulan, qry1.keluar"
"                    Sort Key: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang"
"                    ->  CTE Scan on qry1  (cost=0.00..15329.82 rows=766491 width=376)"
"                          Output: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang, qry1.bulan, qry1.keluar"


On Dec 1, 2013, at 3:12 PM, Andreas Kretschmer wrote:

> Hengky Liwandouw <hengkyliwandouw@gmail.com> wrote:
>>
>> But the problem is : when i change the where clause to :
>>
>> where jualid is not null or returjualid is not null
>> and extract(year from tanggal)='2013')
>
> Try to create this index:
>
> create index xxx on public.tbltransaksi((extract(year from tanggal)))
> where jualid is not null or returjualid is not null;
>
> an run the query again, and if this not helps show us explain analyse,
> you can use explain.depesz.com to provide us the plan.
>
>
> Andreas
> --
> Really, I'm not out to destroy Microsoft. That will just be a completely
> unintentional side effect.                              (Linus Torvalds)
> "If I was god, I would recompile penguin with --enable-fly."   (unknown)
> Kaufbach, Saxony, Germany, Europe.              N 51.05082°, E 13.56889°
>
>
> --
> Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
> To make changes to your subscription:
> http://www.postgresql.org/mailpref/pgsql-performance



Re: Speed up the query

From
Andreas Kretschmer
Date:
Hengky Liwandouw <hengkyliwandouw@gmail.com> wrote:

> Thanks Adreas,
>
> Already try your suggestion but it not help.  This is the index i created :
>
> CREATE INDEX tbltransaksi_idx10 ON public.tbltransaksi
>   USING btree ((date_part('year'::text, tanggal)));

I wrote:

> create index xxx on public.tbltransaksi((extract(year from
> tanggal))) where jualid is not null or returjualid is not null;

2 lines, with the where-condition ;-)

Your explain isn't a explain ANALYSE, and it's not for the 2nd query
(with condition on returjualid)

Do you have propper indexes on tblsupplier.id and tblproduk.produkid?

I see seq-scans there...


>
> Speed is the same. Here is the analyse result :
>
> "Limit  (cost=11821.17..11822.13 rows=384 width=376)"
> "  Output: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang, (sum(CASE WHEN (qry1.bulan = 1::double precision)
THENqry1.keluar ELSE 0::numeric END)), (sum(CASE WHEN (qry1.bulan = 2::double precision) THEN qry1.keluar ELSE
0::numericEND)), (sum(CASE WH (...)" 
> "  CTE qry1"
> "    ->  Hash Join  (cost=3353.66..11446.48 rows=3831 width=84)"
> "          Output: tbltransaksi.tanggal, date_part('month'::text, (tbltransaksi.tanggal)::timestamp without time
zone),tblsupplier.id, tblsupplier.nama, tbltransaksi.kodebarang, tblproduk.namabarang, tbltransaksi.keluar, CASE WHEN
(tbltransaksi.discount<= (...)" 
> "          Hash Cond: ((tblproduk.supplierid)::text = (tblsupplier.id)::text)"
> "          ->  Hash Join  (cost=3331.98..11276.35 rows=3831 width=67)"
> "                Output: tbltransaksi.tanggal, tbltransaksi.kodebarang, tbltransaksi.keluar, tbltransaksi.discount,
tbltransaksi.harga,tblproduk.namabarang, tblproduk.supplierid" 
> "                Hash Cond: ((tbltransaksi.kodebarang)::text = (tblproduk.produkid)::text)"
> "                ->  Bitmap Heap Scan on public.tbltransaksi  (cost=79.55..7952.09 rows=3831 width=29)"
> "                      Output: tbltransaksi.id, tbltransaksi.tanggal, tbltransaksi.kodebarang, tbltransaksi.masuk,
tbltransaksi.keluar,tbltransaksi.satuan, tbltransaksi.keterangan, tbltransaksi.jenis, tbltransaksi.harga,
tbltransaksi.discount,tbltransaksi (...)" 
> "                      Recheck Cond: (date_part('year'::text, (tbltransaksi.tanggal)::timestamp without time zone) =
2013::doubleprecision)" 
> "                      Filter: (tbltransaksi.jualid IS NOT NULL)"
> "                      ->  Bitmap Index Scan on tbltransaksi_idx10  (cost=0.00..78.59 rows=4022 width=0)"
> "                            Index Cond: (date_part('year'::text, (tbltransaksi.tanggal)::timestamp without time
zone)= 2013::double precision)" 
> "                ->  Hash  (cost=2188.30..2188.30 rows=85130 width=51)"
> "                      Output: tblproduk.namabarang, tblproduk.produkid, tblproduk.supplierid"
> "                      ->  Seq Scan on public.tblproduk  (cost=0.00..2188.30 rows=85130 width=51)"
> "                            Output: tblproduk.namabarang, tblproduk.produkid, tblproduk.supplierid"
> "          ->  Hash  (cost=14.08..14.08 rows=608 width=26)"
> "                Output: tblsupplier.id, tblsupplier.nama"
> "                ->  Seq Scan on public.tblsupplier  (cost=0.00..14.08 rows=608 width=26)"
> "                      Output: tblsupplier.id, tblsupplier.nama"
> "  ->  Sort  (cost=374.69..375.65 rows=384 width=376)"
> "        Output: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang, (sum(CASE WHEN (qry1.bulan = 1::double
precision)THEN qry1.keluar ELSE 0::numeric END)), (sum(CASE WHEN (qry1.bulan = 2::double precision) THEN qry1.keluar
ELSE0::numeric END)), (sum(C (...)" 
> "        Sort Key: (sum(COALESCE(qry1.keluar, 0::numeric)))"
> "        ->  HashAggregate  (cost=354.37..358.21 rows=384 width=376)"
> "              Output: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang, sum(CASE WHEN (qry1.bulan = 1::double
precision)THEN qry1.keluar ELSE 0::numeric END), sum(CASE WHEN (qry1.bulan = 2::double precision) THEN qry1.keluar ELSE
0::numericEND), sum( (...)" 
> "              ->  CTE Scan on qry1  (cost=0.00..76.62 rows=3831 width=376)"
> "                    Output: qry1.tanggal, qry1.bulan, qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang,
qry1.keluar,qry1.jumlah" 
>
> On Dec 1, 2013, at 3:12 PM, Andreas Kretschmer wrote:
>
> > Hengky Liwandouw <hengkyliwandouw@gmail.com> wrote:
> >>
> >> But the problem is : when i change the where clause to :
> >>
> >> where jualid is not null or returjualid is not null
> >> and extract(year from tanggal)='2013')
> >
> > Try to create this index:
> >
> > create index xxx on public.tbltransaksi((extract(year from tanggal)))
> > where jualid is not null or returjualid is not null;
> >
> > an run the query again, and if this not helps show us explain analyse,
> > you can use explain.depesz.com to provide us the plan.
> >
> >
> > Andreas
> > --
> > Really, I'm not out to destroy Microsoft. That will just be a completely
> > unintentional side effect.                              (Linus Torvalds)
> > "If I was god, I would recompile penguin with --enable-fly."   (unknown)
> > Kaufbach, Saxony, Germany, Europe.              N 51.05082°, E 13.56889°
> >
> >
> > --
> > Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
> > To make changes to your subscription:
> > http://www.postgresql.org/mailpref/pgsql-performance
>


Andreas
--
Really, I'm not out to destroy Microsoft. That will just be a completely
unintentional side effect.                              (Linus Torvalds)
"If I was god, I would recompile penguin with --enable-fly."   (unknown)
Kaufbach, Saxony, Germany, Europe.              N 51.05082°, E 13.56889°


Re: Speed up the query

From
Hengky Liwandouw
Date:
Ok, i just recreate the index :

CREATE INDEX tbltransaksi_idx10
  ON tbltransaksi
  USING btree
  (date_part('year'::text, tanggal))
  WHERE jualid IS NOT NULL OR returjualid IS NOT NULL;

(PGAdminIII always convert extract(year from tanggal) to date_part('year'::text,tanggal))

This is the product table

CREATE TABLE public.tblproduk (
  produkid VARCHAR(20) NOT NULL,
  namabarang VARCHAR(50),
  hargajual NUMERIC(15,2) DEFAULT 0,
  subkategoriid VARCHAR(10),
  createby VARCHAR(10),
  kodepromo VARCHAR(10),
  satuan VARCHAR(5),
  foto BYTEA,
  pajak BOOLEAN,
  listingfee BOOLEAN,
  supplierid VARCHAR(20),
  modifyby VARCHAR(10),
  qtygrosir INTEGER DEFAULT 0,
  hargagrosir NUMERIC(15,2) DEFAULT 0,
  diskonjual NUMERIC(5,2) DEFAULT 0,
  modal NUMERIC(15,2) DEFAULT 0,
  CONSTRAINT tblproduk_pkey PRIMARY KEY(produkid)
)
WITH (oids = false);

CREATE INDEX tblproduk_idx ON public.tblproduk
  USING btree (namabarang COLLATE pg_catalog."default");

CREATE INDEX tblproduk_idx1 ON public.tblproduk
  USING btree (supplierid COLLATE pg_catalog."default");

CREATE INDEX tblproduk_idx2 ON public.tblproduk
  USING btree (subkategoriid COLLATE pg_catalog."default");


Supplier table :

CREATE TABLE public.tblsupplier (
  id VARCHAR(20) NOT NULL,
  nama VARCHAR(50),
  alamat VARCHAR(50),
  telepon VARCHAR(50),
  kontak VARCHAR(50),
  email VARCHAR(50),
  kota VARCHAR(50),
  hp VARCHAR(50),
  createby VARCHAR(10),
  modifyby VARCHAR(10),
  CONSTRAINT tblsupplier_pkey PRIMARY KEY(id)
)
WITH (oids = false);

CREATE INDEX tblsupplier_idx ON public.tblsupplier
  USING btree (nama COLLATE pg_catalog."default");

CREATE INDEX tblsupplier_idx1 ON public.tblsupplier
  USING btree (kota COLLATE pg_catalog."default");

Transaksi table :

CREATE TABLE public.tbltransaksi (
  id INTEGER NOT NULL,
  tanggal DATE,
  kodebarang VARCHAR(20),
  masuk NUMERIC(10,2) DEFAULT 0,
  keluar NUMERIC(10,2) DEFAULT 0,
  satuan VARCHAR(5),
  keterangan VARCHAR(30),
  jenis VARCHAR(5),
  harga NUMERIC(15,2) DEFAULT 0,
  discount NUMERIC(10,2) DEFAULT 0,
  jualid INTEGER,
  beliid INTEGER,
  mutasiid INTEGER,
  nobukti VARCHAR(20),
  customerid VARCHAR(20),
  modal NUMERIC(15,2) DEFAULT 0,
  awalid INTEGER,
  terimabrgid INTEGER,
  opnameid INTEGER,
  returjualid INTEGER,
  returbeliid INTEGER,
  CONSTRAINT tbltransaksi_pkey PRIMARY KEY(id),
  CONSTRAINT tbltransaksi_fk FOREIGN KEY (returjualid)
    REFERENCES public.tblreturjual(id)
    ON DELETE CASCADE
    ON UPDATE NO ACTION
    DEFERRABLE
    INITIALLY IMMEDIATE,
  CONSTRAINT tbltransaksi_fk1 FOREIGN KEY (jualid)
    REFERENCES public.tblpenjualan(id)
    ON DELETE CASCADE
    ON UPDATE NO ACTION
    NOT DEFERRABLE,
  CONSTRAINT tbltransaksi_fk2 FOREIGN KEY (beliid)
    REFERENCES public.tblpembelian(id)
    ON DELETE CASCADE
    ON UPDATE NO ACTION
    NOT DEFERRABLE,
  CONSTRAINT tbltransaksi_fk3 FOREIGN KEY (mutasiid)
    REFERENCES public.tblmutasi(id)
    ON DELETE CASCADE
    ON UPDATE NO ACTION
    NOT DEFERRABLE,
  CONSTRAINT tbltransaksi_fk4 FOREIGN KEY (returbeliid)
    REFERENCES public.tblreturbeli(id)
    ON DELETE CASCADE
    ON UPDATE NO ACTION
    NOT DEFERRABLE
)
WITH (oids = false);

CREATE INDEX tbltransaksi_idx ON public.tbltransaksi
  USING btree (tanggal);

CREATE INDEX tbltransaksi_idx1 ON public.tbltransaksi
  USING btree (kodebarang COLLATE pg_catalog."default");

CREATE INDEX tbltransaksi_idx10 ON public.tbltransaksi
  USING btree ((date_part('year'::text, tanggal)))
  WHERE ((jualid IS NOT NULL) OR (returjualid IS NOT NULL));

CREATE INDEX tbltransaksi_idx2 ON public.tbltransaksi
  USING btree (customerid COLLATE pg_catalog."default");

CREATE INDEX tbltransaksi_idx3 ON public.tbltransaksi
  USING btree (awalid);

CREATE INDEX tbltransaksi_idx4 ON public.tbltransaksi
  USING btree (jualid);

CREATE INDEX tbltransaksi_idx5 ON public.tbltransaksi
  USING btree (beliid);

CREATE INDEX tbltransaksi_idx6 ON public.tbltransaksi
  USING btree (mutasiid);

CREATE INDEX tbltransaksi_idx7 ON public.tbltransaksi
  USING btree (opnameid);

CREATE INDEX tbltransaksi_idx8 ON public.tbltransaksi
  USING btree (returjualid);

CREATE INDEX tbltransaksi_idx9 ON public.tbltransaksi
  USING btree (returbeliid);


the query that run slow:

with qry1 as
(select tanggal, extract(month from tanggal) as bulan, tblsupplier.id, nama, kodebarang, namabarang, keluar,
    case when discount<=100 then
        keluar*(harga -(discount/100*harga))
    when tbltransaksi.discount>100 then
        keluar*(harga-discount)
    end
    as jumlah
from tbltransaksi
join tblproduk on tbltransaksi.kodebarang=tblproduk.produkid
join tblsupplier on tblproduk.supplierid=tblsupplier.id
where jualid is not null or returjualid is not null
and extract(year from tanggal)='2013')

select
  id, nama, kodebarang, namabarang,
  sum(case when bulan = 1 then keluar else 0 end) as Jan,
  sum(case when bulan = 2 then keluar else 0 end) as Feb,
  sum(case when bulan = 3 then keluar else 0 end) as Maret,
  sum(case when bulan = 4 then keluar else 0 end) as April,
  sum(case when bulan = 5 then keluar else 0 end) as Mei,
  sum(case when bulan = 6 then keluar else 0 end) as Juni,
  sum(case when bulan = 7 then keluar else 0 end) as Juli,
  sum(case when bulan = 8 then keluar else 0 end) as Agust,
  sum(case when bulan = 9 then keluar else 0 end) as Sept,
  sum(case when bulan = 10 then keluar else 0 end) as Okt,
  sum(case when bulan = 11 then keluar else 0 end) as Nov,
  sum(case when bulan = 12 then keluar else 0 end) as Des,
  sum(coalesce(keluar,0)) as total
from qry1
group by id, nama, kodebarang, namabarang
order by total desc
limit 1000

this is the explain analyse :

"Limit  (cost=346389.90..346392.40 rows=1000 width=376) (actual time=56765.848..56766.229 rows=1000 loops=1)"
"  CTE qry1"
"    ->  Hash Join  (cost=4444.64..62683.91 rows=766519 width=84) (actual time=87.342..1786.851 rows=737662 loops=1)"
"          Hash Cond: ((tbltransaksi.kodebarang)::text = (tblproduk.produkid)::text)"
"          ->  Seq Scan on tbltransaksi  (cost=0.00..24704.06 rows=766519 width=29) (actual time=0.010..271.147
rows=767225loops=1)" 
"                Filter: ((jualid IS NOT NULL) OR ((returjualid IS NOT NULL) AND (date_part('year'::text,
(tanggal)::timestampwithout time zone) = 2013::double precision)))" 
"                Rows Removed by Filter: 37441"
"          ->  Hash  (cost=3380.52..3380.52 rows=85130 width=68) (actual time=87.265..87.265 rows=65219 loops=1)"
"                Buckets: 16384  Batches: 1  Memory Usage: 5855kB"
"                ->  Hash Join  (cost=21.68..3380.52 rows=85130 width=68) (actual time=0.748..59.469 rows=65219
loops=1)"
"                      Hash Cond: ((tblproduk.supplierid)::text = (tblsupplier.id)::text)"
"                      ->  Seq Scan on tblproduk  (cost=0.00..2188.30 rows=85130 width=51) (actual time=0.005..17.184
rows=85034loops=1)" 
"                      ->  Hash  (cost=14.08..14.08 rows=608 width=26) (actual time=0.730..0.730 rows=609 loops=1)"
"                            Buckets: 1024  Batches: 1  Memory Usage: 28kB"
"                            ->  Seq Scan on tblsupplier  (cost=0.00..14.08 rows=608 width=26) (actual
time=0.006..0.298rows=609 loops=1)" 
"  ->  Sort  (cost=283705.99..283897.62 rows=76652 width=376) (actual time=56765.846..56766.006 rows=1000 loops=1)"
"        Sort Key: (sum(COALESCE(qry1.keluar, 0::numeric)))"
"        Sort Method: top-N heapsort  Memory: 280kB"
"        ->  GroupAggregate  (cost=221247.80..279503.25 rows=76652 width=376) (actual time=50731.735..56739.181
rows=23630loops=1)" 
"              ->  Sort  (cost=221247.80..223164.10 rows=766519 width=376) (actual time=50731.687..54455.528
rows=737662loops=1)" 
"                    Sort Key: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang"
"                    Sort Method: external merge  Disk: 71872kB"
"                    ->  CTE Scan on qry1  (cost=0.00..15330.38 rows=766519 width=376) (actual time=87.346..2577.066
rows=737662loops=1)" 
"Total runtime: 56787.136 ms"


Hope you can help.



On Dec 1, 2013, at 4:35 PM, Andreas Kretschmer wrote:

> Hengky Liwandouw <hengkyliwandouw@gmail.com> wrote:
>
>> Thanks Adreas,
>>
>> Already try your suggestion but it not help.  This is the index i created :
>>
>> CREATE INDEX tbltransaksi_idx10 ON public.tbltransaksi
>>  USING btree ((date_part('year'::text, tanggal)));
>
> I wrote:
>
>> create index xxx on public.tbltransaksi((extract(year from
>> tanggal))) where jualid is not null or returjualid is not null;
>
> 2 lines, with the where-condition ;-)
>
> Your explain isn't a explain ANALYSE, and it's not for the 2nd query
> (with condition on returjualid)
>
> Do you have propper indexes on tblsupplier.id and tblproduk.produkid?
>
> I see seq-scans there...
>
>
>>
>> Speed is the same. Here is the analyse result :
>>
>> "Limit  (cost=11821.17..11822.13 rows=384 width=376)"
>> "  Output: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang, (sum(CASE WHEN (qry1.bulan = 1::double precision)
THENqry1.keluar ELSE 0::numeric END)), (sum(CASE WHEN (qry1.bulan = 2::double precision) THEN qry1.keluar ELSE
0::numericEND)), (sum(CASE WH (...)" 
>> "  CTE qry1"
>> "    ->  Hash Join  (cost=3353.66..11446.48 rows=3831 width=84)"
>> "          Output: tbltransaksi.tanggal, date_part('month'::text, (tbltransaksi.tanggal)::timestamp without time
zone),tblsupplier.id, tblsupplier.nama, tbltransaksi.kodebarang, tblproduk.namabarang, tbltransaksi.keluar, CASE WHEN
(tbltransaksi.discount<= (...)" 
>> "          Hash Cond: ((tblproduk.supplierid)::text = (tblsupplier.id)::text)"
>> "          ->  Hash Join  (cost=3331.98..11276.35 rows=3831 width=67)"
>> "                Output: tbltransaksi.tanggal, tbltransaksi.kodebarang, tbltransaksi.keluar, tbltransaksi.discount,
tbltransaksi.harga,tblproduk.namabarang, tblproduk.supplierid" 
>> "                Hash Cond: ((tbltransaksi.kodebarang)::text = (tblproduk.produkid)::text)"
>> "                ->  Bitmap Heap Scan on public.tbltransaksi  (cost=79.55..7952.09 rows=3831 width=29)"
>> "                      Output: tbltransaksi.id, tbltransaksi.tanggal, tbltransaksi.kodebarang, tbltransaksi.masuk,
tbltransaksi.keluar,tbltransaksi.satuan, tbltransaksi.keterangan, tbltransaksi.jenis, tbltransaksi.harga,
tbltransaksi.discount,tbltransaksi (...)" 
>> "                      Recheck Cond: (date_part('year'::text, (tbltransaksi.tanggal)::timestamp without time zone) =
2013::doubleprecision)" 
>> "                      Filter: (tbltransaksi.jualid IS NOT NULL)"
>> "                      ->  Bitmap Index Scan on tbltransaksi_idx10  (cost=0.00..78.59 rows=4022 width=0)"
>> "                            Index Cond: (date_part('year'::text, (tbltransaksi.tanggal)::timestamp without time
zone)= 2013::double precision)" 
>> "                ->  Hash  (cost=2188.30..2188.30 rows=85130 width=51)"
>> "                      Output: tblproduk.namabarang, tblproduk.produkid, tblproduk.supplierid"
>> "                      ->  Seq Scan on public.tblproduk  (cost=0.00..2188.30 rows=85130 width=51)"
>> "                            Output: tblproduk.namabarang, tblproduk.produkid, tblproduk.supplierid"
>> "          ->  Hash  (cost=14.08..14.08 rows=608 width=26)"
>> "                Output: tblsupplier.id, tblsupplier.nama"
>> "                ->  Seq Scan on public.tblsupplier  (cost=0.00..14.08 rows=608 width=26)"
>> "                      Output: tblsupplier.id, tblsupplier.nama"
>> "  ->  Sort  (cost=374.69..375.65 rows=384 width=376)"
>> "        Output: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang, (sum(CASE WHEN (qry1.bulan = 1::double
precision)THEN qry1.keluar ELSE 0::numeric END)), (sum(CASE WHEN (qry1.bulan = 2::double precision) THEN qry1.keluar
ELSE0::numeric END)), (sum(C (...)" 
>> "        Sort Key: (sum(COALESCE(qry1.keluar, 0::numeric)))"
>> "        ->  HashAggregate  (cost=354.37..358.21 rows=384 width=376)"
>> "              Output: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang, sum(CASE WHEN (qry1.bulan = 1::double
precision)THEN qry1.keluar ELSE 0::numeric END), sum(CASE WHEN (qry1.bulan = 2::double precision) THEN qry1.keluar ELSE
0::numericEND), sum( (...)" 
>> "              ->  CTE Scan on qry1  (cost=0.00..76.62 rows=3831 width=376)"
>> "                    Output: qry1.tanggal, qry1.bulan, qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang,
qry1.keluar,qry1.jumlah" 
>>
>> On Dec 1, 2013, at 3:12 PM, Andreas Kretschmer wrote:
>>
>>> Hengky Liwandouw <hengkyliwandouw@gmail.com> wrote:
>>>>
>>>> But the problem is : when i change the where clause to :
>>>>
>>>> where jualid is not null or returjualid is not null
>>>> and extract(year from tanggal)='2013')
>>>
>>> Try to create this index:
>>>
>>> create index xxx on public.tbltransaksi((extract(year from tanggal)))
>>> where jualid is not null or returjualid is not null;
>>>
>>> an run the query again, and if this not helps show us explain analyse,
>>> you can use explain.depesz.com to provide us the plan.
>>>
>>>
>>> Andreas
>>> --
>>> Really, I'm not out to destroy Microsoft. That will just be a completely
>>> unintentional side effect.                              (Linus Torvalds)
>>> "If I was god, I would recompile penguin with --enable-fly."   (unknown)
>>> Kaufbach, Saxony, Germany, Europe.              N 51.05082°, E 13.56889°
>>>
>>>
>>> --
>>> Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
>>> To make changes to your subscription:
>>> http://www.postgresql.org/mailpref/pgsql-performance
>>
>
>
> Andreas
> --
> Really, I'm not out to destroy Microsoft. That will just be a completely
> unintentional side effect.                              (Linus Torvalds)
> "If I was god, I would recompile penguin with --enable-fly."   (unknown)
> Kaufbach, Saxony, Germany, Europe.              N 51.05082°, E 13.56889°
>
>
> --
> Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
> To make changes to your subscription:
> http://www.postgresql.org/mailpref/pgsql-performance



Re: Speed up the query

From
desmodemone
Date:
Hello,
             your problem seems to arises from  the sort that id sone to disk :

"              ->  Sort  (cost=221247.80..223164.10 rows=766519 width=376) (actual time=50731.687..54455.528 rows=737662 loops=1)"
"                    Sort Key: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang"
"                    Sort Method: external merge  Disk: 71872kB"
"                    ->  CTE Scan on qry1  (cost=0.00..15330.38 rows=766519 width=376) (actual time=87.346..2577.066 rows=737662 loops=1)"
 infact the qry1 is builded in 2.5 seconds but for the sort it neeses around 50 seconds.
Try to increase work_mem to almost 100 MB and see if the sort will done in memory.

it's better you use the explain (analyze,buffers) so we could see  the number of buffers hitted in shared memory.

Could you post how much big in Mb are this tables ?

Mat


2013/12/1 Hengky Liwandouw <hengkyliwandouw@gmail.com>
Ok, i just recreate the index :

CREATE INDEX tbltransaksi_idx10
  ON tbltransaksi
  USING btree
  (date_part('year'::text, tanggal))
  WHERE jualid IS NOT NULL OR returjualid IS NOT NULL;

(PGAdminIII always convert extract(year from tanggal) to date_part('year'::text,tanggal))

This is the product table

CREATE TABLE public.tblproduk (
  produkid VARCHAR(20) NOT NULL,
  namabarang VARCHAR(50),
  hargajual NUMERIC(15,2) DEFAULT 0,
  subkategoriid VARCHAR(10),
  createby VARCHAR(10),
  kodepromo VARCHAR(10),
  satuan VARCHAR(5),
  foto BYTEA,
  pajak BOOLEAN,
  listingfee BOOLEAN,
  supplierid VARCHAR(20),
  modifyby VARCHAR(10),
  qtygrosir INTEGER DEFAULT 0,
  hargagrosir NUMERIC(15,2) DEFAULT 0,
  diskonjual NUMERIC(5,2) DEFAULT 0,
  modal NUMERIC(15,2) DEFAULT 0,
  CONSTRAINT tblproduk_pkey PRIMARY KEY(produkid)
)
WITH (oids = false);

CREATE INDEX tblproduk_idx ON public.tblproduk
  USING btree (namabarang COLLATE pg_catalog."default");

CREATE INDEX tblproduk_idx1 ON public.tblproduk
  USING btree (supplierid COLLATE pg_catalog."default");

CREATE INDEX tblproduk_idx2 ON public.tblproduk
  USING btree (subkategoriid COLLATE pg_catalog."default");


Supplier table :

CREATE TABLE public.tblsupplier (
  id VARCHAR(20) NOT NULL,
  nama VARCHAR(50),
  alamat VARCHAR(50),
  telepon VARCHAR(50),
  kontak VARCHAR(50),
  email VARCHAR(50),
  kota VARCHAR(50),
  hp VARCHAR(50),
  createby VARCHAR(10),
  modifyby VARCHAR(10),
  CONSTRAINT tblsupplier_pkey PRIMARY KEY(id)
)
WITH (oids = false);

CREATE INDEX tblsupplier_idx ON public.tblsupplier
  USING btree (nama COLLATE pg_catalog."default");

CREATE INDEX tblsupplier_idx1 ON public.tblsupplier
  USING btree (kota COLLATE pg_catalog."default");

Transaksi table :

CREATE TABLE public.tbltransaksi (
  id INTEGER NOT NULL,
  tanggal DATE,
  kodebarang VARCHAR(20),
  masuk NUMERIC(10,2) DEFAULT 0,
  keluar NUMERIC(10,2) DEFAULT 0,
  satuan VARCHAR(5),
  keterangan VARCHAR(30),
  jenis VARCHAR(5),
  harga NUMERIC(15,2) DEFAULT 0,
  discount NUMERIC(10,2) DEFAULT 0,
  jualid INTEGER,
  beliid INTEGER,
  mutasiid INTEGER,
  nobukti VARCHAR(20),
  customerid VARCHAR(20),
  modal NUMERIC(15,2) DEFAULT 0,
  awalid INTEGER,
  terimabrgid INTEGER,
  opnameid INTEGER,
  returjualid INTEGER,
  returbeliid INTEGER,
  CONSTRAINT tbltransaksi_pkey PRIMARY KEY(id),
  CONSTRAINT tbltransaksi_fk FOREIGN KEY (returjualid)
    REFERENCES public.tblreturjual(id)
    ON DELETE CASCADE
    ON UPDATE NO ACTION
    DEFERRABLE
    INITIALLY IMMEDIATE,
  CONSTRAINT tbltransaksi_fk1 FOREIGN KEY (jualid)
    REFERENCES public.tblpenjualan(id)
    ON DELETE CASCADE
    ON UPDATE NO ACTION
    NOT DEFERRABLE,
  CONSTRAINT tbltransaksi_fk2 FOREIGN KEY (beliid)
    REFERENCES public.tblpembelian(id)
    ON DELETE CASCADE
    ON UPDATE NO ACTION
    NOT DEFERRABLE,
  CONSTRAINT tbltransaksi_fk3 FOREIGN KEY (mutasiid)
    REFERENCES public.tblmutasi(id)
    ON DELETE CASCADE
    ON UPDATE NO ACTION
    NOT DEFERRABLE,
  CONSTRAINT tbltransaksi_fk4 FOREIGN KEY (returbeliid)
    REFERENCES public.tblreturbeli(id)
    ON DELETE CASCADE
    ON UPDATE NO ACTION
    NOT DEFERRABLE
)
WITH (oids = false);

CREATE INDEX tbltransaksi_idx ON public.tbltransaksi
  USING btree (tanggal);

CREATE INDEX tbltransaksi_idx1 ON public.tbltransaksi
  USING btree (kodebarang COLLATE pg_catalog."default");

CREATE INDEX tbltransaksi_idx10 ON public.tbltransaksi
  USING btree ((date_part('year'::text, tanggal)))
  WHERE ((jualid IS NOT NULL) OR (returjualid IS NOT NULL));

CREATE INDEX tbltransaksi_idx2 ON public.tbltransaksi
  USING btree (customerid COLLATE pg_catalog."default");

CREATE INDEX tbltransaksi_idx3 ON public.tbltransaksi
  USING btree (awalid);

CREATE INDEX tbltransaksi_idx4 ON public.tbltransaksi
  USING btree (jualid);

CREATE INDEX tbltransaksi_idx5 ON public.tbltransaksi
  USING btree (beliid);

CREATE INDEX tbltransaksi_idx6 ON public.tbltransaksi
  USING btree (mutasiid);

CREATE INDEX tbltransaksi_idx7 ON public.tbltransaksi
  USING btree (opnameid);

CREATE INDEX tbltransaksi_idx8 ON public.tbltransaksi
  USING btree (returjualid);

CREATE INDEX tbltransaksi_idx9 ON public.tbltransaksi
  USING btree (returbeliid);


the query that run slow:

with qry1 as
(select tanggal, extract(month from tanggal) as bulan, tblsupplier.id, nama, kodebarang, namabarang, keluar,
        case when discount<=100 then
            keluar*(harga -(discount/100*harga))
        when tbltransaksi.discount>100 then
                keluar*(harga-discount)
        end
    as jumlah
from tbltransaksi
join tblproduk on tbltransaksi.kodebarang=tblproduk.produkid
join tblsupplier on tblproduk.supplierid=tblsupplier.id
where jualid is not null or returjualid is not null
and extract(year from tanggal)='2013')

select
  id, nama, kodebarang, namabarang,
  sum(case when bulan = 1 then keluar else 0 end) as Jan,
  sum(case when bulan = 2 then keluar else 0 end) as Feb,
  sum(case when bulan = 3 then keluar else 0 end) as Maret,
  sum(case when bulan = 4 then keluar else 0 end) as April,
  sum(case when bulan = 5 then keluar else 0 end) as Mei,
  sum(case when bulan = 6 then keluar else 0 end) as Juni,
  sum(case when bulan = 7 then keluar else 0 end) as Juli,
  sum(case when bulan = 8 then keluar else 0 end) as Agust,
  sum(case when bulan = 9 then keluar else 0 end) as Sept,
  sum(case when bulan = 10 then keluar else 0 end) as Okt,
  sum(case when bulan = 11 then keluar else 0 end) as Nov,
  sum(case when bulan = 12 then keluar else 0 end) as Des,
  sum(coalesce(keluar,0)) as total
from qry1
group by id, nama, kodebarang, namabarang
order by total desc
limit 1000

this is the explain analyse :

"Limit  (cost=346389.90..346392.40 rows=1000 width=376) (actual time=56765.848..56766.229 rows=1000 loops=1)"
"  CTE qry1"
"    ->  Hash Join  (cost=4444.64..62683.91 rows=766519 width=84) (actual time=87.342..1786.851 rows=737662 loops=1)"
"          Hash Cond: ((tbltransaksi.kodebarang)::text = (tblproduk.produkid)::text)"
"          ->  Seq Scan on tbltransaksi  (cost=0.00..24704.06 rows=766519 width=29) (actual time=0.010..271.147 rows=767225 loops=1)"
"                Filter: ((jualid IS NOT NULL) OR ((returjualid IS NOT NULL) AND (date_part('year'::text, (tanggal)::timestamp without time zone) = 2013::double precision)))"
"                Rows Removed by Filter: 37441"
"          ->  Hash  (cost=3380.52..3380.52 rows=85130 width=68) (actual time=87.265..87.265 rows=65219 loops=1)"
"                Buckets: 16384  Batches: 1  Memory Usage: 5855kB"
"                ->  Hash Join  (cost=21.68..3380.52 rows=85130 width=68) (actual time=0.748..59.469 rows=65219 loops=1)"
"                      Hash Cond: ((tblproduk.supplierid)::text = (tblsupplier.id)::text)"
"                      ->  Seq Scan on tblproduk  (cost=0.00..2188.30 rows=85130 width=51) (actual time=0.005..17.184 rows=85034 loops=1)"
"                      ->  Hash  (cost=14.08..14.08 rows=608 width=26) (actual time=0.730..0.730 rows=609 loops=1)"
"                            Buckets: 1024  Batches: 1  Memory Usage: 28kB"
"                            ->  Seq Scan on tblsupplier  (cost=0.00..14.08 rows=608 width=26) (actual time=0.006..0.298 rows=609 loops=1)"
"  ->  Sort  (cost=283705.99..283897.62 rows=76652 width=376) (actual time=56765.846..56766.006 rows=1000 loops=1)"
"        Sort Key: (sum(COALESCE(qry1.keluar, 0::numeric)))"
"        Sort Method: top-N heapsort  Memory: 280kB"
"        ->  GroupAggregate  (cost=221247.80..279503.25 rows=76652 width=376) (actual time=50731.735..56739.181 rows=23630 loops=1)"
"              ->  Sort  (cost=221247.80..223164.10 rows=766519 width=376) (actual time=50731.687..54455.528 rows=737662 loops=1)"
"                    Sort Key: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang"
"                    Sort Method: external merge  Disk: 71872kB"
"                    ->  CTE Scan on qry1  (cost=0.00..15330.38 rows=766519 width=376) (actual time=87.346..2577.066 rows=737662 loops=1)"
"Total runtime: 56787.136 ms"


Hope you can help.



On Dec 1, 2013, at 4:35 PM, Andreas Kretschmer wrote:

> Hengky Liwandouw <hengkyliwandouw@gmail.com> wrote:
>
>> Thanks Adreas,
>>
>> Already try your suggestion but it not help.  This is the index i created :
>>
>> CREATE INDEX tbltransaksi_idx10 ON public.tbltransaksi
>>  USING btree ((date_part('year'::text, tanggal)));
>
> I wrote:
>
>> create index xxx on public.tbltransaksi((extract(year from
>> tanggal))) where jualid is not null or returjualid is not null;
>
> 2 lines, with the where-condition ;-)
>
> Your explain isn't a explain ANALYSE, and it's not for the 2nd query
> (with condition on returjualid)
>
> Do you have propper indexes on tblsupplier.id and tblproduk.produkid?
>
> I see seq-scans there...
>
>
>>
>> Speed is the same. Here is the analyse result :
>>
>> "Limit  (cost=11821.17..11822.13 rows=384 width=376)"
>> "  Output: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang, (sum(CASE WHEN (qry1.bulan = 1::double precision) THEN qry1.keluar ELSE 0::numeric END)), (sum(CASE WHEN (qry1.bulan = 2::double precision) THEN qry1.keluar ELSE 0::numeric END)), (sum(CASE WH (...)"
>> "  CTE qry1"
>> "    ->  Hash Join  (cost=3353.66..11446.48 rows=3831 width=84)"
>> "          Output: tbltransaksi.tanggal, date_part('month'::text, (tbltransaksi.tanggal)::timestamp without time zone), tblsupplier.id, tblsupplier.nama, tbltransaksi.kodebarang, tblproduk.namabarang, tbltransaksi.keluar, CASE WHEN (tbltransaksi.discount <= (...)"
>> "          Hash Cond: ((tblproduk.supplierid)::text = (tblsupplier.id)::text)"
>> "          ->  Hash Join  (cost=3331.98..11276.35 rows=3831 width=67)"
>> "                Output: tbltransaksi.tanggal, tbltransaksi.kodebarang, tbltransaksi.keluar, tbltransaksi.discount, tbltransaksi.harga, tblproduk.namabarang, tblproduk.supplierid"
>> "                Hash Cond: ((tbltransaksi.kodebarang)::text = (tblproduk.produkid)::text)"
>> "                ->  Bitmap Heap Scan on public.tbltransaksi  (cost=79.55..7952.09 rows=3831 width=29)"
>> "                      Output: tbltransaksi.id, tbltransaksi.tanggal, tbltransaksi.kodebarang, tbltransaksi.masuk, tbltransaksi.keluar, tbltransaksi.satuan, tbltransaksi.keterangan, tbltransaksi.jenis, tbltransaksi.harga, tbltransaksi.discount, tbltransaksi (...)"
>> "                      Recheck Cond: (date_part('year'::text, (tbltransaksi.tanggal)::timestamp without time zone) = 2013::double precision)"
>> "                      Filter: (tbltransaksi.jualid IS NOT NULL)"
>> "                      ->  Bitmap Index Scan on tbltransaksi_idx10  (cost=0.00..78.59 rows=4022 width=0)"
>> "                            Index Cond: (date_part('year'::text, (tbltransaksi.tanggal)::timestamp without time zone) = 2013::double precision)"
>> "                ->  Hash  (cost=2188.30..2188.30 rows=85130 width=51)"
>> "                      Output: tblproduk.namabarang, tblproduk.produkid, tblproduk.supplierid"
>> "                      ->  Seq Scan on public.tblproduk  (cost=0.00..2188.30 rows=85130 width=51)"
>> "                            Output: tblproduk.namabarang, tblproduk.produkid, tblproduk.supplierid"
>> "          ->  Hash  (cost=14.08..14.08 rows=608 width=26)"
>> "                Output: tblsupplier.id, tblsupplier.nama"
>> "                ->  Seq Scan on public.tblsupplier  (cost=0.00..14.08 rows=608 width=26)"
>> "                      Output: tblsupplier.id, tblsupplier.nama"
>> "  ->  Sort  (cost=374.69..375.65 rows=384 width=376)"
>> "        Output: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang, (sum(CASE WHEN (qry1.bulan = 1::double precision) THEN qry1.keluar ELSE 0::numeric END)), (sum(CASE WHEN (qry1.bulan = 2::double precision) THEN qry1.keluar ELSE 0::numeric END)), (sum(C (...)"
>> "        Sort Key: (sum(COALESCE(qry1.keluar, 0::numeric)))"
>> "        ->  HashAggregate  (cost=354.37..358.21 rows=384 width=376)"
>> "              Output: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang, sum(CASE WHEN (qry1.bulan = 1::double precision) THEN qry1.keluar ELSE 0::numeric END), sum(CASE WHEN (qry1.bulan = 2::double precision) THEN qry1.keluar ELSE 0::numeric END), sum( (...)"
>> "              ->  CTE Scan on qry1  (cost=0.00..76.62 rows=3831 width=376)"
>> "                    Output: qry1.tanggal, qry1.bulan, qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang, qry1.keluar, qry1.jumlah"
>>
>> On Dec 1, 2013, at 3:12 PM, Andreas Kretschmer wrote:
>>
>>> Hengky Liwandouw <hengkyliwandouw@gmail.com> wrote:
>>>>
>>>> But the problem is : when i change the where clause to :
>>>>
>>>> where jualid is not null or returjualid is not null
>>>> and extract(year from tanggal)='2013')
>>>
>>> Try to create this index:
>>>
>>> create index xxx on public.tbltransaksi((extract(year from tanggal)))
>>> where jualid is not null or returjualid is not null;
>>>
>>> an run the query again, and if this not helps show us explain analyse,
>>> you can use explain.depesz.com to provide us the plan.
>>>
>>>
>>> Andreas
>>> --
>>> Really, I'm not out to destroy Microsoft. That will just be a completely
>>> unintentional side effect.                              (Linus Torvalds)
>>> "If I was god, I would recompile penguin with --enable-fly."   (unknown)
>>> Kaufbach, Saxony, Germany, Europe.              N 51.05082°, E 13.56889°
>>>
>>>
>>> --
>>> Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
>>> To make changes to your subscription:
>>> http://www.postgresql.org/mailpref/pgsql-performance
>>
>
>
> Andreas
> --
> Really, I'm not out to destroy Microsoft. That will just be a completely
> unintentional side effect.                              (Linus Torvalds)
> "If I was god, I would recompile penguin with --enable-fly."   (unknown)
> Kaufbach, Saxony, Germany, Europe.              N 51.05082°, E 13.56889°
>
>
> --
> Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
> To make changes to your subscription:
> http://www.postgresql.org/mailpref/pgsql-performance



--
Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance

Re: Speed up the query

From
Torsten Förtsch
Date:
On 01/12/13 10:07, Hengky Liwandouw wrote:
> with qry1 as
> (select tanggal, extract(month from tanggal) as bulan, tblsupplier.id, nama, kodebarang, namabarang, keluar,
>     case when discount<=100 then
>         keluar*(harga -(discount/100*harga))
>     when tbltransaksi.discount>100 then
>         keluar*(harga-discount)
>     end
>     as jumlah
> from tbltransaksi
> join tblproduk on tbltransaksi.kodebarang=tblproduk.produkid
> join tblsupplier on tblproduk.supplierid=tblsupplier.id
> where jualid is not null or returjualid is not null
> and extract(year from tanggal)='2013')
>
> select
>   id, nama, kodebarang, namabarang,
>   sum(case when bulan = 1 then keluar else 0 end) as Jan,
>   sum(case when bulan = 2 then keluar else 0 end) as Feb,
>   sum(case when bulan = 3 then keluar else 0 end) as Maret,
>   sum(case when bulan = 4 then keluar else 0 end) as April,
>   sum(case when bulan = 5 then keluar else 0 end) as Mei,
>   sum(case when bulan = 6 then keluar else 0 end) as Juni,
>   sum(case when bulan = 7 then keluar else 0 end) as Juli,
>   sum(case when bulan = 8 then keluar else 0 end) as Agust,
>   sum(case when bulan = 9 then keluar else 0 end) as Sept,
>   sum(case when bulan = 10 then keluar else 0 end) as Okt,
>   sum(case when bulan = 11 then keluar else 0 end) as Nov,
>   sum(case when bulan = 12 then keluar else 0 end) as Des,
>   sum(coalesce(keluar,0)) as total
> from qry1
> group by id, nama, kodebarang, namabarang
> order by total desc
> limit 1000
>
> this is the explain analyse :
>
> "Limit  (cost=346389.90..346392.40 rows=1000 width=376) (actual time=56765.848..56766.229 rows=1000 loops=1)"
> "  CTE qry1"
> "    ->  Hash Join  (cost=4444.64..62683.91 rows=766519 width=84) (actual time=87.342..1786.851 rows=737662 loops=1)"
> "          Hash Cond: ((tbltransaksi.kodebarang)::text = (tblproduk.produkid)::text)"
> "          ->  Seq Scan on tbltransaksi  (cost=0.00..24704.06 rows=766519 width=29) (actual time=0.010..271.147
rows=767225loops=1)" 
> "                Filter: ((jualid IS NOT NULL) OR ((returjualid IS NOT NULL) AND (date_part('year'::text,
(tanggal)::timestampwithout time zone) = 2013::double precision)))" 
> "                Rows Removed by Filter: 37441"
> "          ->  Hash  (cost=3380.52..3380.52 rows=85130 width=68) (actual time=87.265..87.265 rows=65219 loops=1)"
> "                Buckets: 16384  Batches: 1  Memory Usage: 5855kB"
> "                ->  Hash Join  (cost=21.68..3380.52 rows=85130 width=68) (actual time=0.748..59.469 rows=65219
loops=1)"
> "                      Hash Cond: ((tblproduk.supplierid)::text = (tblsupplier.id)::text)"
> "                      ->  Seq Scan on tblproduk  (cost=0.00..2188.30 rows=85130 width=51) (actual time=0.005..17.184
rows=85034loops=1)" 
> "                      ->  Hash  (cost=14.08..14.08 rows=608 width=26) (actual time=0.730..0.730 rows=609 loops=1)"
> "                            Buckets: 1024  Batches: 1  Memory Usage: 28kB"
> "                            ->  Seq Scan on tblsupplier  (cost=0.00..14.08 rows=608 width=26) (actual
time=0.006..0.298rows=609 loops=1)" 
> "  ->  Sort  (cost=283705.99..283897.62 rows=76652 width=376) (actual time=56765.846..56766.006 rows=1000 loops=1)"
> "        Sort Key: (sum(COALESCE(qry1.keluar, 0::numeric)))"
> "        Sort Method: top-N heapsort  Memory: 280kB"
> "        ->  GroupAggregate  (cost=221247.80..279503.25 rows=76652 width=376) (actual time=50731.735..56739.181
rows=23630loops=1)" 
> "              ->  Sort  (cost=221247.80..223164.10 rows=766519 width=376) (actual time=50731.687..54455.528
rows=737662loops=1)" 
> "                    Sort Key: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang"
> "                    Sort Method: external merge  Disk: 71872kB"
> "                    ->  CTE Scan on qry1  (cost=0.00..15330.38 rows=766519 width=376) (actual time=87.346..2577.066
rows=737662loops=1)" 
> "Total runtime: 56787.136 ms"

I'd try 2 things:

1) set work_mem to ~100Mb. You don't have to do that globally in
postgresql.conf. You can set it for the current session only.

  set work_mem to '100MB';

Then run your query.

2) change the common table expression to a subquery:

select
  id, nama, kodebarang, namabarang,
  sum(case when bulan = 1 then keluar else 0 end) as Jan,
  sum(case when bulan = 2 then keluar else 0 end) as Feb,
  sum(case when bulan = 3 then keluar else 0 end) as Maret,
  sum(case when bulan = 4 then keluar else 0 end) as April,
  sum(case when bulan = 5 then keluar else 0 end) as Mei,
  sum(case when bulan = 6 then keluar else 0 end) as Juni,
  sum(case when bulan = 7 then keluar else 0 end) as Juli,
  sum(case when bulan = 8 then keluar else 0 end) as Agust,
  sum(case when bulan = 9 then keluar else 0 end) as Sept,
  sum(case when bulan = 10 then keluar else 0 end) as Okt,
  sum(case when bulan = 11 then keluar else 0 end) as Nov,
  sum(case when bulan = 12 then keluar else 0 end) as Des,
  sum(coalesce(keluar,0)) as total
from (select tanggal, extract(month from tanggal) as bulan,
             tblsupplier.id, nama, kodebarang, namabarang, keluar,
             case
               when discount<=100 then
                 keluar*(harga -(discount/100*harga))
               when tbltransaksi.discount>100 then
                 keluar*(harga-discount)
             end as jumlah
        from tbltransaksi
        join tblproduk on tbltransaksi.kodebarang=tblproduk.produkid
        join tblsupplier on tblproduk.supplierid=tblsupplier.id
       where jualid is not null or returjualid is not null
         and extract(year from tanggal)='2013') qry1
group by id, nama, kodebarang, namabarang
order by total desc
limit 1000

Selamat berjaya,
Torsten


Re: Speed up the query

From
Hengky Liwandouw
Date:
Dear All,

Thanks for the suggestion ! I tried to change the work_mem and the query only needs 4.9 sec to display the result !


Torsten, your 2nd option didnt work with this error :

ERROR:  syntax error at or near "discount"
LINE 1: ...rang, keluar,             case               when discount<=...
                                                             ^

For Mat : what command i can use to show how big the tables in MB ?

Thanks

On Dec 1, 2013, at 8:06 PM, Torsten Förtsch wrote:

> On 01/12/13 10:07, Hengky Liwandouw wrote:
>> with qry1 as
>> (select tanggal, extract(month from tanggal) as bulan, tblsupplier.id, nama, kodebarang, namabarang, keluar,
>>     case when discount<=100 then
>>         keluar*(harga -(discount/100*harga))
>>     when tbltransaksi.discount>100 then
>>         keluar*(harga-discount)
>>     end
>>    as jumlah
>> from tbltransaksi
>> join tblproduk on tbltransaksi.kodebarang=tblproduk.produkid
>> join tblsupplier on tblproduk.supplierid=tblsupplier.id
>> where jualid is not null or returjualid is not null
>> and extract(year from tanggal)='2013')
>>
>> select
>>  id, nama, kodebarang, namabarang,
>>  sum(case when bulan = 1 then keluar else 0 end) as Jan,
>>  sum(case when bulan = 2 then keluar else 0 end) as Feb,
>>  sum(case when bulan = 3 then keluar else 0 end) as Maret,
>>  sum(case when bulan = 4 then keluar else 0 end) as April,
>>  sum(case when bulan = 5 then keluar else 0 end) as Mei,
>>  sum(case when bulan = 6 then keluar else 0 end) as Juni,
>>  sum(case when bulan = 7 then keluar else 0 end) as Juli,
>>  sum(case when bulan = 8 then keluar else 0 end) as Agust,
>>  sum(case when bulan = 9 then keluar else 0 end) as Sept,
>>  sum(case when bulan = 10 then keluar else 0 end) as Okt,
>>  sum(case when bulan = 11 then keluar else 0 end) as Nov,
>>  sum(case when bulan = 12 then keluar else 0 end) as Des,
>>  sum(coalesce(keluar,0)) as total
>> from qry1
>> group by id, nama, kodebarang, namabarang
>> order by total desc
>> limit 1000
>>
>> this is the explain analyse :
>>
>> "Limit  (cost=346389.90..346392.40 rows=1000 width=376) (actual time=56765.848..56766.229 rows=1000 loops=1)"
>> "  CTE qry1"
>> "    ->  Hash Join  (cost=4444.64..62683.91 rows=766519 width=84) (actual time=87.342..1786.851 rows=737662
loops=1)"
>> "          Hash Cond: ((tbltransaksi.kodebarang)::text = (tblproduk.produkid)::text)"
>> "          ->  Seq Scan on tbltransaksi  (cost=0.00..24704.06 rows=766519 width=29) (actual time=0.010..271.147
rows=767225loops=1)" 
>> "                Filter: ((jualid IS NOT NULL) OR ((returjualid IS NOT NULL) AND (date_part('year'::text,
(tanggal)::timestampwithout time zone) = 2013::double precision)))" 
>> "                Rows Removed by Filter: 37441"
>> "          ->  Hash  (cost=3380.52..3380.52 rows=85130 width=68) (actual time=87.265..87.265 rows=65219 loops=1)"
>> "                Buckets: 16384  Batches: 1  Memory Usage: 5855kB"
>> "                ->  Hash Join  (cost=21.68..3380.52 rows=85130 width=68) (actual time=0.748..59.469 rows=65219
loops=1)"
>> "                      Hash Cond: ((tblproduk.supplierid)::text = (tblsupplier.id)::text)"
>> "                      ->  Seq Scan on tblproduk  (cost=0.00..2188.30 rows=85130 width=51) (actual
time=0.005..17.184rows=85034 loops=1)" 
>> "                      ->  Hash  (cost=14.08..14.08 rows=608 width=26) (actual time=0.730..0.730 rows=609 loops=1)"
>> "                            Buckets: 1024  Batches: 1  Memory Usage: 28kB"
>> "                            ->  Seq Scan on tblsupplier  (cost=0.00..14.08 rows=608 width=26) (actual
time=0.006..0.298rows=609 loops=1)" 
>> "  ->  Sort  (cost=283705.99..283897.62 rows=76652 width=376) (actual time=56765.846..56766.006 rows=1000 loops=1)"
>> "        Sort Key: (sum(COALESCE(qry1.keluar, 0::numeric)))"
>> "        Sort Method: top-N heapsort  Memory: 280kB"
>> "        ->  GroupAggregate  (cost=221247.80..279503.25 rows=76652 width=376) (actual time=50731.735..56739.181
rows=23630loops=1)" 
>> "              ->  Sort  (cost=221247.80..223164.10 rows=766519 width=376) (actual time=50731.687..54455.528
rows=737662loops=1)" 
>> "                    Sort Key: qry1.id, qry1.nama, qry1.kodebarang, qry1.namabarang"
>> "                    Sort Method: external merge  Disk: 71872kB"
>> "                    ->  CTE Scan on qry1  (cost=0.00..15330.38 rows=766519 width=376) (actual time=87.346..2577.066
rows=737662loops=1)" 
>> "Total runtime: 56787.136 ms"
>
> I'd try 2 things:
>
> 1) set work_mem to ~100Mb. You don't have to do that globally in
> postgresql.conf. You can set it for the current session only.
>
>  set work_mem to '100MB';
>
> Then run your query.
>
> 2) change the common table expression to a subquery:
>
> select
>  id, nama, kodebarang, namabarang,
>  sum(case when bulan = 1 then keluar else 0 end) as Jan,
>  sum(case when bulan = 2 then keluar else 0 end) as Feb,
>  sum(case when bulan = 3 then keluar else 0 end) as Maret,
>  sum(case when bulan = 4 then keluar else 0 end) as April,
>  sum(case when bulan = 5 then keluar else 0 end) as Mei,
>  sum(case when bulan = 6 then keluar else 0 end) as Juni,
>  sum(case when bulan = 7 then keluar else 0 end) as Juli,
>  sum(case when bulan = 8 then keluar else 0 end) as Agust,
>  sum(case when bulan = 9 then keluar else 0 end) as Sept,
>  sum(case when bulan = 10 then keluar else 0 end) as Okt,
>  sum(case when bulan = 11 then keluar else 0 end) as Nov,
>  sum(case when bulan = 12 then keluar else 0 end) as Des,
>  sum(coalesce(keluar,0)) as total
> from (select tanggal, extract(month from tanggal) as bulan,
>             tblsupplier.id, nama, kodebarang, namabarang, keluar,
>             case
>               when discount<=100 then
>                 keluar*(harga -(discount/100*harga))
>               when tbltransaksi.discount>100 then
>                 keluar*(harga-discount)
>             end as jumlah
>        from tbltransaksi
>        join tblproduk on tbltransaksi.kodebarang=tblproduk.produkid
>        join tblsupplier on tblproduk.supplierid=tblsupplier.id
>       where jualid is not null or returjualid is not null
>         and extract(year from tanggal)='2013') qry1
> group by id, nama, kodebarang, namabarang
> order by total desc
> limit 1000
>
> Selamat berjaya,
> Torsten



Re: Speed up the query

From
Andreas Kretschmer
Date:
Torsten Förtsch <torsten.foertsch@gmx.net> wrote:
> I'd try 2 things:
>
> 1) set work_mem to ~100Mb. You don't have to do that globally in
> postgresql.conf. You can set it for the current session only.
>
>   set work_mem to '100MB';
>
> Then run your query.
>
> 2) change the common table expression to a subquery:

Yeah, agree.


Andreas
--
Really, I'm not out to destroy Microsoft. That will just be a completely
unintentional side effect.                              (Linus Torvalds)
"If I was god, I would recompile penguin with --enable-fly."   (unknown)
Kaufbach, Saxony, Germany, Europe.              N 51.05082°, E 13.56889°


Re: Speed up the query

From
Andreas Kretschmer
Date:
Hengky Liwandouw <hengkyliwandouw@gmail.com> wrote:

>
> For Mat : what command i can use to show how big the tables in MB ?

http://andreas.scherbaum.la/blog/archives/282-table-size,-database-size.html


Andreas
--
Really, I'm not out to destroy Microsoft. That will just be a completely
unintentional side effect.                              (Linus Torvalds)
"If I was god, I would recompile penguin with --enable-fly."   (unknown)
Kaufbach, Saxony, Germany, Europe.              N 51.05082°, E 13.56889°


Re: Speed up the query

From
Hengky Liwandouw
Date:
Thanks a lot Andreas :)

The tbltransaksi size = 263MB
Total database size = 1277MB

Quite small for so many records store in it.

This group really helpfull.

On Dec 1, 2013, at 8:29 PM, Andreas Kretschmer wrote:

> Hengky Liwandouw <hengkyliwandouw@gmail.com> wrote:
>
>>
>> For Mat : what command i can use to show how big the tables in MB ?
>
> http://andreas.scherbaum.la/blog/archives/282-table-size,-database-size.html
>
>
> Andreas
> --
> Really, I'm not out to destroy Microsoft. That will just be a completely
> unintentional side effect.                              (Linus Torvalds)
> "If I was god, I would recompile penguin with --enable-fly."   (unknown)
> Kaufbach, Saxony, Germany, Europe.              N 51.05082°, E 13.56889°
>
>
> --
> Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
> To make changes to your subscription:
> http://www.postgresql.org/mailpref/pgsql-performance



Re: Speed up the query

From
Kevin Grittner
Date:
Hengky Liwandouw <hengkyliwandouw@gmail.com> wrote:

> where jualid is not null
> and extract(year from tanggal)='2013')

> But the problem is : when i change the where clause to :
>
> where jualid is not null or returjualid is not null
> and extract(year from tanggal)='2013')
>
> (there is additional or returjualid is not null,) the query needs
> 56 second to display the result.

Before worrying about the run time, I would worry about whether you
are getting the results you expect.  That will be interpreted as:

where jualid is not null
   or (returjualid is not null and extract(year from tanggal) = '2013')

... not:

where (jualid is not null or returjualid is not null)
  and extract(year from tanggal) = '2013'
AND has higher priority than OR; so if you want to limit by year
from tanggal even when jualid is not null, you must use
parentheses.

--
Kevin Grittner
EDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company


Re: Speed up the query

From
Hengky Lie
Date:
Thanks Kevin. You are absolutely right. I should use parentheses, it is what i want for the query to do.

It also increasing processing time to 5.444 seconds. Should be okay i think.


On Sun, Dec 1, 2013 at 11:02 PM, Kevin Grittner <kgrittn@ymail.com> wrote:
Hengky Liwandouw <hengkyliwandouw@gmail.com> wrote:

> where jualid is not null
> and extract(year from tanggal)='2013')

> But the problem is : when i change the where clause to :
>
> where jualid is not null or returjualid is not null
> and extract(year from tanggal)='2013')
>
> (there is additional or returjualid is not null,) the query needs
> 56 second to display the result.

Before worrying about the run time, I would worry about whether you
are getting the results you expect.  That will be interpreted as:

where jualid is not null
   or (returjualid is not null and extract(year from tanggal) = '2013')

... not:

where (jualid is not null or returjualid is not null)
  and extract(year from tanggal) = '2013'
AND has higher priority than OR; so if you want to limit by year
from tanggal even when jualid is not null, you must use
parentheses.

--
Kevin Grittner
EDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company

Re: Speed up the query

From
Hengky Lie
Date:
Dear Torsten and friends,

This is another good case to analyse why the query performance is not  the same :

There are 2 query :
(1)

with qry1 as (
select subkategori, kodebarang as produkid, namabarang, keluar, tbltransaksi.modal*keluar as ttlmodal,
    case
    when tbltransaksi.discount<=100 then
        keluar*(harga - (discount/100*harga))
        when tbltransaksi.discount>100
            then keluar*(harga-discount)
        end as jumlah
        from tblpenjualan
        join tbltransaksi on tblpenjualan.id=tbltransaksi.jualid
        join tblproduk on tbltransaksi.kodebarang=tblproduk.produkid
        join tblsubkategori on tblproduk.subkategoriid=tblsubkategori.tblsubkategoriid
        join tblkategori on tblkategori.kategoriid=tblsubkategori.kategoriid
        where tblpenjualan.tanggal between '01/01/13' and '31/10/13')


select subkategori,produkid, namabarang , sum(keluar) as ttlkeluar, sum(jumlah) as jumlah, sum(ttlmodal) as ttlmodal
from qry1
group by subkategori, produkid, namabarang

"QUERY PLAN"
"HashAggregate  (cost=99124.61..99780.94 rows=65633 width=334) (actual time=3422.786..3434.511 rows=24198 loops=1)"
"  Buffers: shared hit=14543"
"  CTE qry1"
"    ->  Hash Join  (cost=11676.07..76153.06 rows=656330 width=73) (actual time=181.683..2028.046 rows=657785 loops=1)"
"          Hash Cond: ((tbltransaksi.kodebarang)::text = (tblproduk.produkid)::text)"
"          Buffers: shared hit=14543"
"          ->  Hash Join  (cost=7247.75..44651.13 rows=656330 width=31) (actual time=84.885..787.029 rows=658438 loops=1)"
"                Hash Cond: (tbltransaksi.jualid = tblpenjualan.id)"
"                Buffers: shared hit=13204"
"                ->  Seq Scan on tbltransaksi  (cost=0.00..18730.83 rows=807283 width=35) (actual time=0.005..157.004 rows=807033 loops=1)"
"                      Buffers: shared hit=10658"
"                ->  Hash  (cost=5293.64..5293.64 rows=156329 width=4) (actual time=84.842..84.842 rows=154900 loops=1)"
"                      Buckets: 16384  Batches: 1  Memory Usage: 3631kB"
"                      Buffers: shared hit=2546"
"                      ->  Seq Scan on tblpenjualan  (cost=0.00..5293.64 rows=156329 width=4) (actual time=0.007..49.444 rows=154900 loops=1)"
"                            Filter: ((tanggal >= '2013-01-01'::date) AND (tanggal <= '2013-10-31'::date))"
"                            Rows Removed by Filter: 27928"
"                            Buffers: shared hit=2546"
"          ->  Hash  (cost=3364.19..3364.19 rows=85130 width=55) (actual time=96.736..96.736 rows=84701 loops=1)"
"                Buckets: 16384  Batches: 1  Memory Usage: 6323kB"
"                Buffers: shared hit=1339"
"                ->  Hash Join  (cost=5.35..3364.19 rows=85130 width=55) (actual time=0.241..62.038 rows=84701 loops=1)"
"                      Hash Cond: ((tblproduk.subkategoriid)::text = (tblsubkategori.tblsubkategoriid)::text)"
"                      Buffers: shared hit=1339"
"                      ->  Seq Scan on tblproduk  (cost=0.00..2188.30 rows=85130 width=45) (actual time=0.008..17.549 rows=85035 loops=1)"
"                            Buffers: shared hit=1337"
"                      ->  Hash  (cost=4.23..4.23 rows=90 width=17) (actual time=0.224..0.224 rows=90 loops=1)"
"                            Buckets: 1024  Batches: 1  Memory Usage: 4kB"
"                            Buffers: shared hit=2"
"                            ->  Hash Join  (cost=1.09..4.23 rows=90 width=17) (actual time=0.028..0.153 rows=90 loops=1)"
"                                  Hash Cond: ((tblsubkategori.kategoriid)::text = (tblkategori.kategoriid)::text)"
"                                  Buffers: shared hit=2"
"                                  ->  Seq Scan on tblsubkategori  (cost=0.00..1.90 rows=90 width=21) (actual time=0.005..0.029 rows=90 loops=1)"
"                                        Buffers: shared hit=1"
"                                  ->  Hash  (cost=1.04..1.04 rows=4 width=4) (actual time=0.011..0.011 rows=4 loops=1)"
"                                        Buckets: 1024  Batches: 1  Memory Usage: 1kB"
"                                        Buffers: shared hit=1"
"                                        ->  Seq Scan on tblkategori  (cost=0.00..1.04 rows=4 width=4) (actual time=0.002..0.004 rows=4 loops=1)"
"                                              Buffers: shared hit=1"
"  ->  CTE Scan on qry1  (cost=0.00..13126.60 rows=656330 width=334) (actual time=181.687..2556.526 rows=657785 loops=1)"
"        Buffers: shared hit=14543"
"Total runtime: 3454.442 ms"

(2)this is exactly the same query with no.1 except it uses subquery

select subkategori,produkid, namabarang , sum(keluar) as ttlkeluar, sum(jumlah) as jumlah, sum(ttlmodal) as ttlmodal from
( select subkategori, kodebarang as produkid, namabarang, keluar, tbltransaksi.modal*keluar as ttlmodal,
case
when tbltransaksi.discount<=100 then
keluar*(harga - (discount/100*harga))
when tbltransaksi.discount>100
then keluar*(harga-discount)
end as jumlah
from tblpenjualan
join tbltransaksi on tblpenjualan.id=tbltransaksi.jualid
join tblproduk on tbltransaksi.kodebarang=tblproduk.produkid
join tblsubkategori on tblproduk.subkategoriid=tblsubkategori.tblsubkategoriid
join tblkategori on tblkategori.kategoriid=tblsubkategori.kategoriid
where tblpenjualan.tanggal between '01/01/13' and '31/10/13')
as dt group by subkategori, produkid, namabarang
The analyse result :

"QUERY PLAN"
"GroupAggregate  (cost=124800.44..157616.94 rows=656330 width=73) (actual time=13895.782..15236.212 rows=24198 loops=1)"
"  Buffers: shared hit=14543"
"  ->  Sort  (cost=124800.44..126441.26 rows=656330 width=73) (actual time=13895.750..14024.911 rows=657785 loops=1)"
"        Sort Key: tblsubkategori.subkategori, tbltransaksi.kodebarang, tblproduk.namabarang"
"        Sort Method: quicksort  Memory: 103431kB"
"        Buffers: shared hit=14543"
"        ->  Hash Join  (cost=11676.07..61385.63 rows=656330 width=73) (actual time=177.521..1264.431 rows=657785 loops=1)"
"              Hash Cond: ((tbltransaksi.kodebarang)::text = (tblproduk.produkid)::text)"
"              Buffers: shared hit=14543"
"              ->  Hash Join  (cost=7247.75..44651.13 rows=656330 width=31) (actual time=84.473..739.064 rows=658438 loops=1)"
"                    Hash Cond: (tbltransaksi.jualid = tblpenjualan.id)"
"                    Buffers: shared hit=13204"
"                    ->  Seq Scan on tbltransaksi  (cost=0.00..18730.83 rows=807283 width=35) (actual time=0.005..146.601 rows=807033 loops=1)"
"                          Buffers: shared hit=10658"
"                    ->  Hash  (cost=5293.64..5293.64 rows=156329 width=4) (actual time=84.429..84.429 rows=154900 loops=1)"
"                          Buckets: 16384  Batches: 1  Memory Usage: 3631kB"
"                          Buffers: shared hit=2546"
"                          ->  Seq Scan on tblpenjualan  (cost=0.00..5293.64 rows=156329 width=4) (actual time=0.008..48.968 rows=154900 loops=1)"
"                                Filter: ((tanggal >= '2013-01-01'::date) AND (tanggal <= '2013-10-31'::date))"
"                                Rows Removed by Filter: 27928"
"                                Buffers: shared hit=2546"
"              ->  Hash  (cost=3364.19..3364.19 rows=85130 width=55) (actual time=92.998..92.998 rows=84701 loops=1)"
"                    Buckets: 16384  Batches: 1  Memory Usage: 6323kB"
"                    Buffers: shared hit=1339"
"                    ->  Hash Join  (cost=5.35..3364.19 rows=85130 width=55) (actual time=0.240..59.587 rows=84701 loops=1)"
"                          Hash Cond: ((tblproduk.subkategoriid)::text = (tblsubkategori.tblsubkategoriid)::text)"
"                          Buffers: shared hit=1339"
"                          ->  Seq Scan on tblproduk  (cost=0.00..2188.30 rows=85130 width=45) (actual time=0.008..16.942 rows=85035 loops=1)"
"                                Buffers: shared hit=1337"
"                          ->  Hash  (cost=4.23..4.23 rows=90 width=17) (actual time=0.221..0.221 rows=90 loops=1)"
"                                Buckets: 1024  Batches: 1  Memory Usage: 4kB"
"                                Buffers: shared hit=2"
"                                ->  Hash Join  (cost=1.09..4.23 rows=90 width=17) (actual time=0.028..0.142 rows=90 loops=1)"
"                                      Hash Cond: ((tblsubkategori.kategoriid)::text = (tblkategori.kategoriid)::text)"
"                                      Buffers: shared hit=2"
"                                      ->  Seq Scan on tblsubkategori  (cost=0.00..1.90 rows=90 width=21) (actual time=0.006..0.046 rows=90 loops=1)"
"                                            Buffers: shared hit=1"
"                                      ->  Hash  (cost=1.04..1.04 rows=4 width=4) (actual time=0.012..0.012 rows=4 loops=1)"
"                                            Buckets: 1024  Batches: 1  Memory Usage: 1kB"
"                                            Buffers: shared hit=1"
"                                            ->  Seq Scan on tblkategori  (cost=0.00..1.04 rows=4 width=4) (actual time=0.002..0.005 rows=4 loops=1)"
"                                                  Buffers: shared hit=1"
"Total runtime: 15244.038 ms"

This is my  Postgresqlconf :
max_connections=50
shared_buffers=1024MB
wall_buffers=16MB
max_prepared_transactions=0
work_mem=50MB
maintenance_work_mem=256MB

Thanks


On Sun, Dec 1, 2013 at 9:39 PM, Torsten Förtsch <torsten.foertsch@gmx.net> wrote:
On 01/12/13 13:40, Hengky Liwandouw wrote:
> Torsten, your 2nd option works now. I dont know maybe copy and paste error. I just want to report that your 2nd option with work_mem=100MB required the same amount of time (about 58 seconds), while my query required 4.9 seconds.
>
> What make this two query so different ?
>
Without the "explain (analyze,buffers) ..." it's hard to say. A CTE is
currently a way to trick the query planner because it's planned
separately. A subquery on the other hand is integrated in the outer
query and planned/optimized as one thing.

If your planner parameters are correctly set up, the subquery should
almost always outrun the CTE. Often, though, not much.

Now, you may ask why CTE then exist at all? There are things that cannot
be expressed without them, in particular WITH RECURSIVE.

The fact that it performs so badly as a subquery indicates that either
your table statistics are suboptimal or more probably the planner
parameters or work_mem.

Another point I have just noticed, how does it perform if you change

  and extract(... from tanggal)='2013'

to

  and '2013-01-01'::date <= tanggal
  and tanggal < '2013-01-01'::date + '1 year'::interval

Also, I think it would be possible to even get rid of the subquery. At
least you can get rid of the tanggal and jumlah output from the subquery.

select s.id, s.nama, t.kodebarang, p.namabarang,
       sum(case when extract(month from t.tanggal) = 1
                then t.keluar else 0 end) as jan,
       sum(case when extract(month from t.tanggal) = 2
                then t.keluar else 0 end) as feb,
       ...,
       sum(t.keluar) as total
  from tbltransaksi t
  join tblproduk p on t.kodebarang=p.produkid
  join tblsupplier s on p.supplierid=s.id
 where (t.jualid is not null or t.returjualid is not null)
   and '2013-01-01'::date <= t.tanggal
   and t.tanggal < '2013-01-01'::date + '1 year'::interval
 group by s.id, s.nama, t.kodebarang, p.namabarang
 order by total desc
 limit 1000

would be interesting to see the "explain (analyze,buffers)" output for
the query above.

Please double-check the query. I think it should do exactly the same as
your query. But you know, shit happens.

BTW, am I right in assuming that you are from Malaysia or Indonesia? I
am trying to learn a bit of Malay. I am a complete beginner, though.

Selamat berjaya      (is that possible to wish you success?)
Torsten

Re: Speed up the query

From
Hengky Lie
Date:
sorry, for now, work_mem=100MB


On Mon, Dec 2, 2013 at 12:33 AM, Hengky Lie <hengkyliwandouw@gmail.com> wrote:
Dear Torsten and friends,

This is another good case to analyse why the query performance is not  the same :

There are 2 query :
(1)

with qry1 as (
select subkategori, kodebarang as produkid, namabarang, keluar, tbltransaksi.modal*keluar as ttlmodal,
    case
    when tbltransaksi.discount<=100 then
        keluar*(harga - (discount/100*harga))

        when tbltransaksi.discount>100
            then keluar*(harga-discount)
        end as jumlah
        from tblpenjualan
        join tbltransaksi on tblpenjualan.id=tbltransaksi.jualid
        join tblproduk on tbltransaksi.kodebarang=tblproduk.produkid
        join tblsubkategori on tblproduk.subkategoriid=tblsubkategori.tblsubkategoriid
        join tblkategori on tblkategori.kategoriid=tblsubkategori.kategoriid
        where tblpenjualan.tanggal between '01/01/13' and '31/10/13')


select subkategori,produkid, namabarang , sum(keluar) as ttlkeluar, sum(jumlah) as jumlah, sum(ttlmodal) as ttlmodal
from qry1
group by subkategori, produkid, namabarang

"QUERY PLAN"
"HashAggregate  (cost=99124.61..99780.94 rows=65633 width=334) (actual time=3422.786..3434.511 rows=24198 loops=1)"
"  Buffers: shared hit=14543"
"  CTE qry1"
"    ->  Hash Join  (cost=11676.07..76153.06 rows=656330 width=73) (actual time=181.683..2028.046 rows=657785 loops=1)"
"          Hash Cond: ((tbltransaksi.kodebarang)::text = (tblproduk.produkid)::text)"
"          Buffers: shared hit=14543"
"          ->  Hash Join  (cost=7247.75..44651.13 rows=656330 width=31) (actual time=84.885..787.029 rows=658438 loops=1)"
"                Hash Cond: (tbltransaksi.jualid = tblpenjualan.id)"
"                Buffers: shared hit=13204"
"                ->  Seq Scan on tbltransaksi  (cost=0.00..18730.83 rows=807283 width=35) (actual time=0.005..157.004 rows=807033 loops=1)"
"                      Buffers: shared hit=10658"
"                ->  Hash  (cost=5293.64..5293.64 rows=156329 width=4) (actual time=84.842..84.842 rows=154900 loops=1)"
"                      Buckets: 16384  Batches: 1  Memory Usage: 3631kB"
"                      Buffers: shared hit=2546"
"                      ->  Seq Scan on tblpenjualan  (cost=0.00..5293.64 rows=156329 width=4) (actual time=0.007..49.444 rows=154900 loops=1)"
"                            Filter: ((tanggal >= '2013-01-01'::date) AND (tanggal <= '2013-10-31'::date))"
"                            Rows Removed by Filter: 27928"
"                            Buffers: shared hit=2546"
"          ->  Hash  (cost=3364.19..3364.19 rows=85130 width=55) (actual time=96.736..96.736 rows=84701 loops=1)"
"                Buckets: 16384  Batches: 1  Memory Usage: 6323kB"
"                Buffers: shared hit=1339"
"                ->  Hash Join  (cost=5.35..3364.19 rows=85130 width=55) (actual time=0.241..62.038 rows=84701 loops=1)"
"                      Hash Cond: ((tblproduk.subkategoriid)::text = (tblsubkategori.tblsubkategoriid)::text)"
"                      Buffers: shared hit=1339"
"                      ->  Seq Scan on tblproduk  (cost=0.00..2188.30 rows=85130 width=45) (actual time=0.008..17.549 rows=85035 loops=1)"
"                            Buffers: shared hit=1337"
"                      ->  Hash  (cost=4.23..4.23 rows=90 width=17) (actual time=0.224..0.224 rows=90 loops=1)"
"                            Buckets: 1024  Batches: 1  Memory Usage: 4kB"
"                            Buffers: shared hit=2"
"                            ->  Hash Join  (cost=1.09..4.23 rows=90 width=17) (actual time=0.028..0.153 rows=90 loops=1)"
"                                  Hash Cond: ((tblsubkategori.kategoriid)::text = (tblkategori.kategoriid)::text)"
"                                  Buffers: shared hit=2"
"                                  ->  Seq Scan on tblsubkategori  (cost=0.00..1.90 rows=90 width=21) (actual time=0.005..0.029 rows=90 loops=1)"
"                                        Buffers: shared hit=1"
"                                  ->  Hash  (cost=1.04..1.04 rows=4 width=4) (actual time=0.011..0.011 rows=4 loops=1)"
"                                        Buckets: 1024  Batches: 1  Memory Usage: 1kB"
"                                        Buffers: shared hit=1"
"                                        ->  Seq Scan on tblkategori  (cost=0.00..1.04 rows=4 width=4) (actual time=0.002..0.004 rows=4 loops=1)"
"                                              Buffers: shared hit=1"
"  ->  CTE Scan on qry1  (cost=0.00..13126.60 rows=656330 width=334) (actual time=181.687..2556.526 rows=657785 loops=1)"
"        Buffers: shared hit=14543"
"Total runtime: 3454.442 ms"

(2)this is exactly the same query with no.1 except it uses subquery

select subkategori,produkid, namabarang , sum(keluar) as ttlkeluar, sum(jumlah) as jumlah, sum(ttlmodal) as ttlmodal from
( select subkategori, kodebarang as produkid, namabarang, keluar, tbltransaksi.modal*keluar as ttlmodal,
case
when tbltransaksi.discount<=100 then
keluar*(harga - (discount/100*harga))

when tbltransaksi.discount>100
then keluar*(harga-discount)
end as jumlah
from tblpenjualan
join tbltransaksi on tblpenjualan.id=tbltransaksi.jualid
join tblproduk on tbltransaksi.kodebarang=tblproduk.produkid
join tblsubkategori on tblproduk.subkategoriid=tblsubkategori.tblsubkategoriid
join tblkategori on tblkategori.kategoriid=tblsubkategori.kategoriid
where tblpenjualan.tanggal between '01/01/13' and '31/10/13')
as dt group by subkategori, produkid, namabarang
The analyse result :

"QUERY PLAN"
"GroupAggregate  (cost=124800.44..157616.94 rows=656330 width=73) (actual time=13895.782..15236.212 rows=24198 loops=1)"
"  Buffers: shared hit=14543"
"  ->  Sort  (cost=124800.44..126441.26 rows=656330 width=73) (actual time=13895.750..14024.911 rows=657785 loops=1)"
"        Sort Key: tblsubkategori.subkategori, tbltransaksi.kodebarang, tblproduk.namabarang"
"        Sort Method: quicksort  Memory: 103431kB"
"        Buffers: shared hit=14543"
"        ->  Hash Join  (cost=11676.07..61385.63 rows=656330 width=73) (actual time=177.521..1264.431 rows=657785 loops=1)"
"              Hash Cond: ((tbltransaksi.kodebarang)::text = (tblproduk.produkid)::text)"
"              Buffers: shared hit=14543"
"              ->  Hash Join  (cost=7247.75..44651.13 rows=656330 width=31) (actual time=84.473..739.064 rows=658438 loops=1)"
"                    Hash Cond: (tbltransaksi.jualid = tblpenjualan.id)"
"                    Buffers: shared hit=13204"
"                    ->  Seq Scan on tbltransaksi  (cost=0.00..18730.83 rows=807283 width=35) (actual time=0.005..146.601 rows=807033 loops=1)"
"                          Buffers: shared hit=10658"
"                    ->  Hash  (cost=5293.64..5293.64 rows=156329 width=4) (actual time=84.429..84.429 rows=154900 loops=1)"
"                          Buckets: 16384  Batches: 1  Memory Usage: 3631kB"
"                          Buffers: shared hit=2546"
"                          ->  Seq Scan on tblpenjualan  (cost=0.00..5293.64 rows=156329 width=4) (actual time=0.008..48.968 rows=154900 loops=1)"
"                                Filter: ((tanggal >= '2013-01-01'::date) AND (tanggal <= '2013-10-31'::date))"
"                                Rows Removed by Filter: 27928"
"                                Buffers: shared hit=2546"
"              ->  Hash  (cost=3364.19..3364.19 rows=85130 width=55) (actual time=92.998..92.998 rows=84701 loops=1)"
"                    Buckets: 16384  Batches: 1  Memory Usage: 6323kB"
"                    Buffers: shared hit=1339"
"                    ->  Hash Join  (cost=5.35..3364.19 rows=85130 width=55) (actual time=0.240..59.587 rows=84701 loops=1)"
"                          Hash Cond: ((tblproduk.subkategoriid)::text = (tblsubkategori.tblsubkategoriid)::text)"
"                          Buffers: shared hit=1339"
"                          ->  Seq Scan on tblproduk  (cost=0.00..2188.30 rows=85130 width=45) (actual time=0.008..16.942 rows=85035 loops=1)"
"                                Buffers: shared hit=1337"
"                          ->  Hash  (cost=4.23..4.23 rows=90 width=17) (actual time=0.221..0.221 rows=90 loops=1)"
"                                Buckets: 1024  Batches: 1  Memory Usage: 4kB"
"                                Buffers: shared hit=2"
"                                ->  Hash Join  (cost=1.09..4.23 rows=90 width=17) (actual time=0.028..0.142 rows=90 loops=1)"
"                                      Hash Cond: ((tblsubkategori.kategoriid)::text = (tblkategori.kategoriid)::text)"
"                                      Buffers: shared hit=2"
"                                      ->  Seq Scan on tblsubkategori  (cost=0.00..1.90 rows=90 width=21) (actual time=0.006..0.046 rows=90 loops=1)"
"                                            Buffers: shared hit=1"
"                                      ->  Hash  (cost=1.04..1.04 rows=4 width=4) (actual time=0.012..0.012 rows=4 loops=1)"
"                                            Buckets: 1024  Batches: 1  Memory Usage: 1kB"
"                                            Buffers: shared hit=1"
"                                            ->  Seq Scan on tblkategori  (cost=0.00..1.04 rows=4 width=4) (actual time=0.002..0.005 rows=4 loops=1)"
"                                                  Buffers: shared hit=1"
"Total runtime: 15244.038 ms"

This is my  Postgresqlconf :
max_connections=50
shared_buffers=1024MB
wall_buffers=16MB
max_prepared_transactions=0
work_mem=50MB
maintenance_work_mem=256MB

Thanks


On Sun, Dec 1, 2013 at 9:39 PM, Torsten Förtsch <torsten.foertsch@gmx.net> wrote:
On 01/12/13 13:40, Hengky Liwandouw wrote:
> Torsten, your 2nd option works now. I dont know maybe copy and paste error. I just want to report that your 2nd option with work_mem=100MB required the same amount of time (about 58 seconds), while my query required 4.9 seconds.
>
> What make this two query so different ?
>
Without the "explain (analyze,buffers) ..." it's hard to say. A CTE is
currently a way to trick the query planner because it's planned
separately. A subquery on the other hand is integrated in the outer
query and planned/optimized as one thing.

If your planner parameters are correctly set up, the subquery should
almost always outrun the CTE. Often, though, not much.

Now, you may ask why CTE then exist at all? There are things that cannot
be expressed without them, in particular WITH RECURSIVE.

The fact that it performs so badly as a subquery indicates that either
your table statistics are suboptimal or more probably the planner
parameters or work_mem.

Another point I have just noticed, how does it perform if you change

  and extract(... from tanggal)='2013'

to

  and '2013-01-01'::date <= tanggal
  and tanggal < '2013-01-01'::date + '1 year'::interval

Also, I think it would be possible to even get rid of the subquery. At
least you can get rid of the tanggal and jumlah output from the subquery.

select s.id, s.nama, t.kodebarang, p.namabarang,
       sum(case when extract(month from t.tanggal) = 1
                then t.keluar else 0 end) as jan,
       sum(case when extract(month from t.tanggal) = 2
                then t.keluar else 0 end) as feb,
       ...,
       sum(t.keluar) as total
  from tbltransaksi t
  join tblproduk p on t.kodebarang=p.produkid
  join tblsupplier s on p.supplierid=s.id
 where (t.jualid is not null or t.returjualid is not null)
   and '2013-01-01'::date <= t.tanggal
   and t.tanggal < '2013-01-01'::date + '1 year'::interval
 group by s.id, s.nama, t.kodebarang, p.namabarang
 order by total desc
 limit 1000

would be interesting to see the "explain (analyze,buffers)" output for
the query above.

Please double-check the query. I think it should do exactly the same as
your query. But you know, shit happens.

BTW, am I right in assuming that you are from Malaysia or Indonesia? I
am trying to learn a bit of Malay. I am a complete beginner, though.

Selamat berjaya      (is that possible to wish you success?)
Torsten