Обсуждение: The best option to insert data with primary id

Поиск
Список
Период
Сортировка

The best option to insert data with primary id

От
-
Дата:
Hi everyone,
 
I have a question about how best to insert and manipulate the table with primary key id for better productivity. I need to insert data into the table and get last id.

1. First option to take counter Postgres SEQUENCE:
INSERT INTO table (id, ...) VALUES ((SELECT nextval ('seq_table')), ...) RETURNING (SELECT currval ('seq_table')) AS id

Only thing I see, that if the row is not inserted, the counter is incremented every time when called. Then they will have empty unused id in the table and ID number will grow much. There will be many records. This id int8 type declared with length 64.
Is there any option to occupy empty sequence records. I have to worry about this?

2. Second option is to take control of id and
INSERT INTO table (id, ...) VALUES ((SELECT MAX (id) +1 FROM table), ...)
RETURNING (SELECT MAX (id) +1 FROM table) AS id

Quero your opinions on how best to insert data to have less maintenance and better productivity with concurrent users.
Thank you very much.


Same question in Spanish.

Hola a todos,
 tengo una pregunta sobre como mejor hacer insert en la tabla y manipular id con primary key para mejor productividad. Necesito Insertar datos a la tabla y obtener ultima id.

1. Primera opcion llevar contador con SEQUENCE de Postgres :
INSERT INTO table (id, ...) VALUES ((SELECT nextval('seq_table')), ...)  RETURNING (SELECT currval('seq_table')) AS id

Unica cosa que veo, que si no se inserta la fila, el contador se incrementa cada ves cuando se llama. Entonces habran id vacias sin usar en la tabla y numero de id se va a crecer mucho. Habran muchos registros. Esta id declarada como type int8 con longitud 64. 
Hay alguna opcion de ocupar registros de sequence vacias. Tengo que preocupar por esto?

2. Segunda opcion es coger control de id como
INSERT INTO table (id, ...) VALUES ((SELECT MAX(id)+1 FROM table), ...) 
RETURNING (SELECT MAX(id)+1 FROM table) AS id

Quero vuestras opiniones sobre como mejor hacer insert de datos para tener menor mantenimiento y mejor productividad con usuarios concurrentes.
Muchas gracias.


Re: The best option to insert data with primary id

От
mike@if-then-else.pl
Дата:
Quoting - <grandebuzon@gmail.com>:

> I have a question about how best to insert and manipulate the table with
> primary key id for better productivity. I need to insert data into the table
> and get last id.
>
> 1. First option to take counter Postgres SEQUENCE:
> INSERT INTO table (id, ...) VALUES ((SELECT nextval ('seq_table')), ...)
> RETURNING (SELECT currval ('seq_table')) AS id

Much simplier:

INSERT INTO table (name, email, salary) VALUES ('joe', 'joe@example.com',
100) RETURNING id;

Cheers,
  -Mike

--
Michał Roszka
mike@if-then-else.pl



Re: The best option to insert data with primary id

От
mike@if-then-else.pl
Дата:
Quoting - <grandebuzon@gmail.com>:

> I know you can skip SEQUENCE - ((SELECT nextval ('seq_table')) do not put
> this in the query, my question was that such concurrency, and ids
> omitted  which can not be inserted but increased with SEQUENCE ?

In the initial message you have been wondering, if you should be worried
about "wasted" sequence tokens.  You have mentioned, that your primary key
is of type int8 and so is the sequence range.  Do you really expect as many
records and/or insert queries?

If so, consider the id column int8 DEFAULT NULL and an AFTER INSERT trigger
function that would take a nextval of the sequence and update the id
accordingly once the record *has been actually inserted* instead of poking
the sequence each time you *are going to insert* something.

I am pretty sure, that the table is locked to prevent inserts until the
after-insert-trigger is finished.

Cheers,
   -Mike

--
Michał Roszka
mike@if-then-else.pl



Re: The best option to insert data with primary id

От
Jasen Betts
Дата:
On 2010-12-06, - <grandebuzon@gmail.com> wrote:
> --0016364d26cf7fa4970496bf2224
> Content-Type: text/plain; charset=ISO-8859-1
>
> Hi everyone,
>  I have a question about how best to insert and manipulate the table with
> primary key id for better productivity. I need to insert data into the table
> and get last id.
>
> 1. First option to take counter Postgres SEQUENCE:
> INSERT INTO table (id, ...) VALUES ((SELECT nextval ('seq_table')), ...)
> RETURNING (SELECT currval ('seq_table')) AS id
>
> Only thing I see, that if the row is not inserted, the counter is
> incremented every time when called. Then they will have empty unused id in
> the table and ID number will grow much. There will be many records. This id
> int8 type declared with length 64.
> Is there any option to occupy empty sequence records. I have to worry about
> this?
(assuming the default for id is nextval ('seq_table'))

INSERT INTO table ( id, ...) VALUES ( default, ...)  RETURNING id;
or you can leave id and default out of the left half:

INSERT INTO table ( ...) VALUES ( ...)  RETURNING id;

> 2. Second option is to take control of id and
> INSERT INTO table (id, ...) VALUES ((SELECT MAX (id) +1 FROM table), ...)
> RETURNING (SELECT MAX (id) +1 FROM table) AS id

you run into concurrency issues that way. (two concurrent inserts
could pick the same ID, one will fail with an error)

> Quero your opinions on how best to insert data to have less maintenance and
> better productivity with concurrent users.
> Thank you very much.

INSERT INTO table ( ...) VALUES ( ...)  RETURNING id;

Use the sequence, that's what they were designed for.
Let id get the default value and pull that from the returning.
you will get gaps in the serquence due to failed or cancelled
transactions but there will probably not be many gaps.

-- 
⚂⚃ 100% natural