Thread: making queries more effecient
Hi. I have this query that I have been trying to reduce to a single statement, but haven't figured out how. Am I missing something? CREATE TEMP TABLE temp20561149207391 AS SELECT DISTINCT ON ("VisitorID") "VisitorID","Type" FROM "ProgramEvent" WHERE "ProgramID" = 10 ORDER BY "VisitorID","Created" DESC;INSERT INTO "VisitorPointer839" ("VisitorID") SELECT temp20561149207391."VisitorID" FROM temp20561149207391 WHERE temp20561149207391."Type" = 0 Thanks
This should be all you need. insert into VisitorPointer839 ("VisitorID") select VisitorID from ProgramEvent Where ProgramID = 10 and Type = 0 group by VisitorID You dont need order by because its not important the order it goes in the database, just the order that it comes out. I have found that group by works faster than distinct in some cases. You may have to test it for your senario. Thanks Chad ----- Original Message ----- From: "Peter T. Brown" <peter@memeticsystems.com> To: <pgsql-sql@postgresql.org> Sent: Friday, November 01, 2002 3:24 PM Subject: [SQL] making queries more effecient > Hi. I have this query that I have been trying to reduce to a single > statement, but haven't figured out how. Am I missing something? > > CREATE TEMP TABLE temp20561149207391 AS SELECT DISTINCT ON ("VisitorID") > "VisitorID","Type" FROM "ProgramEvent" WHERE "ProgramID" = 10 ORDER BY > "VisitorID","Created" DESC;INSERT INTO "VisitorPointer839" ("VisitorID") > SELECT temp20561149207391."VisitorID" FROM temp20561149207391 WHERE > temp20561149207391."Type" = 0 > > > Thanks > > > ---------------------------(end of broadcast)--------------------------- > TIP 3: if posting/reading through Usenet, please send an appropriate > subscribe-nomail command to majordomo@postgresql.org so that your > message can get through to the mailing list cleanly >
Peter, For the rest of our sakes, in the future, please format your SQL before posting it to request help. > CREATE TEMP TABLE temp20561149207391 AS SELECT DISTINCT ON ("VisitorID") > "VisitorID","Type" FROM "ProgramEvent" WHERE "ProgramID" = 10 ORDER BY > "VisitorID","Created" DESC;INSERT INTO "VisitorPointer839" ("VisitorID") > SELECT temp20561149207391."VisitorID" FROM temp20561149207391 WHERE > temp20561149207391."Type" = 0 Can be re-written as: INSERT INTO "VisitorPointer839" ("VisitorID") SELECT "VisitorID" FROM (SELECT DISTINCT ON ("VisitorID") "VisitorID","Type" FROM "ProgramEvent" WHERE "ProgramID" = 10 ORDERBY "VisitorID","Created" DESC ) v_first WHERE v_first."Type" = 0; Please also keep in mind that the SELECT DISTINCT ON syntax is a PostgreSQL-specific extension and is not portable. -- -Josh BerkusAglio Database SolutionsSan Francisco
Chad, > Im not sure I can get my head around the difference between doing your > subselect.... > > INSERT INTO "VisitorPointer839" ("VisitorID") > SELECT "VisitorID" FROM ( > SELECT DISTINCT ON ("VisitorID") "VisitorID","Type" > FROM "ProgramEvent" WHERE "ProgramID" = 10 > ORDER BY "VisitorID","Created" DESC ) v_first > WHERE v_first."Type" = 0; This gives him a list of all Visitor IDs where the most recent instance of that VisitorID is of Type = 0; It's the equivalent of, in SQL-92: INSERT INTO "VisitorPointer839" ("VisitorID") SELECT "VisitorID" FROM "ProgramEvent" pe1 WHERE EXISTS( SELECT "VisitorID", MAX("Created") FROM "ProgramEvent" pe2 WHERE "ProgramID" = 10 GROUP BY "VisitorID" HAVING pe2."VisitorID" = pe1."VisitorID"AND MAX(pe2."Created") = pe1."Created") v_firstAND "Type" = 0; ... which is what I would use, as I dislike database-specific extensions of ANSI SQL. > And Just writing it out straight. > > insert into VisitorPointer839 ("VisitorID") > select VisitorID > from ProgramEvent > Where ProgramID = 10 > and Type = 0 > group by VisitorID This just gives him a list of all VisitorIDs with a Type = 0, most recent or not. > Thanks > Chad "I wanna be Josh when i grow up" Thompson <grin> Thanks. But heck, I'm only 32! I'm not grown up yet! -- -Josh BerkusAglio Database SolutionsSan Francisco