Re: [GENERAL] Why does this SQL work?

2015-05-12 Thread hubert depesz lubaczewski
On Tue, May 12, 2015 at 04:07:52PM +0800, Anil Menon wrote:
 Thank you very much - looks like I will have to prefix all cols.

You should anyway.
Queries with unaliased columns make it impossible to analyze without
in-depth knowledge of the database.

Consider:

select c1, c2, c3, c4, c5
from t1 join t2 using (c6)
where c7 = 'a' and c8  now() and c9;

which fields belong to which tables? what indexes make sense? it's
impossible to tell. if the column references were prefixed with table
name/alias - it would become possible, and easy, even, to figure out
what's going on.

depesz


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


Re: [GENERAL] Why does this SQL work?

2015-05-12 Thread Anil Menon
Thank you very much - looks like I will have to prefix all cols.

Regards
AK

On Tue, May 12, 2015 at 3:05 AM, Victor Yegorov vyego...@gmail.com wrote:

 2015-05-11 19:26 GMT+03:00 Anil Menon gakme...@gmail.com:

 manualscan= select count(*) From public.msgtxt where msgid in (select
 msgid From ver736.courier where org_id=3);
  count
 ---
  10225
 (1 row)

 Please note, there is no msgid col in courier table. Which brings the
 question why does this SQL work? An select msgid From courier where
 org_id=3 by itself gives error column msgid does not exist.


 Because you can reference both, inner and outer columns from the inner
 query.
 Here you're most likely referring to the outer `msgid` in the subquery.

 That's why it is always a good idea to prefix all your columns with tables
 aliases.


 --
 Victor Y. Yegorov



Re: [GENERAL] Why does this SQL work?

2015-05-11 Thread Victor Yegorov
2015-05-11 19:26 GMT+03:00 Anil Menon gakme...@gmail.com:

 manualscan= select count(*) From public.msgtxt where msgid in (select
 msgid From ver736.courier where org_id=3);
  count
 ---
  10225
 (1 row)

 Please note, there is no msgid col in courier table. Which brings the
 question why does this SQL work? An select msgid From courier where
 org_id=3 by itself gives error column msgid does not exist.


Because you can reference both, inner and outer columns from the inner
query.
Here you're most likely referring to the outer `msgid` in the subquery.

That's why it is always a good idea to prefix all your columns with tables
aliases.


-- 
Victor Y. Yegorov


Re: [GENERAL] Why does this SQL work?

2015-05-11 Thread hubert depesz lubaczewski
On Tue, May 12, 2015 at 12:26:15AM +0800, Anil Menon wrote:
 manualscan= select count(*) From msgtxt where msgid in (
 manualscan( select msgid From courier where org_id=3
 manualscan( )
 manualscan-  ;
  count
 ---
  10225
 (1 row)
 manualscan= select count(*) From public.msgtxt where msgid in (select
 msgid From ver736.courier where org_id=3);
  count
 ---
  10225
 (1 row)
 Please note, there is no msgid col in courier table. Which brings the
 question why does this SQL work? An select msgid From courier where
 org_id=3 by itself gives error column msgid does not exist.

This works because this is correlated subquery.

You should have always use aliases to avoid such errors. Like here:
select count(*) From msgtxt as m where m.msgid in (
select c.msgid from courier c where c.org_id = 3
);

Your query is equivalent to:
select count(*) From msgtxt as m where m.msgid in (
select m.msgid from courier c where c.org_id = 3
);
which returns all rows from msgtxt if there is at least one row in
courier with org_id = 3.

depesz

-- 
The best thing about modern society is how easy it is to avoid contact with it.
 http://depesz.com/


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


[GENERAL] Why does this SQL work?

2015-05-11 Thread Anil Menon
Hi,
I have the following setup :

manualscan= set search_path=ver736,public;
SET
manualscan= \d courier;
  Table ver736.courier
Column |  Type  |Modifiers
---++--
 org_id| smallint   | not null default
nextval('courier_org_id_seq'::regclass)
 courier_name  | character varying(500) | not null
 courier_code  | character varying(50)  |
 is_valid  | boolean|
 universe_id   | character varying(50)  |
 courier_image | bytea  |
Indexes:
courier_pk PRIMARY KEY, btree (org_id)
courier_code_un UNIQUE CONSTRAINT, btree (courier_code)
courier_name_un UNIQUE CONSTRAINT, btree (courier_name)
courier_code_idx btree (courier_code)
Referenced by:
xxx...xxx...(a few tables)


manualscan= \d msgtxt;
 Table public.msgtxt
  Column   |   Type   |
Modifiers
---+--+
 msgid | integer  | not null default
nextval('msgtxt_msgid_seq'::regclass)
 msgval| text |
 transaction_stamp | timestamp with time zone | default now()
 corelationid  | text |
 deviverymode  | integer  |
 destination   | text |
 expiration| integer  |
 messageid | text |
 priority  | integer  |
 redelivered   | boolean  |
 replyto   | text |
 timestamp | bigint   |
 msgtype   | text |
 senderid  | text |
Indexes:
msgtxt_pkey PRIMARY KEY, btree (msgid)
Triggers:
manual_scan_tx_tr AFTER INSERT ON msgtxt FOR EACH ROW EXECUTE PROCEDURE
process_manual_scan_tx()

manualscan= select count(*) From msgtxt where msgid in (
manualscan( select msgid From courier where org_id=3
manualscan( )
manualscan-  ;
 count
---
 10225
(1 row)
manualscan= select count(*) From public.msgtxt where msgid in (select
msgid From ver736.courier where org_id=3);
 count
---
 10225
(1 row)

Please note, there is no msgid col in courier table. Which brings the
question why does this SQL work? An select msgid From courier where
org_id=3 by itself gives error column msgid does not exist.

OS Version : Centos 7
PG Version : PostgreSQL 9.4.1 on x86_64-unknown-linux-gnu, compiled by gcc
(GCC) 4.8.2 20140120 (Red Hat 4.8.2-16), 64-bit

Regards
AK