Skip to content

Commit

Permalink
[FEATURE] [mssql] Save styles to the database in MSSQL
Browse files Browse the repository at this point in the history
Adding the functions to save styles in an mssql database.
Creates tables, etc to support default and listing styles.
  • Loading branch information
frugardc authored and NathanW2 committed Jun 1, 2016
1 parent d47fe0f commit 36714d5
Show file tree
Hide file tree
Showing 3 changed files with 352 additions and 1 deletion.
344 changes: 344 additions & 0 deletions src/providers/mssql/qgsmssqlprovider.cpp
Expand Up @@ -475,6 +475,32 @@ void QgsMssqlProvider::loadFields()
}
}

QString QgsMssqlProvider::quotedValue( const QVariant& value )
{
if ( value.isNull() )
return "NULL";

switch ( value.type() )
{
case QVariant::Int:
case QVariant::LongLong:
case QVariant::Double:
return value.toString();

case QVariant::Bool:
return value.toBool() ? "1" : "0";

default:
case QVariant::String:
QString v = value.toString();
v.replace( '\'', "''" );
if ( v.contains( '\\' ) )
return v.replace( '\\', "\\\\" ).prepend( "N'" ).append( '\'' );
else
return v.prepend( '\'' ).append( '\'' );
}
}

QVariant QgsMssqlProvider::defaultValue( int fieldId )
{
if ( mDefaultValues.contains( fieldId ) )
Expand Down Expand Up @@ -1934,3 +1960,321 @@ QGISEXTERN QgsVectorLayerImport::ImportError createEmptyLayer(
oldToNewAttrIdxMap, errorMessage, options
);
}
QGISEXTERN bool saveStyle( const QString& uri, const QString& qmlStyle, const QString& sldStyle,
const QString& styleName, const QString& styleDescription,
const QString& uiFileContent, bool useAsDefault, QString& errCause )
{
QgsDataSourceURI dsUri( uri );
// connect to database
QSqlDatabase mDatabase = QgsMssqlProvider::GetDatabase( dsUri.service(), dsUri.host(), dsUri.database(), dsUri.username(), dsUri.password() );

if ( !QgsMssqlProvider::OpenDatabase( mDatabase ) )
{
QgsDebugMsg( "Error connecting to database" );
QgsDebugMsg( mDatabase.lastError().text() );
return false;
}

QSqlQuery query = QSqlQuery( mDatabase );
query.setForwardOnly( true );
if ( !query.exec( QString( "SELECT COUNT(*) FROM information_schema.tables WHERE table_name= N'layer_styles'" ) ) )
{
QString msg = query.lastError().text();
QgsDebugMsg( msg );
return false;
}
if ( query.isActive() && query.next() && query.value( 0 ).toInt() == 0 )
{
QgsDebugMsg( "Need to create styles table" );
bool execOk = query.exec( QString( "CREATE TABLE [dbo].[layer_styles]("
"[id] int IDENTITY(1,1) PRIMARY KEY,"
"[f_table_catalog] [varchar](1024) NULL,"
"[f_table_schema] [varchar](1024) NULL,"
"[f_table_name] [varchar](1024) NULL,"
"[f_geometry_column] [varchar](1024) NULL,"
"[styleName] [varchar](1024) NULL,"
"[styleQML] [text] NULL,"
"[styleSLD] [text] NULL,"
"[useAsDefault] [int] NULL,"
"[description] [text] NULL,"
"[owner] [varchar](1024) NULL,"
"[ui] [text] NULL,"
"[update_time] [datetime] NULL"
") ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]" ));
if ( !execOk )
{
errCause = QObject::tr( "Unable to save layer style. It's not possible to create the destination table on the database. Maybe this is due to table permissions. Please contact your database admin" );
return false;
}
query.finish();
query.clear();
}

QString uiFileColumn;
QString uiFileValue;
if ( !uiFileContent.isEmpty() )
{
uiFileColumn = ",ui";
uiFileValue = QString( ",XMLPARSE(DOCUMENT %1)" ).arg( uiFileContent );
}
QgsDebugMsg( "Ready to insert new style" );
// Note: in the construction of the INSERT and UPDATE strings the qmlStyle and sldStyle values
// can contain user entered strings, which may themselves include %## values that would be
// replaced by the QString.arg function. To ensure that the final SQL string is not corrupt these
// two values are both replaced in the final .arg call of the string construction.

QString sql = QString( "INSERT INTO layer_styles"
"(f_table_catalog,f_table_schema,f_table_name,f_geometry_column,styleName,styleQML,styleSLD,useAsDefault,description,owner%11"
") VALUES ("
"%1,%2,%3,%4,%5,%6,%7,%8,%9,%10%12"
")" )
.arg( QgsMssqlProvider::quotedValue( dsUri.database() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.schema() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.table() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.geometryColumn() ) )
.arg( QgsMssqlProvider::quotedValue( styleName.isEmpty() ? dsUri.table() : styleName ) )
.arg( QgsMssqlProvider::quotedValue( qmlStyle ) )
.arg( QgsMssqlProvider::quotedValue( sldStyle ) )
.arg( useAsDefault ? "1" : "0" )
.arg( QgsMssqlProvider::quotedValue( styleDescription.isEmpty() ? QDateTime::currentDateTime().toString() : styleDescription ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.username() ) )
.arg( uiFileColumn )
.arg( uiFileValue );

QString checkQuery = QString( "SELECT styleName"
" FROM layer_styles"
" WHERE f_table_catalog=%1"
" AND f_table_schema=%2"
" AND f_table_name=%3"
" AND f_geometry_column=%4"
" AND styleName=%5" )
.arg( QgsMssqlProvider::quotedValue(dsUri.database() ) )
.arg( QgsMssqlProvider::quotedValue(dsUri.schema() ) )
.arg( QgsMssqlProvider::quotedValue(dsUri.table() ) )
.arg( QgsMssqlProvider::quotedValue(dsUri.geometryColumn() ) )
.arg( QgsMssqlProvider::quotedValue(styleName.isEmpty() ? dsUri.table() : styleName ) );

if ( !query.exec( checkQuery ) )
{
QgsDebugMsg( query.lastError().text() );
QgsDebugMsg("Check Query failed");
return false;
}
if ( query.isActive() && query.next() && query.value( 0 ).toString() == styleName )
{
if ( QMessageBox::question( nullptr, QObject::tr( "Save style in database" ),
QObject::tr( "A style named \"%1\" already exists in the database for this layer. Do you want to overwrite it?" )
.arg( styleName.isEmpty() ? dsUri.table() : styleName ),
QMessageBox::Yes | QMessageBox::No ) == QMessageBox::No )
{
errCause = QObject::tr( "Operation aborted. No changes were made in the database" );
QgsDebugMsg("User selected not to overwrite styles");
return false;
}

QgsDebugMsg("Updating styles");
sql = QString( "UPDATE layer_styles "
" SET useAsDefault=%1"
",styleQML=%2"
",styleSLD=%3"
",description=%4"
",owner=%5"
" WHERE f_table_catalog=%6"
" AND f_table_schema=%7"
" AND f_table_name=%8"
" AND f_geometry_column=%9"
" AND styleName=%10" )
.arg( useAsDefault ? "1" : "0" )
.arg( QgsMssqlProvider::quotedValue( qmlStyle ) )
.arg( QgsMssqlProvider::quotedValue( sldStyle ) )
.arg( QgsMssqlProvider::quotedValue( styleDescription.isEmpty() ? QDateTime::currentDateTime().toString() : styleDescription ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.username() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.database() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.schema() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.table() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.geometryColumn() ) )
.arg( QgsMssqlProvider::quotedValue( styleName.isEmpty() ? dsUri.table() : styleName ) );
}
if ( useAsDefault )
{
QString removeDefaultSql = QString( "UPDATE layer_styles "
" SET useAsDefault=0"
" WHERE f_table_catalog=%1"
" AND f_table_schema=%2"
" AND f_table_name=%3"
" AND f_geometry_column=%4" )
.arg( QgsMssqlProvider::quotedValue( dsUri.database() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.schema() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.table() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.geometryColumn() ) );
sql = QString( "%1; %2;" ).arg( removeDefaultSql, sql );
}

QgsDebugMsg("Inserting styles");
QgsDebugMsg(sql);
bool execOk = query.exec( sql );

if ( !execOk )
{
errCause = QObject::tr( "Unable to save layer style. It's not possible to insert a new record into the style table. Maybe this is due to table permissions. Please contact your database administrator." );
}
return execOk;
}


