pdbench/census/Queries/q5.sql

128 lines
2.8 KiB
SQL

-- Query 5: join of r2(tid,powstate1,citizen,immigr) and r3(tid,powstate2,marital,fertil) on powstate1 <> powstate2
-- the following two should be done outside
update f2
SET Col='POWSTATE1' WHERE Col='POWSTATE';
update f3
SET Col='POWSTATE2' WHERE Col='POWSTATE';
-- clean r2 and r3 with the selection condition
DELETE FROM r2
WHERE not(powstate1 > 50 or powstate1 = -1);
DELETE FROM r3
WHERE not(powstate2 > 50 or powstate2 = -1);
-- create r5 as r2 x r3
CREATE TABLE r5 WITHOUT OIDS AS
SELECT r2.TID || 'x' || r3.TID as TID, r2.tid as tid1, r3.tid as tid2, r2.POWSTATE1, r2.CITIZEN, r2.IMMIGR, r3.POWSTATE2, r3.MARITAL,r3.FERTIL
FROM r2, r3
WHERE
r2.POWSTATE1 = r3.POWSTATE2 OR r2.POWSTATE1 = -1 OR r3.POWSTATE2 = -1;
DELETE FROM f2
WHERE tid not in (select tid1 from r5);
DELETE FROM f3
WHERE tid not in (select tid2 from r5);
DELETE FROM c2
WHERE
hid not in (
select hid from f2
where (case when f2.col in ('POWSTATE1','POWSTATE2')
then c2.value > 50
else true end)
);
DELETE FROM c3
WHERE
hid not in (
select hid from f3
where (case when f3.col in ('POWSTATE1','POWSTATE2')
then c3.value > 50
else true end)
);
-- ALTER TABLE r5 DROP tid1;
-- ALTER TABLE r5 DROP tid2;
-- create new holes: f5 = f2 x r3 union all f3 x r2
CREATE TABLE f5 WITHOUT OIDS AS
SELECT 'r5' as relation, f2.tid || 'x' || r3.tid as tid, f2.col, f2.cid, '1.' || f2.hid || 'x' || r3.tid as hid
FROM f2,r3
union all
SELECT 'r5' as relation, f3.tid || 'x' || r2.tid as tid, f3.col, f3.cid, '2.' || f3.hid || 'x' || r2.tid as hid
FROM f3,r2;
--create unique index f5hididx on f5(hid);
CREATE TABLE consts5 WITHOUT OIDS AS
SELECT HID, POWSTATE1, POWSTATE2
FROM r5, f5
WHERE r5.TID = f5.TID AND
(POWSTATE1 = -1 AND POWSTATE2 <> -1 OR POWSTATE1 <> -1 AND POWSTATE2 = -1) AND
(CASE WHEN POWSTATE1 = -1 THEN f5.COL = 'POWSTATE1' ELSE f5.COL = 'POWSTATE2' END);
create unique index consts5idx on consts5(hid);
SET ENABLE_SEQSCAN=OFF;
-- create the new component relation
create table c5 without oids as
SELECT c2.cid, '1.' || c2.hid || 'x' || r3.tid as hid, c2.wid, c2.value
FROM c2,r3
union all
SELECT c3.cid, '2.' || c3.hid || 'x' || r2.tid as hid, c3.wid, c3.value
FROM c3,r2;
delete from c5 where
hid in
(select hid from consts5
where consts5.POWSTATE2 <> c5.VALUE and consts5.POWSTATE1 <> c5.VALUE);
SET ENABLE_SEQSCAN=ON;
DELETE FROM f5
WHERE HID NOT IN (SELECT HID FROM c5);
-------------------------------------
-- apply now the join condition POWSTATE1 = POWSTATE2 on the relation c5
SELECT 1 from filter5();
-------------------------------------
CREATE TABLE DEL5 WITHOUT OIDS AS
SELECT f5.TID FROM f5 left join c5 on (f5.hid = c5.hid)
WHERE c5.hid is null;
DELETE FROM r5
WHERE TID IN (SELECT TID FROM DEL5);
DELETE FROM f5
WHERE TID IN (SELECT TID FROM DEL5);
DELETE FROM c5
WHERE HID NOT IN (SELECT HID FROM f5);