Re: [PATCHES] [HACKERS] TRUNCATE TABLE with IDENTITY

2008-07-01 Thread Bruce Momjian
Alvaro Herrera wrote:
> Tom Lane wrote:
> 
> > 2. I had first dismissed Neil's idea of transactional sequence updates
> > as impossible, but on second look it could be done.  Suppose RESTART
> > IDENTITY does this for each sequence;
> > 
> > * obtain AccessExclusiveLock;
> > * assign a new relfilenode;
> > * insert a sequence row with all parameters copied except
> >   last_value copies start_value;
> > * hold AccessExclusiveLock till commit.
> 
> Hmm, this kills the idea of moving sequence data to a single
> non-transactional catalog :-(
> 
> > So what I think we should do is leave the patch there, revise the
> > warning per Neil's complaint, and add a TODO item to reimplement RESTART
> > IDENTITY transactionally.
> 
> I think the TODO item did not make it, but the docs do seem updated.

Done:

* Fix TRUNCATE ... RESTART IDENTITY so its affect on sequences is rolled
  back on transaction abort

-- 
  Bruce Momjian  <[EMAIL PROTECTED]>http://momjian.us
  EnterpriseDB http://enterprisedb.com

  + If your life is a hard drive, Christ can be your backup. +

-- 
Sent via pgsql-patches mailing list (pgsql-patches@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-patches


Re: [PATCHES] [HACKERS] TRUNCATE TABLE with IDENTITY

2008-06-08 Thread Tom Lane
Alvaro Herrera <[EMAIL PROTECTED]> writes:
> Tom Lane wrote:
>> 2. I had first dismissed Neil's idea of transactional sequence updates
>> as impossible, but on second look it could be done.  Suppose RESTART
>> IDENTITY does this for each sequence;
>> 
>> * obtain AccessExclusiveLock;
>> * assign a new relfilenode;
>> * insert a sequence row with all parameters copied except
>> last_value copies start_value;
>> * hold AccessExclusiveLock till commit.

> Hmm, this kills the idea of moving sequence data to a single
> non-transactional catalog :-(

Well, there are a number of holes in our ideas of how to do that anyway.
But offhand I don't see why we couldn't distinguish regular heap_update
from update_in_place on single rows within a catalog.

regards, tom lane

-- 
Sent via pgsql-patches mailing list (pgsql-patches@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-patches


Re: [PATCHES] [HACKERS] TRUNCATE TABLE with IDENTITY

2008-06-07 Thread Alvaro Herrera
Tom Lane wrote:

> 2. I had first dismissed Neil's idea of transactional sequence updates
> as impossible, but on second look it could be done.  Suppose RESTART
> IDENTITY does this for each sequence;
> 
>   * obtain AccessExclusiveLock;
>   * assign a new relfilenode;
>   * insert a sequence row with all parameters copied except
> last_value copies start_value;
>   * hold AccessExclusiveLock till commit.

Hmm, this kills the idea of moving sequence data to a single
non-transactional catalog :-(

> So what I think we should do is leave the patch there, revise the
> warning per Neil's complaint, and add a TODO item to reimplement RESTART
> IDENTITY transactionally.

I think the TODO item did not make it, but the docs do seem updated.

-- 
Alvaro Herrerahttp://www.CommandPrompt.com/
PostgreSQL Replication, Consulting, Custom Development, 24x7 support

-- 
Sent via pgsql-patches mailing list (pgsql-patches@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-patches


Re: [PATCHES] [HACKERS] TRUNCATE TABLE with IDENTITY

2008-05-17 Thread Simon Riggs

On Sat, 2008-05-17 at 12:04 -0400, Tom Lane wrote:

> So what I think we should do is leave the patch there, revise the
> warning per Neil's complaint, and add a TODO item to reimplement
> RESTART IDENTITY transactionally.

Sounds good.

-- 
 Simon Riggs   www.2ndQuadrant.com
 PostgreSQL Training, Services and Support


-- 
Sent via pgsql-patches mailing list (pgsql-patches@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-patches


Re: [PATCHES] [HACKERS] TRUNCATE TABLE with IDENTITY

2008-05-17 Thread Tom Lane
Simon Riggs <[EMAIL PROTECTED]> writes:
> On Fri, 2008-05-16 at 21:50 -0400, Tom Lane wrote:
>> Actually, I agree.  Shall we just revert that feature?

> Perhaps, but we should also take into account that TRUNCATE is not and
> never will be MVCC compliant, so its not something you'd expect to run
> except as a maintenance action.

Good point.  I had a couple of further thoughts this morning:

1. The case Neil is worried about is something like

BEGIN;
TRUNCATE TABLE foo RESTART IDENTITY;
COPY foo FROM ...;
COMMIT;

If the COPY fails partway through, the old table contents are restored,
but the sequences are not.  However removing RESTART IDENTITY will not
remove the hazard, because there is no difference between this and

BEGIN;
TRUNCATE TABLE foo;
SELECT setval('foo_id', 1);
COPY foo FROM ...;
COMMIT;

other than the latter adding a little extra chance for pilot error in
resetting the wrong sequence.  So if we revert the patch we haven't
accomplished much except to take away an opportunity to point out the
risk.  I vote for leaving the patch in and rewriting the 
to point out this risk.

2. I had first dismissed Neil's idea of transactional sequence updates
as impossible, but on second look it could be done.  Suppose RESTART
IDENTITY does this for each sequence;

* obtain AccessExclusiveLock;
* assign a new relfilenode;
* insert a sequence row with all parameters copied except
  last_value copies start_value;
* hold AccessExclusiveLock till commit.

IOW just like truncate-and-reload, but for a sequence.  Within the
current backend, subsequent operations see the new sequence values.
If the transaction rolls back, the old sequence relfilenode is still
there and untouched.

It's slightly annoying to need to lock out other backends' nextval
operations, but for the use-case of TRUNCATE this doesn't seem
like it's really much of a problem.

I'm not sure if it'd be worth exposing this behavior as a separate
user-visible command (CREATE OR REPLACE SEQUENCE, maybe?), but it seems
worth doing to make TRUNCATE-and-reload less of a foot gun.

So what I think we should do is leave the patch there, revise the
warning per Neil's complaint, and add a TODO item to reimplement RESTART
IDENTITY transactionally.

regards, tom lane

-- 
Sent via pgsql-patches mailing list (pgsql-patches@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-patches


Re: [PATCHES] [HACKERS] TRUNCATE TABLE with IDENTITY

2008-05-17 Thread Simon Riggs

On Fri, 2008-05-16 at 21:50 -0400, Tom Lane wrote:
> Neil Conway <[EMAIL PROTECTED]> writes:
> > Ugh. The fact that the RESTART IDENTITY part of TRUNCATE is
> > non-transactional is a pretty unsightly wort.
> 
> Actually, I agree.  Shall we just revert that feature?  The ALTER
> SEQUENCE part of this patch is clean and useful, but I'm less than
> enamored of the TRUNCATE part.

Perhaps, but we should also take into account that TRUNCATE is not and
never will be MVCC compliant, so its not something you'd expect to run
except as a maintenance action. If we do keep it, I would suggest that
we add a WARNING so that the effects are clearly recorded.

-- 
 Simon Riggs   www.2ndQuadrant.com
 PostgreSQL Training, Services and Support


-- 
Sent via pgsql-patches mailing list (pgsql-patches@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-patches


Re: [PATCHES] [HACKERS] TRUNCATE TABLE with IDENTITY

2008-05-16 Thread Tom Lane
Neil Conway <[EMAIL PROTECTED]> writes:
> Ugh. The fact that the RESTART IDENTITY part of TRUNCATE is
> non-transactional is a pretty unsightly wort.

Actually, I agree.  Shall we just revert that feature?  The ALTER
SEQUENCE part of this patch is clean and useful, but I'm less than
enamored of the TRUNCATE part.

regards, tom lane

-- 
Sent via pgsql-patches mailing list (pgsql-patches@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-patches


Re: [PATCHES] [HACKERS] TRUNCATE TABLE with IDENTITY

2008-05-16 Thread Neil Conway
On Fri, 2008-05-16 at 19:41 -0400, Tom Lane wrote:
> Applied with corrections.  Most notably, since ALTER SEQUENCE RESTART
> is nontransactional like most other ALTER SEQUENCE operations, I
> rearranged things to try to ensure that foreseeable failures like
> deadlock and lack of permissions would be detected before TRUNCATE
> starts to issue any RESTART commands.

Ugh. The fact that the RESTART IDENTITY part of TRUNCATE is
non-transactional is a pretty unsightly wort. I would also quarrel with
your addition to the docs that suggests this is only an issue "in
practice" if TRUNCATE RESTART IDENTITY is used in a transaction block:
unpredictable failures (such as OOM or query cancellation) can certainly
occur in practice, and would be very disruptive (e.g. if the sequence
values are stored into a column with a UNIQUE constraint, it would break
all inserting transactions until the DBA intervenes).

I wonder if it would be possible to make the sequence operations
performed by TRUNCATE transactional: while the TRUNCATE remains
uncommitted, it should be okay to block concurrent access to the
sequence.

-Neil



-- 
Sent via pgsql-patches mailing list (pgsql-patches@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-patches


Re: [PATCHES] [HACKERS] TRUNCATE TABLE with IDENTITY

2008-05-16 Thread Tom Lane
Zoltan Boszormenyi <[EMAIL PROTECTED]> writes:
>> Attached patch implements the extension found in the current SQL200n draft,
>> implementing stored start value and supporting ALTER SEQUENCE seq RESTART;

> Updated patch implements TRUNCATE ... RESTART IDENTITY
> which restarts all owned sequences for the truncated table(s).

Applied with corrections.  Most notably, since ALTER SEQUENCE RESTART
is nontransactional like most other ALTER SEQUENCE operations, I
rearranged things to try to ensure that foreseeable failures like
deadlock and lack of permissions would be detected before TRUNCATE
starts to issue any RESTART commands.

One interesting point here is that the patch as submitted allowed
ALTER SEQUENCE MINVALUE/MAXVALUE to be used to set a sequence range
that the original START value was outside of.  This would result in
a failure at ALTER SEQUENCE RESTART.  Since, as stated above, we
really don't want that happening during TRUNCATE, I adjusted the
patch to make such an ALTER SEQUENCE fail.  This is at least potentially
an incompatible change: command sequences that used to be legal could
now fail.  I doubt it's very likely to bite anyone in practice, though.

regards, tom lane

-- 
Sent via pgsql-patches mailing list (pgsql-patches@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-patches


Re: [PATCHES] [HACKERS] TRUNCATE TABLE with IDENTITY

2008-04-21 Thread Zoltan Boszormenyi

Zoltan Boszormenyi írta:

Zoltan Boszormenyi írta:

Decibel! írta:

On Apr 3, 2008, at 12:52 AM, Zoltan Boszormenyi wrote:

Where is the info in the sequence to provide restarting with
the _original_ start value?


There isn't any. If you want the sequence to start at some magic 
value, adjust the minimum value.


There's the START WITH option for IDENTITY columns and this below
is paragraph 8 under General rules of 14.10 
in 6WD2_02_Foundation_2007-12.pdf (page 902):

8) If RESTART IDENTITY is specified and the table descriptor of T 
includes a column descriptor IDCD of

  an identity column, then:
  a) Let CN be the column name included in IDCD and let SV be the 
start value included in IDCD.
  b) The following  is effectively executed 
without further Access Rule checking:

  ALTER TABLE TN ALTER COLUMN CN RESTART WITH SV

This says that the original start value is used, not the minimum value.
IDENTITY has the same options as CREATE SEQUENCE. In fact the
"identity column specification" links to "11.63 definition>"

when it comes to IDENTITY sequence options. And surprise, surprise,
"11.64 " now defines
ALTER SEQUENCE sn RESTART [WITH newvalue]
where omitting the "WITH newval" part also uses the original start 
value.


Best regards,
Zoltán Böszörményi


Attached patch implements the extension found in the current SQL200n 
draft,
implementing stored start value and supporting ALTER SEQUENCE seq 
RESTART;
Some error check are also added to prohibit CREATE SEQUENCE ... 
RESTART ...

and ALTER SEQUENCE ... START ...

Best regards,
Zoltán Böszörményi


Updated patch implements TRUNCATE ... RESTART IDENTITY
which restarts all owned sequences for the truncated table(s).
Regression tests updated, documentation added. pg_dump was
also extended to output original[1] START value for creating SEQUENCEs.

[1] For 8.3 and below I could only guesstimate it as MINVALUE for ascending
 and MAXVALUE for descending sequences.

Best regards,
Zoltán Böszörményi

--
--
Zoltán Böszörményi
Cybertec Schönig & Schönig GmbH
http://www.postgresql.at/



sql2008-compliant-seq-v2.patch.gz
Description: Unix tar archive

-- 
Sent via pgsql-patches mailing list (pgsql-patches@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-patches


Re: [PATCHES] [HACKERS] TRUNCATE TABLE with IDENTITY

2008-04-08 Thread Zoltan Boszormenyi

Zoltan Boszormenyi írta:

Decibel! írta:

On Apr 3, 2008, at 12:52 AM, Zoltan Boszormenyi wrote:

Where is the info in the sequence to provide restarting with
the _original_ start value?


There isn't any. If you want the sequence to start at some magic 
value, adjust the minimum value.


There's the START WITH option for IDENTITY columns and this below
is paragraph 8 under General rules of 14.10 
in 6WD2_02_Foundation_2007-12.pdf (page 902):

8) If RESTART IDENTITY is specified and the table descriptor of T 
includes a column descriptor IDCD of

  an identity column, then:
  a) Let CN be the column name included in IDCD and let SV be the 
start value included in IDCD.
  b) The following  is effectively executed 
without further Access Rule checking:

  ALTER TABLE TN ALTER COLUMN CN RESTART WITH SV

This says that the original start value is used, not the minimum value.
IDENTITY has the same options as CREATE SEQUENCE. In fact the
"identity column specification" links to "11.63 definition>"

when it comes to IDENTITY sequence options. And surprise, surprise,
"11.64 " now defines
ALTER SEQUENCE sn RESTART [WITH newvalue]
where omitting the "WITH newval" part also uses the original start value.

Best regards,
Zoltán Böszörményi


Attached patch implements the extension found in the current SQL200n draft,
implementing stored start value and supporting ALTER SEQUENCE seq RESTART;
Some error check are also added to prohibit CREATE SEQUENCE ... RESTART ...
and ALTER SEQUENCE ... START ...

Best regards,
Zoltán Böszörményi

--
--
Zoltán Böszörményi
Cybertec Schönig & Schönig GmbH
http://www.postgresql.at/

diff -dcrpN pgsql.orig/src/backend/commands/sequence.c pgsql/src/backend/commands/sequence.c
*** pgsql.orig/src/backend/commands/sequence.c	2008-01-01 20:45:49.0 +0100
--- pgsql/src/backend/commands/sequence.c	2008-04-08 10:51:27.0 +0200
*** static Relation open_share_lock(SeqTable
*** 88,94 
  static void init_sequence(Oid relid, SeqTable *p_elm, Relation *p_rel);
  static Form_pg_sequence read_info(SeqTable elm, Relation rel, Buffer *buf);
  static void init_params(List *options, bool isInit,
! 			Form_pg_sequence new, List **owned_by);
  static void do_setval(Oid relid, int64 next, bool iscalled);
  static void process_owned_by(Relation seqrel, List *owned_by);
  
--- 88,94 
  static void init_sequence(Oid relid, SeqTable *p_elm, Relation *p_rel);
  static Form_pg_sequence read_info(SeqTable elm, Relation rel, Buffer *buf);
  static void init_params(List *options, bool isInit,
! 			Form_pg_sequence new, Form_pg_sequence old, List **owned_by);
  static void do_setval(Oid relid, int64 next, bool iscalled);
  static void process_owned_by(Relation seqrel, List *owned_by);
  
*** DefineSequence(CreateSeqStmt *seq)
*** 116,122 
  	NameData	name;
  
  	/* Check and set all option values */
! 	init_params(seq->options, true, &new, &owned_by);
  
  	/*
  	 * Create relation (and fill *null & *value)
--- 116,122 
  	NameData	name;
  
  	/* Check and set all option values */
! 	init_params(seq->options, true, &new, NULL, &owned_by);
  
  	/*
  	 * Create relation (and fill *null & *value)
*** DefineSequence(CreateSeqStmt *seq)
*** 143,148 
--- 143,153 
  namestrcpy(&name, seq->sequence->relname);
  value[i - 1] = NameGetDatum(&name);
  break;
+ 			case SEQ_COL_STARTVAL:
+ coldef->typename = makeTypeNameFromOid(INT8OID, -1);
+ coldef->colname = "start_value";
+ value[i - 1] = Int64GetDatumFast(new.start_value);
+ break;
  			case SEQ_COL_LASTVAL:
  coldef->typename = makeTypeNameFromOid(INT8OID, -1);
  coldef->colname = "last_value";
*** AlterSequence(AlterSeqStmt *stmt)
*** 336,342 
  	memcpy(&new, seq, sizeof(FormData_pg_sequence));
  
  	/* Check and set new values */
! 	init_params(stmt->options, false, &new, &owned_by);
  
  	/* Clear local cache so that we don't think we have cached numbers */
  	/* Note that we do not change the currval() state */
--- 341,347 
  	memcpy(&new, seq, sizeof(FormData_pg_sequence));
  
  	/* Check and set new values */
! 	init_params(stmt->options, false, &new, seq, &owned_by);
  
  	/* Clear local cache so that we don't think we have cached numbers */
  	/* Note that we do not change the currval() state */
*** read_info(SeqTable elm, Relation rel, Bu
*** 967,973 
   */
  static void
  init_params(List *options, bool isInit,
! 			Form_pg_sequence new, List **owned_by)
  {
  	DefElem*last_value = NULL;
  	DefElem*increment_by = NULL;
--- 972,978 
   */
  static void
  init_params(List *options, bool isInit,
! 			Form_pg_sequence new, Form_pg_sequence old, List **owned_by)
  {
  	DefElem*last_value = NULL;
  	DefElem*increment_by = NULL;
*** init_params(List *options, bool isInit,
*** 995,1003 
  		/*
  		 * start is for a new sequence restart is for alter
  		 */
!