QGISEXTERN QString loadStyle( const QString& uri, QString& errCause )
{
QString style;
QgsDataSourceURI dsUri( uri );
// connect to database
QSqlDatabase mDatabase = QgsMssqlProvider::GetDatabase( dsUri.service(), dsUri.host(), dsUri.database(), dsUri.username(), dsUri.password() );

if ( !QgsMssqlProvider::OpenDatabase( mDatabase ) )
{
QgsDebugMsg( "Error connecting to database" );
QgsDebugMsg( mDatabase.lastError().text() );
return QString();
}

QSqlQuery query = QSqlQuery( mDatabase );
query.setForwardOnly( true );

QString selectQmlQuery = QString( "SELECT top 1 styleQML"
" FROM layer_styles"
" WHERE f_table_catalog=%1"
" AND f_table_schema=%2"
" AND f_table_name=%3"
" AND f_geometry_column=%4"
" ORDER BY useAsDefault desc" )
.arg( QgsMssqlProvider::quotedValue( dsUri.database() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.schema() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.table() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.geometryColumn() ) );

if ( !query.exec( selectQmlQuery ) )
{
QgsDebugMsg( query.lastError().text() );
QgsDebugMsg("Load of Style failed");
return QString();
}
if ( query.isActive() && query.next())
{
QString style = query.value( 0 ).toString();
return style;
}
return QString();
}

