@@ -525,9 +525,12 @@ transientrel_destroy(DestReceiver *self)
525
525
/*
526
526
* Given a qualified temporary table name, append an underscore followed by
527
527
* the given integer, to make a new table name based on the old one.
528
+ * The result is a palloc'd string.
528
529
*
529
- * This leaks memory through palloc(), which won't be cleaned up until the
530
- * current memory context is freed.
530
+ * As coded, this would fail to make a valid SQL name if the given name were,
531
+ * say, "FOO"."BAR". Currently, the table name portion of the input will
532
+ * never be double-quoted because it's of the form "pg_temp_NNN", cf
533
+ * make_new_heap(). But we might have to work harder someday.
531
534
*/
532
535
static char *
533
536
make_temptable_name_n (char * tempname , int n )
@@ -615,16 +618,20 @@ refresh_by_match_merge(Oid matviewOid, Oid tempOid, Oid relowner,
615
618
* that in a way that allows showing the first duplicated row found. Even
616
619
* after we pass this test, a unique index on the materialized view may
617
620
* find a duplicate key problem.
621
+ *
622
+ * Note: here and below, we use "tablename.*::tablerowtype" as a hack to
623
+ * keep ".*" from being expanded into multiple columns in a SELECT list.
624
+ * Compare ruleutils.c's get_variable().
618
625
*/
619
626
resetStringInfo (& querybuf );
620
627
appendStringInfo (& querybuf ,
621
- "SELECT _$ newdata FROM %s _$ newdata "
622
- "WHERE _$ newdata IS NOT NULL AND EXISTS "
623
- "(SELECT 1 FROM %s _$ newdata2 WHERE _$ newdata2 IS NOT NULL "
624
- "AND _$ newdata2 OPERATOR(pg_catalog.*=) _$ newdata "
625
- "AND _$ newdata2.ctid OPERATOR(pg_catalog.<>) "
626
- "_$ newdata.ctid)" ,
627
- tempname , tempname );
628
+ "SELECT newdata.*::%s FROM %s newdata "
629
+ "WHERE newdata.* IS NOT NULL AND EXISTS "
630
+ "(SELECT 1 FROM %s newdata2 WHERE newdata2.* IS NOT NULL "
631
+ "AND newdata2.* OPERATOR(pg_catalog.*=) newdata.* "
632
+ "AND newdata2.ctid OPERATOR(pg_catalog.<>) "
633
+ "newdata.ctid)" ,
634
+ tempname , tempname , tempname );
628
635
if (SPI_execute (querybuf .data , false, 1 ) != SPI_OK_SELECT )
629
636
elog (ERROR , "SPI_exec failed: %s" , querybuf .data );
630
637
if (SPI_processed > 0 )
@@ -651,9 +658,9 @@ refresh_by_match_merge(Oid matviewOid, Oid tempOid, Oid relowner,
651
658
resetStringInfo (& querybuf );
652
659
appendStringInfo (& querybuf ,
653
660
"CREATE TEMP TABLE %s AS "
654
- "SELECT _$ mv.ctid AS tid, _$ newdata "
655
- "FROM %s _$ mv FULL JOIN %s _$ newdata ON (" ,
656
- diffname , matviewname , tempname );
661
+ "SELECT mv.ctid AS tid, newdata.*::%s AS newdata "
662
+ "FROM %s mv FULL JOIN %s newdata ON (" ,
663
+ diffname , tempname , matviewname , tempname );
657
664
658
665
/*
659
666
* Get the list of index OIDs for the table from the relcache, and look up
@@ -745,9 +752,9 @@ refresh_by_match_merge(Oid matviewOid, Oid tempOid, Oid relowner,
745
752
if (foundUniqueIndex )
746
753
appendStringInfoString (& querybuf , " AND " );
747
754
748
- leftop = quote_qualified_identifier ("_$ newdata" ,
755
+ leftop = quote_qualified_identifier ("newdata" ,
749
756
NameStr (attr -> attname ));
750
- rightop = quote_qualified_identifier ("_$ mv" ,
757
+ rightop = quote_qualified_identifier ("mv" ,
751
758
NameStr (attr -> attname ));
752
759
753
760
generate_operator_clause (& querybuf ,
@@ -775,8 +782,8 @@ refresh_by_match_merge(Oid matviewOid, Oid tempOid, Oid relowner,
775
782
Assert (foundUniqueIndex );
776
783
777
784
appendStringInfoString (& querybuf ,
778
- " AND _$ newdata OPERATOR(pg_catalog.*=) _$mv ) "
779
- "WHERE _$ newdata IS NULL OR _$mv IS NULL "
785
+ " AND newdata.* OPERATOR(pg_catalog.*=) mv.* ) "
786
+ "WHERE newdata.* IS NULL OR mv.* IS NULL "
780
787
"ORDER BY tid" );
781
788
782
789
/* Create the temporary "diff" table. */
@@ -802,19 +809,19 @@ refresh_by_match_merge(Oid matviewOid, Oid tempOid, Oid relowner,
802
809
/* Deletes must come before inserts; do them first. */
803
810
resetStringInfo (& querybuf );
804
811
appendStringInfo (& querybuf ,
805
- "DELETE FROM %s _$ mv WHERE ctid OPERATOR(pg_catalog.=) ANY "
806
- "(SELECT _$ diff.tid FROM %s _$ diff "
807
- "WHERE _$ diff.tid IS NOT NULL "
808
- "AND _$ diff._$ newdata IS NULL)" ,
812
+ "DELETE FROM %s mv WHERE ctid OPERATOR(pg_catalog.=) ANY "
813
+ "(SELECT diff.tid FROM %s diff "
814
+ "WHERE diff.tid IS NOT NULL "
815
+ "AND diff.newdata IS NULL)" ,
809
816
matviewname , diffname );
810
817
if (SPI_exec (querybuf .data , 0 ) != SPI_OK_DELETE )
811
818
elog (ERROR , "SPI_exec failed: %s" , querybuf .data );
812
819
813
820
/* Inserts go last. */
814
821
resetStringInfo (& querybuf );
815
822
appendStringInfo (& querybuf ,
816
- "INSERT INTO %s SELECT (_$ diff._$ newdata).* "
817
- "FROM %s _$ diff WHERE tid IS NULL" ,
823
+ "INSERT INTO %s SELECT (diff.newdata).* "
824
+ "FROM %s diff WHERE tid IS NULL" ,
818
825
matviewname , diffname );
819
826
if (SPI_exec (querybuf .data , 0 ) != SPI_OK_INSERT )
820
827
elog (ERROR , "SPI_exec failed: %s" , querybuf .data );
0 commit comments