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