QGISEXTERN int listStyles( const QString &uri, QStringList &ids, QStringList &names,
QStringList &descriptions, QString& errCause )
{
QgsDataSourceURI dsUri( uri );
// connect to database
QSqlDatabase mDatabase = QgsMssqlProvider::GetDatabase( dsUri.service(), dsUri.host(), dsUri.database(), dsUri.username(), dsUri.password() );

if ( !QgsMssqlProvider::OpenDatabase( mDatabase ) )
{
QgsDebugMsg( "Error connecting to database" );
QgsDebugMsg( mDatabase.lastError().text() );
return -1;
}

QSqlQuery query = QSqlQuery( mDatabase );
query.setForwardOnly( true );

// check if layer_styles table already exist
if ( !query.exec( QString( "SELECT COUNT(*) FROM information_schema.tables WHERE table_name= N'layer_styles'" ) ) )
{
QString msg = query.lastError().text();
errCause = msg;
QgsDebugMsg( msg );
return -1;
}
if ( query.isActive() && query.next() && query.value( 0 ).toInt() == 0 )
{
QgsDebugMsg( QObject::tr( "No styles available on DB, or there is an error connecting to the database." ) );
return -1;
}

QString selectRelatedQuery = QString( "SELECT id,styleName,description"
" FROM layer_styles "
" WHERE f_table_catalog=%1"
" AND f_table_schema=%2"
" AND f_table_name=%3"
" AND f_geometry_column=%4" )
.arg( QgsMssqlProvider::quotedValue( dsUri.database() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.schema() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.table() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.geometryColumn() ) );
bool queryOk = query.exec(selectRelatedQuery);
if(!queryOk)
{
QgsDebugMsg( query.lastError().text() );
return -1;
}
int numberOfRelatedStyles = 0;
while( query.isActive() && query.next())
{
QgsDebugMsg(query.value(1).toString());
ids.append( query.value(0).toString() );
names.append( query.value(1).toString() );
descriptions.append( query.value(2).toString() );
numberOfRelatedStyles = numberOfRelatedStyles + 1;
}
QString selectOthersQuery = QString( "SELECT id,styleName,description"
" FROM layer_styles "
" WHERE NOT (f_table_catalog=%1 AND f_table_schema=%2 AND f_table_name=%3 AND f_geometry_column=%4)"
" ORDER BY update_time DESC" )
.arg( QgsMssqlProvider::quotedValue( dsUri.database() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.schema() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.table() ) )
.arg( QgsMssqlProvider::quotedValue( dsUri.geometryColumn() ) );
QgsDebugMsg(selectOthersQuery);
queryOk = query.exec(selectOthersQuery);
if(!queryOk)
{
QString msg = query.lastError().text();
QgsDebugMsg( msg );
return -1;
}
QgsDebugMsg(query.isActive() && query.size());
while(query.next())
{
ids.append( query.value(0).toString() );
names.append( query.value(1).toString() );
descriptions.append( query.value(2).toString() );
}
return numberOfRelatedStyles;
}
QGISEXTERN QString getStyleById( const QString& uri, QString styleId, QString& errCause )
{
QgsDataSourceURI dsUri( uri );
// connect to database
QSqlDatabase mDatabase = QgsMssqlProvider::GetDatabase( dsUri.service(), dsUri.host(), dsUri.database(), dsUri.username(), dsUri.password() );

if ( !QgsMssqlProvider::OpenDatabase( mDatabase ) )
{
QgsDebugMsg( "Error connecting to database" );
QgsDebugMsg( mDatabase.lastError().text() );
return QString();
}

QSqlQuery query = QSqlQuery( mDatabase );
query.setForwardOnly( true );

QString style = "";
QString selectQmlQuery = QString( "SELECT styleQml FROM layer_styles WHERE id=%1" ).arg( QgsMssqlProvider::quotedValue( styleId ) );
bool queryOk = query.exec(selectQmlQuery);
if(!queryOk)
{
QString msg = query.lastError().text();
QgsDebugMsg( msg );
errCause = query.lastError().text();
return QString( );
}
while(query.next())
{
style = query.value(0).toString();
}
return style;
}
8 changes: 8 additions & 0 deletions src/providers/mssql/qgsmssqlprovider.h
Expand Up @@ -186,6 +186,11 @@ class QgsMssqlProvider : public QgsVectorDataProvider
*/
bool isValid() override;

/**
* It returns true. Saving style to db is supported by this provider
*/
virtual bool isSaveAndLoadStyleToDBSupported() override { return true; }

/** Writes a list of features to the database*/
virtual bool addFeatures( QgsFeatureList & flist ) override;

Expand Down Expand Up @@ -223,6 +228,9 @@ class QgsMssqlProvider : public QgsVectorDataProvider
/** Convert a QgsField to work with MSSQL */
static bool convertField( QgsField &field );

/** Convert values to quoted values for database work **/
static QString quotedValue( const QVariant& value );

/** Returns the default value for field specified by @c fieldId */
QVariant defaultValue( int fieldId ) override;

Expand Down
1 change: 0 additions & 1 deletion src/providers/postgres/qgspostgresprovider.h
Expand Up @@ -175,7 +175,6 @@ class QgsPostgresProvider : public QgsVectorDataProvider
*/
bool isValid() override;


/**
* It returns true. Saving style to db is supported by this provider
*/
Expand Down

0 comments on commit 36714d5

Please sign in to comment.