The following bug has been logged on the website: Bug reference: 7604 Logged by: Bill MacArthur Email address: webmas...@dhs-club.com PostgreSQL version: 9.2.1 Operating system: CentOS 5.8 Description:
vip_declines_mailers_base is a VIEW that itself uses another VIEW alongside several other joined tables. nop_seed is a 1 column table that contains 1 date as a reference. members_cancel_pending is a VIEW. CREATE OR REPLACE VIEW vip_decline_mailers_base AS SELECT m.id, m.alias, m.firstname, m.lastname, m.emailaddress, CASE WHEN s.void = false THEN s.end_date ELSE (s.end_date - '1 mon'::interval)::date END AS paid_thru, mop.payment_method, m.mail_option_lvl, now()::date AS "current_date" FROM nop_seed, subscriptions s JOIN mop ON mop.id = s.member_id JOIN members_cancel_pending m ON m.id = s.member_id AND m.membertype::text = 'v'::text JOIN subscription_types st ON s.subscription_type = st.subscription_type WHERE (s.end_date < nop_seed.paid_thru OR s.void = true) AND st.sub_class::text = 'VM'::text; Then executing a query against vip_declines_mailers_base with no constraining arguments, the complete result set counts as this: network=# select count(*) from vip_decline_mailers_base; count ------- 358 vip_declines_mailers_base is another VIEW that merely adds some criteria to limit the result set of the 'base' VIEW. In versions 9.0 and back it did just that. After upgrading to 9.2, the criteria actually expand the result set. CREATE OR REPLACE VIEW vip_mailer_unpaid_current AS SELECT vip_decline_mailers_base.id, vip_decline_mailers_base.alias, vip_decline_mailers_base.firstname, vip_decline_mailers_base.lastname, vip_decline_mailers_base.emailaddress, vip_decline_mailers_base.paid_thru, vip_decline_mailers_base.payment_method, vip_decline_mailers_base.mail_option_lvl, vip_decline_mailers_base."current_date", current_month_text(now()) AS current_month_text FROM vip_decline_mailers_base WHERE vip_decline_mailers_base.mail_option_lvl > 0 AND vip_decline_mailers_base.paid_thru >= first_of_another_month((now()::date - '1 mon'::interval)::date) AND vip_decline_mailers_base.paid_thru <= (first_of_month() - 1); network=# select count(*) from vip_mailer_unpaid_current; count ------- 391 How can this be? What's worse, is that adding the criteria somehow mangles the inner workings of the 'base' VIEW and causes it to return results where the membertype does not even match the join criteria which should be 'v' only. I could create a self contained test case, but the number of tables and scrubbing the data could be tedious. Perhaps there is enough here to help pinpoint a trouble spot. I should restate, also, that these VIEWS have been working fine with 9.0 and earlier versions. FWIW, here are the EXPLAINs on the two queries. network=# explain select count(*) from vip_decline_mailers_base; QUERY PLAN ---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- -------------------------------- Aggregate (cost=82439.33..82439.34 rows=1 width=0) -> Hash Right Join (cost=78647.01..82439.21 rows=47 width=0) Hash Cond: (c.id = m.id) Filter: ((CASE WHEN (c.id IS NULL) THEN m.membertype WHEN ((c.status = 'tr'::text) OR (c.status = 'p'::text) OR (c.status = 'cd'::text) OR (c.status = 'sp'::text) OR (c.status = 'sa'::text)) THEN m.membertype ELSE 'c'::character varying END)::text = 'v'::text) -> Seq Scan on cancellations c (cost=0.00..3325.35 rows=119735 width=6) -> Hash (cost=78529.91..78529.91 rows=9368 width=6) -> Hash Join (cost=6128.57..78529.91 rows=9368 width=6) Hash Cond: (m.id = mop.id) -> Seq Scan on members m (cost=0.00..66417.39 rows=1570739 width=6) -> Hash (cost=6011.47..6011.47 rows=9368 width=8) -> Hash Join (cost=3129.39..6011.47 rows=9368 width=8) Hash Cond: (mop.id = s.member_id) -> Seq Scan on mop (cost=0.00..2158.67 rows=71967 width=4) -> Hash (cost=3012.28..3012.28 rows=9369 width=4) -> Nested Loop (cost=2.67..3012.28 rows=9369 width=4) Join Filter: ((s.end_date < nop_seed.paid_thru) OR s.void) -> Seq Scan on nop_seed (cost=0.00..1.01 rows=1 width=4) -> Hash Join (cost=2.67..2723.56 rows=23017 width=9) Hash Cond: (s.subscription_type = st.subscription_type) -> Seq Scan on subscriptions s (cost=0.00..2188.61 rows=80561 width=11) -> Hash (cost=2.52..2.52 rows=12 width=2) -> Seq Scan on subscription_types st (cost=0.00..2.52 rows=12 width=2) Filter: ((sub_class)::text = 'VM'::text) (23 rows) network=# explain select count(*) from vip_mailer_unpaid_current; QUERY PLAN ---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- ---------------------------------------------------------------------------------------------------------- Aggregate (cost=25954.57..25954.58 rows=1 width=0) -> Nested Loop (cost=0.00..25954.57 rows=1 width=0) -> Nested Loop Left Join (cost=0.00..25948.57 rows=1 width=8) -> Nested Loop (cost=0.00..25741.69 rows=34 width=10) -> Nested Loop (cost=0.00..25186.62 rows=47 width=4) Join Filter: (s.subscription_type = st.subscription_type) -> Nested Loop (cost=0.00..25154.54 rows=164 width=6) Join Filter: ((s.end_date < nop_seed.paid_thru) OR s.void) -> Seq Scan on nop_seed (cost=0.00..1.01 rows=1 width=4) -> Seq Scan on subscriptions s (cost=0.00..25148.50 rows=403 width=11) Filter: ((CASE WHEN (NOT void) THEN end_date ELSE ((end_date - '1 mon'::interval))::date END <= ((date_trunc('month'::text, now()))::date - 1)) AND (CASE WHEN (NOT void) THEN end_date ELSE ((end_date - '1 mon'::interval))::date END >= first_of_another_month((((now())::date - '1 mon'::interval))::date))) -> Materialize (cost=0.00..2.58 rows=12 width=2) -> Seq Scan on subscription_types st (cost=0.00..2.52 rows=12 width=2) Filter: ((sub_class)::text = 'VM'::text) -> Index Scan using members_pkey on members m (cost=0.00..11.80 rows=1 width=6) Index Cond: (id = s.member_id) Filter: (mail_option_lvl > 0) -> Index Scan using cancellations_id_key on cancellations c (cost=0.00..6.07 rows=1 width=6) Index Cond: (id = m.id) Filter: ((CASE WHEN (id IS NULL) THEN m.membertype WHEN ((status = 'tr'::text) OR (status = 'p'::text) OR (status = 'cd'::text) OR (status = 'sp'::text) OR (status = 'sa'::text)) THEN m.membertype ELSE 'c'::character varying END)::text = 'v'::text) -> Index Only Scan using mop_pkey on mop (cost=0.00..5.99 rows=1 width=4) Index Cond: (id = m.id) (22 rows) -- Sent via pgsql-bugs mailing list (pgsql-bugs@postgresql.org) To make changes to your subscription: http://www.postgresql.org/mailpref/pgsql-bugs