Thread: create table like: ACCESS METHOD
I thought this was a good idea, but didn't hear back when I raised it before. Failing to preserve access method is arguably a bug, reminiscent of CREATE STATISTICS and 5564c1181. But maybe it's not important to backpatch a fix in this case, since access methods are still evolving. https://www.postgresql.org/message-id/20190818193533.GL11185@telsasoft.com On Sun, Aug 18, 2019 at 02:35:33PM -0500, Justin Pryzby wrote: > . What do you think about pg_restore --no-tableam; similar to > --no-tablespaces, it would allow restoring a table to a different AM: > PGOPTIONS='-c default_table_access_method=zedstore' pg_restore --no-tableam ./pg_dump.dat -d postgres > Otherwise, the dump says "SET default_table_access_method=heap", which > overrides any value from PGOPTIONS and precludes restoring to new AM. ... > . it'd be nice if there was an ALTER TABLE SET ACCESS METHOD, to allow > migrating data. Otherwise I think the alternative is: > begin; lock t; > CREATE TABLE new_t LIKE (t INCLUDING ALL) USING (zedstore); > INSERT INTO new_t SELECT * FROM t; > for index; do CREATE INDEX...; done > DROP t; RENAME new_t (and all its indices). attach/inherit, etc. > commit; > > . Speaking of which, I think LIKE needs a new option for ACCESS METHOD, which > is otherwise lost.
Attachment
On Wed, Dec 09, 2020 at 02:13:29PM -0600, Justin Pryzby wrote: > I thought this was a good idea, but didn't hear back when I raised it before. > > Failing to preserve access method is arguably a bug, reminiscent of CREATE > STATISTICS and 5564c1181. But maybe it's not important to backpatch a fix in > this case, since access methods are still evolving. Interesting. Access methods for tables are released for more than one year now, so my take about a backpatch is that this boat has already sailed. This may give a reason to actually not introduce this feature. + CREATE_TABLE_LIKE_ACCESSMETHOD = 1 << 0, Nit: wouldn't this be better as ACCESS_METHOD? -- fail, as partitioned tables don't allow NO INHERIT constraints -CREATE TABLE noinh_con_copy1_parted (LIKE noinh_con_copy INCLUDING ALL) +CREATE TABLE noinh_con_copy1_parted (LIKE noinh_con_copy INCLUDING ALL EXCLUDING ACCESS METHOD) PARTITION BY LIST (a); This diff means that you are introducing an incompatible change by forcing any application using CREATE TABLE LIKE for a partitioned table to exclude access methods. This is not acceptable, and it may be better to just ignore this clause instead in this context. This patch should have more tests. Something could be added in create_am.sql where there is a fake heap2 as table AM. + <para> + The table's access method will be copied. By default, the + <literal>default_table_access_method</literal> is used. + </para> Second sentence sounds a bit strange by combining "the" and a GUC name. I would just write "Default is default_table_a_m". -- Michael
Attachment
On Fri, Dec 25, 2020 at 03:41:46PM +0900, Michael Paquier wrote: > On Wed, Dec 09, 2020 at 02:13:29PM -0600, Justin Pryzby wrote: > > I thought this was a good idea, but didn't hear back when I raised it before. > > > > Failing to preserve access method is arguably a bug, reminiscent of CREATE > > STATISTICS and 5564c1181. But maybe it's not important to backpatch a fix in > > this case, since access methods are still evolving. > > Interesting. Access methods for tables are released for more than one > year now, so my take about a backpatch is that this boat has already > sailed. This may give a reason to actually not introduce this > feature. Are you saying that since v12/13 didn't preserve the access method, it might be preferred to never do it ? I think it's reasonable to to not change v12/13 but the behavior seems like an omission going forward. It's not so important right now, since AMs aren't widely used. This might be important for a few cases I can think of easily: If an readonly AM doesn't support DDL, and table needs to be rebuilt, we'd handle that by creating a new table LIKE the existing table, preserving its AM, and then INSERT into it. Like for column type promotion. That's much better than querying amname FROM pg_class JOIN relam. ALTER TABLE..ATTACH PARTITION requires a less strong lock than CREATE TABLE..PARTITION OF, so it's nice to be able to CREATE TABLE LIKE. To use an alternate AM for historic data, we'd CREATE TABLE LIKE an existing, populated table before inserting into it. This would support re-creating on a new AM, or re-creating on the same AM, say, to get rid of dropped columns, or to re-arrange columns. > -- fail, as partitioned tables don't allow NO INHERIT constraints > -CREATE TABLE noinh_con_copy1_parted (LIKE noinh_con_copy INCLUDING ALL) > +CREATE TABLE noinh_con_copy1_parted (LIKE noinh_con_copy INCLUDING ALL EXCLUDING ACCESS METHOD) > PARTITION BY LIST (a); > This diff means that you are introducing an incompatible change by > forcing any application using CREATE TABLE LIKE for a partitioned > table to exclude access methods. This is not acceptable, and it may > be better to just ignore this clause instead in this context. Ok. This means that CREATE TABLE (LIKE x INCLUDING ACCESS METHOD) PARTITION BY ... silently ignores the INCLUDING AM. Is that ok ? I think the alternative is for INCLUDING to be "ternary" options, defaulting to UNSET=0, when it's ok to ignore options in contexts where they're not useful. Maybe we'd need to specially handle INCLUDING ALL, to make options "soft"/implied rather than explicit. > This patch should have more tests. Something could be added in > create_am.sql where there is a fake heap2 as table AM. Yes, I had already done that locally. -- Justin
Attachment
On Tue, 29 Dec 2020 at 23:08, Justin Pryzby <pryzby@telsasoft.com> wrote: > > On Fri, Dec 25, 2020 at 03:41:46PM +0900, Michael Paquier wrote: > > On Wed, Dec 09, 2020 at 02:13:29PM -0600, Justin Pryzby wrote: > > > I thought this was a good idea, but didn't hear back when I raised it before. > > > > > > Failing to preserve access method is arguably a bug, reminiscent of CREATE > > > STATISTICS and 5564c1181. But maybe it's not important to backpatch a fix in > > > this case, since access methods are still evolving. > > > > Interesting. Access methods for tables are released for more than one > > year now, so my take about a backpatch is that this boat has already > > sailed. This may give a reason to actually not introduce this > > feature. > > Are you saying that since v12/13 didn't preserve the access method, it might be > preferred to never do it ? I think it's reasonable to not change v12/13 but > the behavior seems like an omission going forward. It's not so important right > now, since AMs aren't widely used. Omitting copying the AM seems like a bug during CREATE TABLE likeamlike(LIKE likeam INCLUDING ALL); But this does allow you to specify the TableAM by using default_table_access_method, and to use CREATE TABLE likeamlike(LIKE likeam INCLUDING ALL) USING (heapdup); if you wish to set the AM explicitly, so I don't see this as needing backpatch. Which means that the emphasis for the earlier functionality was towards one "preferred AM" rather than using multiple AMs at same time. Allowing this change in later releases makes sense. Please make sure this is marked as an incompatibility in the release notes. > > This patch should have more tests. Something could be added in > > create_am.sql where there is a fake heap2 as table AM. > > Yes, I had already done that locally. There are no tests for the new functionality, please could you add some? -- Simon Riggs http://www.EnterpriseDB.com/
On Wed, Dec 30, 2020 at 12:33:56PM +0000, Simon Riggs wrote: > There are no tests for the new functionality, please could you add some? Did you look at the most recent patch? +CREATE ACCESS METHOD heapdup TYPE TABLE HANDLER heap_tableam_handler; +CREATE TABLE likeam() USING heapdup; +CREATE TABLE likeamlike(LIKE likeam INCLUDING ALL); Also, I just realized that Dilip's toast compression patch adds "INCLUDING COMPRESSION", which is stored in pg_am. That's an implementation detail of that patch, but it's not intuitive that "including access method" wouldn't include the compression stored there. So I think this should use "INCLUDING TABLE ACCESS METHOD" not just ACCESS METHOD. -- Justin
Attachment
On 1/19/21 4:03 PM, Justin Pryzby wrote: > On Wed, Dec 30, 2020 at 12:33:56PM +0000, Simon Riggs wrote: >> There are no tests for the new functionality, please could you add some? > > Did you look at the most recent patch? > > +CREATE ACCESS METHOD heapdup TYPE TABLE HANDLER heap_tableam_handler; > +CREATE TABLE likeam() USING heapdup; > +CREATE TABLE likeamlike(LIKE likeam INCLUDING ALL); > > Also, I just realized that Dilip's toast compression patch adds "INCLUDING > COMPRESSION", which is stored in pg_am. That's an implementation detail of > that patch, but it's not intuitive that "including access method" wouldn't > include the compression stored there. So I think this should use "INCLUDING > TABLE ACCESS METHOD" not just ACCESS METHOD. Simon, do you know when you'll have a chance to review the updated patch in [1]? Regards, -- -David david@pgmasters.net [1] https://www.postgresql.org/message-id/20210119210331.GN8560%40telsasoft.com
On Tue, Jan 19, 2021 at 03:03:31PM -0600, Justin Pryzby wrote: > On Wed, Dec 30, 2020 at 12:33:56PM +0000, Simon Riggs wrote: > > There are no tests for the new functionality, please could you add some? > > Did you look at the most recent patch? > > +CREATE ACCESS METHOD heapdup TYPE TABLE HANDLER heap_tableam_handler; > +CREATE TABLE likeam() USING heapdup; > +CREATE TABLE likeamlike(LIKE likeam INCLUDING ALL); > > Also, I just realized that Dilip's toast compression patch adds "INCLUDING > COMPRESSION", which is stored in pg_am. That's an implementation detail of > that patch, but it's not intuitive that "including access method" wouldn't > include the compression stored there. So I think this should use "INCLUDING > TABLE ACCESS METHOD" not just ACCESS METHOD. Since the TOAST patch ended up not using access methods after all, I renamed this back to "like ACCESS METHOD" (without table). For now, I left TableLikeOption un-alphabetized. -- Justin
Attachment
rebased and alphabetized
Attachment
On Tue, Jun 01, 2021 at 02:10:45PM -0500, Justin Pryzby wrote: > rebased and alphabetized + /* ACCESS METHOD doesn't apply and isn't copied for partitioned tables */ + if ((table_like_clause->options & CREATE_TABLE_LIKE_ACCESS_METHOD) != 0 && + !cxt->ispartitioned) + cxt->accessMethod = get_am_name(relation->rd_rel->relam); I was thinking about an ERROR here, but all the other options do the work when specified only if required, so that's fine. We should have a test with a partitioned table and the clause specified, though. + <para> + The table's access method will be copied. By default, the + <literal>default_table_access_method</literal> is used. + </para> Why is there any need to mention default_table_access_method? This just inherits the AM from the source table, which has nothing to do with the default directly. +CREATE ACCESS METHOD heapdup TYPE TABLE HANDLER heap_tableam_handler; +CREATE TABLE likeam() USING heapdup; +CREATE TABLE likeamlike(LIKE likeam INCLUDING ALL); Rather than creating a custom AM in this test path, I would be tempted to move that to create_am.sql. -- Michael
Attachment
On 3/23/21 1:39 AM, Justin Pryzby wrote: > On Tue, Jan 19, 2021 at 03:03:31PM -0600, Justin Pryzby wrote: >> On Wed, Dec 30, 2020 at 12:33:56PM +0000, Simon Riggs wrote: >>> There are no tests for the new functionality, please could you add some? >> >> Did you look at the most recent patch? >> >> +CREATE ACCESS METHOD heapdup TYPE TABLE HANDLER heap_tableam_handler; >> +CREATE TABLE likeam() USING heapdup; >> +CREATE TABLE likeamlike(LIKE likeam INCLUDING ALL); It seems like this should error to me: CREATE ACCESS METHOD heapdup TYPE TABLE HANDLER heap_tableam_handler; CREATE TABLE likeam1() USING heap; CREATE TABLE likeam2() USING heapdup; CREATE TABLE likeamlike( LIKE likeam1 INCLUDING ACCESS METHOD, LIKE likeam2 INCLUDING ACCESS METHOD ); At the very least, the documentation should say that the last one wins. -- Vik Fearing
On Fri, Aug 27, 2021 at 12:37:59PM +0200, Vik Fearing wrote: > It seems like this should error to me: > > CREATE ACCESS METHOD heapdup TYPE TABLE HANDLER heap_tableam_handler; > CREATE TABLE likeam1() USING heap; > CREATE TABLE likeam2() USING heapdup; > CREATE TABLE likeamlike( > LIKE likeam1 INCLUDING ACCESS METHOD, > LIKE likeam2 INCLUDING ACCESS METHOD > ); > > At the very least, the documentation should say that the last one wins. An error may be annoying once you do an INCLUDING ALL with more than one relation, no? I'd be fine with just documenting that the last one wins. -- Michael
Attachment
On Fri, Aug 27, 2021 at 02:38:43PM +0900, Michael Paquier wrote: > +CREATE ACCESS METHOD heapdup TYPE TABLE HANDLER heap_tableam_handler; > +CREATE TABLE likeam() USING heapdup; > +CREATE TABLE likeamlike(LIKE likeam INCLUDING ALL); > Rather than creating a custom AM in this test path, I would be > tempted to move that to create_am.sql. + /* ACCESS METHOD doesn't apply and isn't copied for partitioned tables */ + if ((table_like_clause->options & CREATE_TABLE_LIKE_ACCESS_METHOD) != 0 && + !cxt->ispartitioned) + cxt->accessMethod = get_am_name(relation->rd_rel->relam); If the new table is partitioned, this would work. Now I think that we should also add here a (relation->rd_rel->relkind == RELKIND_RELATION) to make sure that we only copy an access method if the original relation is a table. Note that the original relation could be as well a view, a foreign table or a composite type. @@ -349,6 +351,9 @@ transformCreateStmt(CreateStmt *stmt, const char *queryString) [...] + if (cxt.accessMethod != NULL) + stmt->accessMethod = cxt.accessMethod; This bit is something I have been chewing on a bit. It means that if we find out an AM to copy from any of the LIKE clauses, we would blindly overwrite the AM defined in an existing CreateStmt. We could also argue in favor of keeping the original AM defined by USING from the query rather than having an error. This means to check that stmt->accessMethod is overwritten only if NULL at this point. Anyway, the patch is wrong with this implementation. This makes me actually wonder if this patch is really a good idea at the end. The interactions with USING and LIKE would be confusing to the end-user one way or the other. The argument of upthread regarding INCLUDING ALL or INCLUDING ACCESS METHOD with multiple original relations also goes in this sense. If we want to move forward here, I think that we should really be careful and have a clear definition behind all those corner cases. The patch fails this point for now. -- Michael
Attachment
On 27.08.21 12:37, Vik Fearing wrote: > It seems like this should error to me: > > CREATE ACCESS METHOD heapdup TYPE TABLE HANDLER heap_tableam_handler; > CREATE TABLE likeam1() USING heap; > CREATE TABLE likeam2() USING heapdup; > CREATE TABLE likeamlike( > LIKE likeam1 INCLUDING ACCESS METHOD, > LIKE likeam2 INCLUDING ACCESS METHOD > ); > > At the very least, the documentation should say that the last one wins. Hmm. The problem is that the LIKE clause is really a macro that expands to the column definitions of the other table. So there is, so far, no such as thing as two LIKE clauses contradicting. Whereas the access method is a table property. So I don't think this syntax is the right approach for this feature. You might think about something like CREATE TABLE t2 (...) USING (LIKE t1); At least in terms of how the syntax should be structured.
On Thu, Sep 09, 2021 at 02:30:51PM +0200, Peter Eisentraut wrote: > Hmm. The problem is that the LIKE clause is really a macro that expands to > the column definitions of the other table. So there is, so far, no such as > thing as two LIKE clauses contradicting. Whereas the access method is a > table property. So I don't think this syntax is the right approach for this > feature. > > You might think about something like > > CREATE TABLE t2 (...) USING (LIKE t1); > > At least in terms of how the syntax should be structured. Good point. I have marked the patch as RwF. -- Michael