Thread: insert with select as value
I need to insert a value = max(value)+1, where max is a select limited by a 'where' clause. Like this: INSERT INTO table (idthread, idsection,txt) VALUES ( (SELECT max(idthread)+1 FROM table WHERE idsection = 'CZE'), 'CZE', 'sample text') ); This works fine, except when the result of SELECT is empty - which is true when the table is empty. Is it possible to create a "SELECT max(idthread)+1 FROM table WHERE idsection = 'CZE';" that will return value 1 instead of value None if the SELECT has no results? -- Milos Prudek _________________ Most websites are confused chintzy gaudy conflicting tacky unpleasant... unusable. Learn how usable YOUR website is! http://www.spoxdesign.com
You can use the COALESCE function, like this: INSERT INTO table (idthread, idsection,txt) VALUES ( COALESCE((SELECT max(idthread)+1 FROM table WHERE idsection = 'CZE'),1), 'CZE', 'sample text') ); This function returns the first of its argument that is not null. If your query returns no value, the second argument (in this case, the number "1"). Marcelo Soares Informática - Master Hotéis ICQ Externo: 19398317 ICQ Interno: 1002 Linux user#: 288006 PGP Key: http://gravatai.ulbra.tche.br/~ringostar/MS-PubOficial.pgp ------------------------------------------------------------------ "Não há limite para a cultura, Watson. O campo de nossas experiências é uma série de lições das quais a maior é sempre a última." Sherlock Holmes (A.C.Doyle) ------------------------------------------------------------------ > I need to insert a value = max(value)+1, where max is a select limited > by a 'where' clause. Like this: > > INSERT INTO table (idthread, idsection,txt) > VALUES ( > (SELECT max(idthread)+1 FROM table WHERE idsection = 'CZE'), 'CZE', > 'sample text') > ); > > This works fine, except when the result of SELECT is empty - which is > true when the table is empty. > > Is it possible to create a "SELECT max(idthread)+1 FROM table WHERE > idsection = 'CZE';" that will return value 1 instead of value None if > the SELECT has no results? > > -- > Milos Prudek > _________________ > Most websites are > confused chintzy gaudy conflicting tacky unpleasant... unusable. > Learn how usable YOUR website is! http://www.spoxdesign.com > > ---------------------------(end of broadcast)--------------------------- > TIP 6: Have you searched our list archives? > > http://archives.postgresql.org >
On Tue, Jun 22, 2004 at 16:22:33 +0200, Milos Prudek <prudek@bvx.cz> wrote: > I need to insert a value = max(value)+1, where max is a select limited > by a 'where' clause. Like this: If your purpose in doing this is just to generate unique keys, you should be using sequences instead. > > INSERT INTO table (idthread, idsection,txt) > VALUES ( > (SELECT max(idthread)+1 FROM table WHERE idsection = 'CZE'), 'CZE', > 'sample text') > ); Note that you probably want to lock the table before doing this or two transactions running at the same time can generate the same value for idthread. > > This works fine, except when the result of SELECT is empty - which is > true when the table is empty. > > Is it possible to create a "SELECT max(idthread)+1 FROM table WHERE > idsection = 'CZE';" that will return value 1 instead of value None if > the SELECT has no results? You could either right your own max function, or you can use coallesce. For example: SELECT coallesce(max(idthread),0)+1 FROM table WHERE idsection = 'CZE'; If there is a compound index on idthread and idsection, then you are probably better off using something like the following to take advantage of the index: coallesce((SELECT idthread FROM table WHERE idsection = 'CZE' ORDER BY idthread DESC, idsection DESC LIMT 1))+1 (You need to list idthread and idsection in the ORDER BY clause in the same order they are listed in the index.)
> Is it possible to create a "SELECT max(idthread)+1 FROM table WHERE > idsection = 'CZE';" that will return value 1 instead of value None if > the SELECT has no results? Never mind, I figured it myself. I found that there is COALESCE function in Postgres (in Functions and Operators / Conditional Expressions) and that it is exactly what is needed. And Kuti Atilla send me the same answer in a private email. Thanks! -- Milos Prudek _________________ Most websites are confused chintzy gaudy conflicting tacky unpleasant... unusable. Learn how usable YOUR website is! http://www.spoxdesign.com
Try rewriting the inner query as: SELECT s.* FROM ( SELECT max(idthread)+1 as MX, 'CZE', 'sample text' FROM table WHERE idsection = 'CZE' union SELECT 1 as MX, 'CZE', 'sample text' ) as s ORDER BY s.MX desc LIMIT 1 I think that should work, and always return a row. John Sidney-Woollett Milos Prudek wrote: > I need to insert a value = max(value)+1, where max is a select limited > by a 'where' clause. Like this: > > INSERT INTO table (idthread, idsection,txt) > VALUES ( > (SELECT max(idthread)+1 FROM table WHERE idsection = 'CZE'), > 'CZE', 'sample text') > ); > > This works fine, except when the result of SELECT is empty - which is > true when the table is empty. > > Is it possible to create a "SELECT max(idthread)+1 FROM table WHERE > idsection = 'CZE';" that will return value 1 instead of value None if > the SELECT has no results? >
> If your purpose in doing this is just to generate unique keys, you should > be using sequences instead. I would need 150 separate sequences, because each idsection needs its own, independent sequence of idthread. > Note that you probably want to lock the table before doing this or > two transactions running at the same time can generate the same > value for idthread. That's a surprise. I could have made two separate queries (a select and then insert) in my programming language (Python), but I wanted to make it in one query PRECISELY because I thought that would prevent the race condition that you describe. Are you quite sure? > For example: > SELECT coallesce(max(idthread),0)+1 FROM table WHERE idsection = 'CZE'; Someone already sent me this by private email, and it works fine. > If there is a compound index on idthread and idsection, then you are probably > better off using something like the following to take advantage of the index: > coallesce((SELECT idthread FROM table WHERE idsection = 'CZE' ORDER BY > idthread DESC, idsection DESC LIMT 1))+1 That's interesting and valuable, thank you very much. -- Milos Prudek _________________ Most websites are confused chintzy gaudy conflicting tacky unpleasant... unusable. Learn how usable YOUR website is! http://www.spoxdesign.com
In article <40D96C94.5040005@bvx.cz>, Milos Prudek <prudek@bvx.cz> writes: >> If your purpose in doing this is just to generate unique keys, you should >> be using sequences instead. > I would need 150 separate sequences, because each idsection needs its > own, independent sequence of idthread. What you really seem to need is a counter for each idsection. Depending on how often you need to access the counter value, it might be worthwile to not store the count at all and instead use a single sequence. You can compute the counter value at SELECT time by something like SELECT idsection, ( SELECT count (*) FROM tbl t WHERE idsection = tbl.idsection AND id <= tbl.id ) AS idthread FROM tbl where "id" is the single sequence.
On Wed, Jun 23, 2004 at 13:42:12 +0200, Milos Prudek <prudek@bvx.cz> wrote: > >If your purpose in doing this is just to generate unique keys, you should > >be using sequences instead. > > I would need 150 separate sequences, because each idsection needs its > own, independent sequence of idthread. Not if you just want to generate unique keys. In that case you can use one sequence for each idsection. If you need more than uniqueness then you don't want to use sequences. > >Note that you probably want to lock the table before doing this or > >two transactions running at the same time can generate the same > >value for idthread. > > That's a surprise. I could have made two separate queries (a select and > then insert) in my programming language (Python), but I wanted to make > it in one query PRECISELY because I thought that would prevent the race > condition that you describe. Are you quite sure? Yes. If two transactions are proceeding at the same time they can both see the same highest value and hence pick the same next value. You need to do some sort of locking to prevent this. Lock table is the simplest. You could also use select for update, but I believe this may result in occassional deadlocks, so you will need to be able to retry queries when that happens.