Search Postgresql Archives

Re: Best Approach for Swapping a Table with its Copy

[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]

 



On Fri, 2025-02-14 at 11:59 +1300, Marcelo Fernandes wrote:
> On Thu, Feb 13, 2025 at 7:37 PM Laurenz Albe <laurenz.albe@xxxxxxxxxxx> wrote:
> > The big challenge here would be to do the swap in a safe way.  How do
> > you intend to guarantee that the foreign keys are valid without a table
> > scan?  How do you handle concurrent data modifications?
> 
> Exactly! This is part of what I am trying to figure out (-:
> 
> The plan that I have in mind so far to swap a table safely is:
> 
> 1. Run the following query to grab information about the toast and the toast
>    index of the tables involved in the swapping:
> 
>   SELECT
>     X.oid,
>     X.reltoastrelid,
>     X.relowner,
>     TOAST_X.indexrelid
>   FROM pg_catalog.pg_class X
>     LEFT JOIN
>       pg_catalog.pg_index TOAST_X ON X.reltoastrelid =
> TOAST_X.indrelid AND TOAST_X.indisvalid
>   WHERE X.oid = ('my_sweet_table')::regclass;
> 
> 2. Open a transaction and acquire an access exclusive lock.
> 3. Ensure that the cloned table has the same owner as the original table
> 
>   ALTER TABLE copy_table OWNER TO owner_of_the_original_table;
> 
> 4. Now I need to swap all the data in the catalogue tables that point to the
>    old table and the toast to point to the new one and vice-versa (in case I
>    need to rollback).
> 5. Commit
> 
> Step 4 is what I am stuck on. What bits of the catalogue do I need to change?
> And for what reasons?
> 
> It may be a risky operation, as you say and I might decide not to do pursue it
> in the end, but first I must understand (-:

In your steps, you carefully avoid the question of whether the foreign key is
valid or not.  So you are trusting the user to have made sure that everything
is fine with the foreign key...

I may forget something, but I'd say that swapping out the files from under a
table's butt is just a question of updating the "pg_class.relfilenode" of the
tables and the TOAST tables.  But if you just UPDATE the catalogs, concurrent
statements that are using the tables will be in trouble, so you need to take
an ACCESS EXCLUSIVE lock.  Moreover, you have to make sure to send out
invalidation messages so that every session that caches statistics or
execution plans for the tables discards them.

Yours,
Laurenz Albe

-- 

*E-Mail Disclaimer*
Der Inhalt dieser E-Mail ist ausschliesslich fuer den 
bezeichneten Adressaten bestimmt. Wenn Sie nicht der vorgesehene Adressat 
dieser E-Mail oder dessen Vertreter sein sollten, so beachten Sie bitte, 
dass jede Form der Kenntnisnahme, Veroeffentlichung, Vervielfaeltigung oder 
Weitergabe des Inhalts dieser E-Mail unzulaessig ist. Wir bitten Sie, sich 
in diesem Fall mit dem Absender der E-Mail in Verbindung zu setzen.

*CONFIDENTIALITY NOTICE & DISCLAIMER
*This message and any attachment are 
confidential and may be privileged or otherwise protected from disclosure 
and solely for the use of the person(s) or entity to whom it is intended. 
If you have received this message in error and are not the intended 
recipient, please notify the sender immediately and delete this message and 
any attachment from your system. If you are not the intended recipient, be 
advised that any use of this message is prohibited and may be unlawful, and 
you must not copy this message or attachment or disclose the contents to 
any other person.






[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]
[Index of Archives]     [Postgresql Jobs]     [Postgresql Admin]     [Postgresql Performance]     [Linux Clusters]     [PHP Home]     [PHP on Windows]     [Kernel Newbies]     [PHP Classes]     [PHP Databases]     [Postgresql & PHP]     [Yosemite]

  Powered by Linux