Re: DELETE FROM t WHERE EXISTS
От | Dan Langille |
---|---|
Тема | Re: DELETE FROM t WHERE EXISTS |
Дата | |
Msg-id | 20030228165800.R29368@xeon.unixathome.org обсуждение исходный текст |
Ответ на | Re: DELETE FROM t WHERE EXISTS (Stephan Szabo <sszabo@megazone23.bigpanda.com>) |
Список | pgsql-sql |
On Fri, 28 Feb 2003, Stephan Szabo wrote: > > On Fri, 28 Feb 2003, Dan Langille wrote: > > > Hi folks, > > > > I wanted to delete "old" rows from a table. These are the rows I > > want to keep: > > > > SELECT * > > FROM clp > > ORDER BY commit_date > > LIMIT 100 > > > > So I tried this: > > > > DELETE FROM clp > > WHERE NOT EXISTS ( > > SELECT * > > FROM clp > > ORDER BY commit_date > > LIMIT 100); > > > > Uhh uhh, nothing deleted. I don't understand why. > > As long as the inner select returns at least 1 result NOT EXISTS is > going to return false (you haven't correlated the two queries at all). > > > OK, I can do this instead: > > > > DELETE from clp > > where commit_log_id NOT in ( > > SELECT commit_log_id > > FROM clp > > ORDER BY commit_date > > LIMIT 100); > > > > Can you think of a better way? > > Possibly something like: > DELETE FROM clp > WHERE NOT EXISTS ( > select * from (select * from clp order by commit_date limit 100) tmp > where tmp.commit_log_id = clp.commit_log_id > ); > > But I haven't tried it for stupid errors, and am not sure that it'd end up > being any better than NOT IN anyway. Thank you. Here's that plan: Seq Scan on clp (cost=0.00..544.87 rows=50 width=6) (actual time=93.71..763.85 rows=400 loops=1) Filter: (NOT (subplan)) SubPlan -> Subquery Scan tmp (cost=5.37..5.62 rows=100width=12) (actual time=1.51..1.51 rows=0 loops=500) Filter: (commit_log_id = $0) -> Limit (cost=5.37..5.62 rows=100 width=12)(actual time=0.03..1.09 rows=90 loops=500) -> Sort (cost=5.37..5.62 rows=101 width=12) (actual time=0.02..0.38 rows=91 loops=500) Sort Key: commit_date -> Seq Scan on clp (cost=0.00..2.01rows=101 width=12) (actual time=0.23..3.88 rows=500 loops=1)Total runtime: 768.14 msec
В списке pgsql-sql по дате отправления: