Skip to content

Commit 09f410c

Browse files
manisandrojef-n
authored andcommitted
Greatly decrease the number of round-trips to the postgres server performed when reading and creating fields in the postgres provider
1 parent 914ecc9 commit 09f410c

File tree

2 files changed

+84
-41
lines changed

2 files changed

+84
-41
lines changed

src/providers/postgres/qgspostgresprovider.cpp

Lines changed: 76 additions & 41 deletions
Original file line numberDiff line numberDiff line change
@@ -658,8 +658,64 @@ bool QgsPostgresProvider::loadFields()
658658

659659
QSet<QString> fields;
660660

661-
// The queries inside this loop could possibly be combined into one
662-
// single query - this would make the code run faster.
661+
/* Collect type info */
662+
sql = "SELECT oid, typname,typtype,typelem,typlen FROM pg_type";
663+
QgsPostgresResult typeResult = connectionRO()->PQexec( sql );
664+
QMap<int, PGTypeInfo> typeMap;
665+
for ( int i = 0; i < typeResult.PQntuples(); ++i )
666+
{
667+
PGTypeInfo typeInfo =
668+
{
669+
/*typeName = */ typeResult.PQgetvalue( i, 1 ),
670+
/*typeType = */ typeResult.PQgetvalue( i, 2 ),
671+
/*typeElem = */ typeResult.PQgetvalue( i, 3 ),
672+
/*typeLen = */ typeResult.PQgetvalue( i, 4 ).toInt()
673+
};
674+
typeMap.insert( typeResult.PQgetvalue( i, 0 ).toInt(), typeInfo );
675+
}
676+
677+
/* Collect table oids */
678+
QSet<int> tableoids;
679+
for ( int i = 0; i < result.PQnfields(); i++ )
680+
{
681+
int tableoid = result.PQftable( i );
682+
if ( tableoid > 0 )
683+
{
684+
tableoids.insert( tableoid );
685+
}
686+
}
687+
QStringList tableoidsList;
688+
foreach ( int tableoid, tableoids )
689+
{
690+
tableoidsList.append( QString::number( tableoid ) );
691+
}
692+
693+
QString tableoidsFilter = "(" + tableoidsList.join( "," ) + ")";
694+
695+
/* Collect formatted field types */
696+
sql = "SELECT attrelid, attnum, pg_catalog.format_type(atttypid,atttypmod) FROM pg_attribute WHERE attrelid IN " + tableoidsFilter;
697+
QgsPostgresResult fmtFieldTypeResult = connectionRO()->PQexec( sql );
698+
QMap<int, QMap<int, QString> > fmtFieldTypeMap;
699+
for ( int i = 0; i < fmtFieldTypeResult.PQntuples(); ++i )
700+
{
701+
int attrelid = fmtFieldTypeResult.PQgetvalue( i, 0 ).toInt();
702+
int attnum = fmtFieldTypeResult.PQgetvalue( i, 1 ).toInt();
703+
QString formatType = fmtFieldTypeResult.PQgetvalue( i, 2 );
704+
fmtFieldTypeMap[attrelid][attnum] = formatType;
705+
}
706+
707+
/* Collect descriptions */
708+
sql = "SELECT objoid, objsubid, description FROM pg_description WHERE objoid IN " + tableoidsFilter;
709+
QgsPostgresResult descrResult = connectionRO()->PQexec( sql );
710+
QMap<int, QMap<int, QString> > descrMap;
711+
for ( int i = 0; i < descrResult.PQntuples(); ++i )
712+
{
713+
int objoid = descrResult.PQgetvalue( i, 0 ).toInt();
714+
int objsubid = descrResult.PQgetvalue( i, 1 ).toInt();
715+
QString descr = descrResult.PQgetvalue( i, 2 );
716+
descrMap[objoid][objsubid] = descr;
717+
}
718+
663719
mAttributeFields.clear();
664720
for ( int i = 0; i < result.PQnfields(); i++ )
665721
{
@@ -668,40 +724,17 @@ bool QgsPostgresProvider::loadFields()
668724
continue;
669725

670726
int fldtyp = result.PQftype( i );
671-
QString typOid = QString().setNum( fldtyp );
672727
int fieldPrec = -1;
673-
QString fieldComment( "" );
674728
int tableoid = result.PQftable( i );
675729
int attnum = result.PQftablecol( i );
676730

677-
sql = QString( "SELECT typname,typtype,typelem,typlen FROM pg_type WHERE oid=%1" ).arg( typOid );
678-
// just oid; needs more work to support array type
679-
// "oid = (SELECT Distinct typelem FROM pg_type WHERE " //needs DISTINCT to guard against 2 or more rows on int2
680-
// "typelem = " + typOid + " AND typlen = -1)";
681-
682-
QgsPostgresResult oidResult = connectionRO()->PQexec( sql );
683-
QString fieldTypeName = oidResult.PQgetvalue( 0, 0 );
684-
QString fieldTType = oidResult.PQgetvalue( 0, 1 );
685-
QString fieldElem = oidResult.PQgetvalue( 0, 2 );
686-
int fieldSize = oidResult.PQgetvalue( 0, 3 ).toInt();
687-
688-
QString formattedFieldType;
689-
if ( tableoid > 0 )
690-
{
691-
sql = QString( "SELECT pg_catalog.format_type(atttypid,atttypmod) FROM pg_attribute WHERE attrelid=%1 AND attnum=%2" )
692-
.arg( tableoid ).arg( quotedValue( attnum ) );
693-
694-
QgsPostgresResult tresult = connectionRO()->PQexec( sql );
695-
if ( tresult.PQntuples() > 0 )
696-
formattedFieldType = tresult.PQgetvalue( 0, 0 );
697-
698-
sql = QString( "SELECT description FROM pg_description WHERE objoid=%1 AND objsubid=%2" )
699-
.arg( tableoid ).arg( attnum );
731+
const PGTypeInfo& typeInfo = typeMap.value( fldtyp );
732+
QString fieldTypeName = typeInfo.typeName;
733+
QString fieldTType = typeInfo.typeType;
734+
int fieldSize = typeInfo.typeLen;
700735

701-
tresult = connectionRO()->PQexec( sql );
702-
if ( tresult.PQntuples() > 0 )
703-
fieldComment = tresult.PQgetvalue( 0, 0 );
704-
}
736+
QString formattedFieldType = fmtFieldTypeMap[tableoid][attnum];
737+
QString fieldComment = descrMap[tableoid][attnum];
705738

706739
QVariant::Type fieldType;
707740

@@ -1919,6 +1952,7 @@ bool QgsPostgresProvider::addAttributes( const QList<QgsField> &attributes )
19191952
{
19201953
conn->begin();
19211954

1955+
QString sql = QString( "ALTER TABLE %1 " ).arg( mQuery );
19221956
for ( QList<QgsField>::const_iterator iter = attributes.begin(); iter != attributes.end(); ++iter )
19231957
{
19241958
QString type = iter->typeName();
@@ -1932,18 +1966,19 @@ bool QgsPostgresProvider::addAttributes( const QList<QgsField> &attributes )
19321966
if ( iter->length() > 0 && iter->precision() >= 0 )
19331967
type = QString( "%1(%2,%3)" ).arg( type ).arg( iter->length() ).arg( iter->precision() );
19341968
}
1969+
sql.append( QString( "ADD COLUMN %1 %2, " ).arg( quotedIdentifier( iter->name() ) ).arg( type ) );
1970+
}
1971+
sql.chop( 2 ); /* ", " */
1972+
sql.append( ";" );
1973+
QgsDebugMsg( sql );
19351974

1936-
QString sql = QString( "ALTER TABLE %1 ADD COLUMN %2 %3" )
1937-
.arg( mQuery )
1938-
.arg( quotedIdentifier( iter->name() ) )
1939-
.arg( type );
1940-
QgsDebugMsg( sql );
1941-
1942-
//send sql statement and do error handling
1943-
QgsPostgresResult result = conn->PQexec( sql );
1944-
if ( result.PQresultStatus() != PGRES_COMMAND_OK )
1945-
throw PGException( result );
1975+
//send sql statement and do error handling
1976+
QgsPostgresResult result = conn->PQexec( sql );
1977+
if ( result.PQresultStatus() != PGRES_COMMAND_OK )
1978+
throw PGException( result );
19461979

1980+
for ( QList<QgsField>::const_iterator iter = attributes.begin(); iter != attributes.end(); ++iter )
1981+
{
19471982
if ( !iter->comment().isEmpty() )
19481983
{
19491984
sql = QString( "COMMENT ON COLUMN %1.%2 IS %3" )

src/providers/postgres/qgspostgresprovider.h

Lines changed: 8 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -455,6 +455,14 @@ class QgsPostgresProvider : public QgsVectorDataProvider
455455
QString mWhat;
456456
};
457457

458+
struct PGTypeInfo
459+
{
460+
QString typeName;
461+
QString typeType;
462+
QString typeElem;
463+
int typeLen;
464+
};
465+
458466
// A function that determines if the given schema.table.column
459467
// contains unqiue entries
460468
bool uniqueData( QString query, QString colName );

0 commit comments

Comments
 (0)