From d3e65089525b883137be5efae1694938017b8f79 Mon Sep 17 00:00:00 2001 From: Dirk Seefeld Date: Mon, 15 Sep 2025 12:25:11 +0200 Subject: [PATCH] Repositories: Introduce and use NPoco and custom extension methods for SQL syntax in ContentTypeRepositoryBase (#19986) * fix Umbraco.Cms.Infrastructure.Persistence.Repositories.Implement .ContentTypeRepositoryBase.DeletePropertyType method. * fix more sql syntax * fix review comments * Fixed issues raised in code review. --------- Co-authored-by: Andy Butland --- .../Persistence/NPocoSqlExtensions.cs | 95 ++++- .../Implement/ContentTypeRepositoryBase.cs | 337 +++++++++++------- .../SqlSyntax/ISqlSyntaxProvider.cs | 7 + .../SqlSyntax/SqlSyntaxProviderBase.cs | 17 +- .../ContentTypeRepositorySqlClausesTest.cs | 33 ++ 5 files changed, 336 insertions(+), 153 deletions(-) diff --git a/src/Umbraco.Infrastructure/Persistence/NPocoSqlExtensions.cs b/src/Umbraco.Infrastructure/Persistence/NPocoSqlExtensions.cs index d2c7aa87ff..71880c95dc 100644 --- a/src/Umbraco.Infrastructure/Persistence/NPocoSqlExtensions.cs +++ b/src/Umbraco.Infrastructure/Persistence/NPocoSqlExtensions.cs @@ -29,6 +29,20 @@ namespace Umbraco.Extensions return sql.Where(s, a); } + /// + /// Adds a WHERE clause to the SQL query based on the specified predicate and optional alias, and appends a + /// closing parenthesis to the query. This is used for selects within "WHERE [column] IN (SELECT ...)" statements. + /// + /// The type of the data transfer object (DTO) used to define the predicate. + /// The SQL query to which the WHERE clause will be added. + /// An expression that defines the condition for the WHERE clause. + /// An optional alias to qualify the table or entity in the query. If null, no alias is used. + /// The modified SQL query with the appended WHERE clause and closing parenthesis. + public static Sql WhereClosure(this Sql sql, Expression> predicate, string? alias = null) + { + return sql.Where(predicate, alias).Append(")"); + } + /// /// Appends a WHERE clause to the Sql statement. /// @@ -74,7 +88,7 @@ namespace Umbraco.Extensions public static Sql WhereIn(this Sql sql, Expression> field, IEnumerable? values) { var fieldName = sql.SqlContext.SqlSyntax.GetFieldName(field); - sql.Where(fieldName + " IN (@values)", new { values }); + sql.Where($"{fieldName} IN (@values)", new { values }); return sql; } @@ -112,29 +126,41 @@ namespace Umbraco.Extensions return sql.WhereIn(field, values, false, tableAlias); } - - public static Sql WhereLike(this Sql sql, Expression> fieldSelector, Sql? valuesSql) + /// + /// This builds a WHERE clause with a LIKE statement where the value is built from a subquery. + /// E.g. for SQL Server: WHERE [field] LIKE CONCAT((SELECT [value] FROM ...), '%'). + /// Or SQLite : WHERE [field] LIKE ((SELECT [value] FROM ...) || '%'). + /// + /// The type of the Dto. + /// The Sql statement. + /// An expression specifying the field. + /// The sql object to select the values. + /// If ommitted or empty the specific wildcard char is used as suffix for the resulting values from valueSql query. + /// + public static Sql WhereLike(this Sql sql, Expression> fieldSelector, Sql? valuesSql, string concatDefault = "") { var fieldName = sql.SqlContext.SqlSyntax.GetFieldName(fieldSelector); - sql.Where(fieldName + " LIKE (" + valuesSql?.SQL + ")", valuesSql?.Arguments); + var concat = sql.SqlContext.SqlSyntax.GetWildcardConcat(concatDefault); + var likeSelect = sql.SqlContext.SqlSyntax.GetConcat(valuesSql?.SQL ?? string.Empty, concat); + sql.Where($"{fieldName} LIKE {likeSelect}", valuesSql?.Arguments); return sql; } public static Sql Union(this Sql sql, Sql sql2) { - return sql.Append( " UNION ").Append(sql2); + return sql.Append(" UNION ").Append(sql2); } public static Sql.SqlJoinClause InnerJoinNested(this Sql sql, Sql nestedQuery, string alias) { return new Sql.SqlJoinClause(sql.Append("INNER JOIN (").Append(nestedQuery) - .Append($") [{alias}]")); + .Append($") {sql.SqlContext.SqlSyntax.GetQuotedName(alias)}")); } public static Sql WhereLike(this Sql sql, Expression> fieldSelector, string likeValue) { var fieldName = sql.SqlContext.SqlSyntax.GetFieldName(fieldSelector); - sql.Where(fieldName + " LIKE ('" + likeValue + "')"); + sql.Where($"{fieldName} LIKE ('{likeValue}')"); return sql; } @@ -162,9 +188,7 @@ namespace Umbraco.Extensions /// A subquery returning the value. /// The Sql statement. public static Sql WhereNotIn(this Sql sql, Expression> field, Sql values) - { - return sql.WhereIn(field, values, true); - } + => sql.WhereIn(field, values, true); /// /// Appends multiple OR WHERE IN clauses to the Sql statement. @@ -258,8 +282,8 @@ namespace Umbraco.Extensions /// The Sql statement. public static Sql WhereNull(this Sql sql, Expression> field, string? tableAlias = null, bool not = false) { - var column = sql.GetColumns(columnExpressions: new[] { field }, tableAlias: tableAlias, withAlias: false).First(); - return sql.Where("(" + column + " IS " + (not ? "NOT " : string.Empty) + "NULL)"); + var column = sql.GetColumns(columnExpressions: [field], tableAlias: tableAlias, withAlias: false).First(); + return sql.Where($"({column} IS {(not ? "NOT " : string.Empty)}NULL)"); } #endregion @@ -275,7 +299,7 @@ namespace Umbraco.Extensions /// The Sql statement. public static Sql From(this Sql sql, string? alias = null) { - Type type = typeof (TDto); + Type type = typeof(TDto); var tableName = type.GetTableName(); var from = sql.SqlContext.SqlSyntax.GetQuotedTableName(tableName); @@ -738,7 +762,7 @@ namespace Umbraco.Extensions var text = "COUNT (" + string.Join(", ", columns) + ")"; if (alias != null) { - text += " AS " + sql.SqlContext.SqlSyntax.GetQuotedColumnName(alias); + text += " AS " + sqlSyntax.GetQuotedColumnName(alias); } return sql.Select(text); @@ -1096,7 +1120,7 @@ namespace Umbraco.Extensions private SqlRef Select(PropertyInfo? propertyInfo, string? tableAlias, Func, SqlRef>? nested = null) { - var referenceName = propertyInfo?.Name ?? typeof (TDto).Name; + var referenceName = propertyInfo?.Name ?? typeof(TDto).Name; if (Prefix != null) { referenceName = Prefix + PocoData.Separator + referenceName; @@ -1163,6 +1187,45 @@ namespace Umbraco.Extensions return string.Join(", ", sql.GetColumns(columnExpressions: fields, withAlias: false, tableAlias: alias)); } + /// + /// Adds a SELECT clause to the SQL query based on the specified predicate and optional alias, and prepends an + /// opening parenthesis to the query. This is used for selects within "WHERE [column] IN (SELECT ...)" statements. + /// + /// The modified SQL query with the prepended SELECT clause and opening parenthesis. + public static Sql SelectClosure(this Sql sql, Func, SqlConvert> converts) + { + sql.Append($"(SELECT "); + + var c = new SqlConvert(sql.SqlContext); + c = converts(c); + var first = true; + foreach (string setExpression in c.SetExpressions) + { + sql.Append($"{(first ? string.Empty : ",")} {setExpression}"); + first = false; + } + + if (!first) + { + sql.Append(" "); + } + + return sql; + } + + public class SqlConvert(ISqlContext sqlContext) + { + public List SetExpressions { get; } = []; + + public SqlConvert ConvertUniqueIdentifierToString(Expression> fieldSelector) + { + var fieldName = sqlContext.SqlSyntax.GetFieldNameForUpdate(fieldSelector); + var convertFieldName = string.Format(sqlContext.SqlSyntax.ConvertUniqueIdentifierToString, fieldName); + SetExpressions.Add(convertFieldName); + return this; + } + } + #endregion #region Delete @@ -1308,7 +1371,7 @@ namespace Umbraco.Extensions private static string[] GetColumns(this Sql sql, string? tableAlias = null, string? referenceName = null, Expression>[]? columnExpressions = null, bool withAlias = true, bool forInsert = false) { - PocoData? pd = sql.SqlContext.PocoDataFactory.ForType(typeof (TDto)); + PocoData? pd = sql.SqlContext.PocoDataFactory.ForType(typeof(TDto)); var tableName = tableAlias ?? pd.TableInfo.TableName; var queryColumns = pd.QueryColumns.ToList(); diff --git a/src/Umbraco.Infrastructure/Persistence/Repositories/Implement/ContentTypeRepositoryBase.cs b/src/Umbraco.Infrastructure/Persistence/Repositories/Implement/ContentTypeRepositoryBase.cs index 0b0a964298..befaa6bc3a 100644 --- a/src/Umbraco.Infrastructure/Persistence/Repositories/Implement/ContentTypeRepositoryBase.cs +++ b/src/Umbraco.Infrastructure/Persistence/Repositories/Implement/ContentTypeRepositoryBase.cs @@ -181,28 +181,36 @@ internal abstract class ContentTypeRepositoryBase : EntityRepositoryBas ContentTypeDto dto = ContentTypeFactory.BuildContentTypeDto(entity); // Cannot add a duplicate content type - var exists = Database.ExecuteScalar( - @"SELECT COUNT(*) FROM cmsContentType -INNER JOIN umbracoNode ON cmsContentType.nodeId = umbracoNode.id -WHERE cmsContentType." + SqlSyntax.GetQuotedColumnName("alias") + @"= @alias -AND umbracoNode.nodeObjectType = @objectType", - new { alias = entity.Alias, objectType = NodeObjectTypeId }); + Sql sqlDuplicates = Sql() + .SelectCount() + .From() + .InnerJoin().On(left => left.NodeId, right => right.NodeId) + .Where(x => x.NodeObjectType == NodeObjectTypeId) + .Where(x => x.Alias == entity.Alias); + var exists = Database.ExecuteScalar(sqlDuplicates); if (exists > 0) { throw new DuplicateNameException("An item with the alias " + entity.Alias + " already exists"); } // Logic for setting Path, Level and SortOrder - NodeDto? parent = Database.First("WHERE id = @ParentId", new { entity.ParentId }); - var level = parent.Level + 1; - var sortOrder = - Database.ExecuteScalar( - "SELECT COUNT(*) FROM umbracoNode WHERE parentID = @ParentId AND nodeObjectType = @NodeObjectType", - new { entity.ParentId, NodeObjectType = NodeObjectTypeId }); + Sql sqlParent = Sql() + .SelectAll() + .From() + .Where(x => x.NodeId == entity.ParentId) + .SelectTop(1); + NodeDto? parent = Database.FirstOrDefault(sqlParent); + + var level = (parent?.Level ?? 0) + 1; + Sql sqlSortOrder = Sql() + .SelectCount() + .From() + .Where(x => x.ParentId == entity.ParentId && x.NodeObjectType == NodeObjectTypeId); + var sortOrder = Database.ExecuteScalar(sqlSortOrder); // Create the (base) node data - umbracoNode NodeDto nodeDto = dto.NodeDto; - nodeDto.Path = parent.Path; + nodeDto.Path = parent?.Path ?? Constants.System.RootString; nodeDto.Level = short.Parse(level.ToString(CultureInfo.InvariantCulture)); nodeDto.SortOrder = sortOrder; var o = Database.IsNew(nodeDto) @@ -210,7 +218,7 @@ AND umbracoNode.nodeObjectType = @objectType", : Database.Update(nodeDto); // Update with new correct path - nodeDto.Path = string.Concat(parent.Path, ",", nodeDto.NodeId); + nodeDto.Path = string.Concat(nodeDto.Path, ",", nodeDto.NodeId); Database.Update(nodeDto); // Update entity with correct values @@ -238,10 +246,12 @@ AND umbracoNode.nodeObjectType = @objectType", else { // Fallback for ContentTypes with no identity - ContentTypeDto? contentTypeDto = - Database.FirstOrDefault( - "WHERE alias = @Alias", - new { composition.Alias }); + Sql sqlDto = Sql() + .SelectAll() + .From() + .Where(x => x.Alias == composition.Alias) + .SelectTop(1); + ContentTypeDto? contentTypeDto = Database.FirstOrDefault(sqlDto); if (contentTypeDto != null) { Database.Insert(new ContentType2ContentTypeDto @@ -254,7 +264,7 @@ AND umbracoNode.nodeObjectType = @objectType", } (TEntity Entity, int SortOrder)[] allowedContentTypes = GetAllowedContentTypes(entity); - if (allowedContentTypes.Any()) + if (allowedContentTypes.Length > 0) { // Insert collection of allowed content types foreach ((TEntity entity1, int sortOrder1) in allowedContentTypes) @@ -269,7 +279,8 @@ AND umbracoNode.nodeObjectType = @objectType", } // Insert Tabs - foreach (PropertyGroup propertyGroup in entity.PropertyGroups) + PropertyGroupCollection propertyGroups = entity.PropertyGroups; + foreach (PropertyGroup propertyGroup in propertyGroups) { PropertyTypeGroupDto tabDto = PropertyGroupFactory.BuildGroupDto(propertyGroup, nodeDto.NodeId); var primaryKey = Convert.ToInt32(Database.Insert(tabDto)); @@ -291,7 +302,8 @@ AND umbracoNode.nodeObjectType = @objectType", } // Insert PropertyTypes - foreach (IPropertyType propertyType in entity.PropertyTypes) + IEnumerable propertyTypes = entity.PropertyTypes; + foreach (IPropertyType propertyType in propertyTypes) { var tabId = propertyType.PropertyGroupId != null ? propertyType.PropertyGroupId.Value : default; @@ -307,10 +319,17 @@ AND umbracoNode.nodeObjectType = @objectType", propertyType.Id = typePrimaryKey; // Set Id on new PropertyType // Update the current PropertyType with correct PropertyEditorAlias and DatabaseType - DataTypeDto? dataTypeDto = - Database.FirstOrDefault("WHERE nodeId = @Id", new { Id = propertyTypeDto.DataTypeId }); - propertyType.PropertyEditorAlias = dataTypeDto.EditorAlias; - propertyType.ValueStorageType = dataTypeDto.DbType.EnumParse(true); + Sql sqlDataType = Sql() + .SelectAll() + .From() + .Where(x => x.NodeId == propertyType.DataTypeId) + .SelectTop(1); + DataTypeDto? dataTypeDto = Database.FirstOrDefault(sqlDataType); + if (dataTypeDto is not null) + { + propertyType.PropertyEditorAlias = dataTypeDto.EditorAlias; + propertyType.ValueStorageType = dataTypeDto.DbType.EnumParse(true); + } } CommonRepository.ClearCache(); // always @@ -324,13 +343,14 @@ AND umbracoNode.nodeObjectType = @objectType", ContentTypeDto dto = ContentTypeFactory.BuildContentTypeDto(entity); // ensure the alias is not used already - var exists = Database.ExecuteScalar( - @"SELECT COUNT(*) FROM cmsContentType -INNER JOIN umbracoNode ON cmsContentType.nodeId = umbracoNode.id -WHERE cmsContentType." + SqlSyntax.GetQuotedColumnName("alias") + @"= @alias -AND umbracoNode.nodeObjectType = @objectType -AND umbracoNode.id <> @id", - new { id = dto.NodeId, alias = dto.Alias, objectType = NodeObjectTypeId }); + Sql sqlContentType1 = Sql() + .SelectCount() + .From() + .InnerJoin().On(left => left.NodeId, right => right.NodeId) + .Where(x => x.Alias == dto.Alias) + .Where(x => x.NodeObjectType == NodeObjectTypeId && x.NodeId != dto.NodeId); + var exists = Database.ExecuteScalar(sqlContentType1); + if (exists > 0) { throw new DuplicateNameException("An item with the alias " + dto.Alias + " already exists"); @@ -344,12 +364,20 @@ AND umbracoNode.id <> @id", // we NEED this: updating, so the .PrimaryKey already exists, but the entity does // not carry it and therefore the dto does not have it yet - must get it from db, // look up ContentType entry to get PrimaryKey for updating the DTO - ContentTypeDto? dtoPk = Database.First("WHERE nodeId = @Id", new { entity.Id }); + Sql sqlContentType2 = Sql() + .SelectAll() + .From() + .Where(x => x.NodeId == dto.NodeId) + .SelectTop(1); + ContentTypeDto? dtoPk = Database.First(sqlContentType2); dto.PrimaryKey = dtoPk.PrimaryKey; Database.Update(dto); // handle (delete then recreate) compositions - Database.Delete("WHERE childContentTypeId = @Id", new { entity.Id }); + Sql sqlContentType2ContentType = Sql() + .Delete() + .Where(x => x.ChildId == entity.Id); + Database.Execute(sqlContentType2ContentType); foreach (IContentTypeComposition composition in entity.ContentTypeComposition) { Database.Insert(new ContentType2ContentTypeDto { ParentId = composition.Id, ChildId = entity.Id }); @@ -364,20 +392,24 @@ AND umbracoNode.id <> @id", // TODO: Could we do the below with bulk SQL statements instead of looking everything up and then manipulating? // find Content based on the current ContentType - Sql sql = Sql() + Sql sqlContent = Sql() .SelectAll() .From() .InnerJoin().On(left => left.NodeId, right => right.NodeId) .Where(x => x.NodeObjectType == Constants.ObjectTypes.Document) .Where(x => x.ContentTypeId == entity.Id); - List? contentDtos = Database.Fetch(sql); + List? contentDtos = Database.Fetch(sqlContent); // loop through all tracked keys, which corresponds to the ContentTypes that has been removed from the composition foreach (var key in entity.RemovedContentTypes) { // find PropertyTypes for the removed ContentType + Sql sqlPropertyType = Sql() + .SelectAll() + .From() + .Where(x => x.ContentTypeId == key); List? propertyTypes = - Database.Fetch("WHERE contentTypeId = @Id", new { Id = key }); + Database.Fetch(sqlPropertyType); // loop through the Content that is based on the current ContentType in order to remove the Properties that are // based on the PropertyTypes that belong to the removed ContentType. @@ -388,7 +420,7 @@ AND umbracoNode.id <> @id", { var nodeId = contentDto.NodeId; var propertyTypeId = propertyType.Id; - Sql propertySql = Sql() + Sql sqlProperty = Sql() .Select(x => x.Id) .From() .InnerJoin() @@ -399,16 +431,20 @@ AND umbracoNode.id <> @id", .Where(x => x.Id == propertyTypeId); // finally delete the properties that match our criteria for removing a ContentType from the composition - Database.Delete(new Sql( - "WHERE id IN (" + propertySql.SQL + ")", - propertySql.Arguments)); + Sql sqlPropertydata = Sql() + .Delete() + .WhereIn(x => x.Id, sqlProperty.Arguments); + Database.Execute(sqlPropertydata); } } } } // delete the allowed content type entries before re-inserting the collection of allowed content types - Database.Delete("WHERE Id = @Id", new { entity.Id }); + Sql sqlAllowedContent = Sql() + .Delete() + .Where(x => x.Id == entity.Id); + Database.Execute(sqlAllowedContent); (TEntity Entity, int SortOrder)[] allowedContentTypes = GetAllowedContentTypes(entity); if (allowedContentTypes.Any()) @@ -431,8 +467,11 @@ AND umbracoNode.id <> @id", if (entity.IsPropertyDirty("NoGroupPropertyTypes") || entity.PropertyGroups.Any(x => x.IsPropertyDirty("PropertyTypes"))) { - List? dbPropertyTypes = - Database.Fetch("WHERE contentTypeId = @Id", new { entity.Id }); + Sql sqlPropertyType = Sql() + .SelectAll() + .From() + .Where(x => x.ContentTypeId == entity.Id); + List? dbPropertyTypes = Database.Fetch(sqlPropertyType); IEnumerable dbPropertyTypeIds = dbPropertyTypes.Select(x => x.Id); IEnumerable entityPropertyTypes = entity.PropertyTypes.Where(x => x.HasIdentity).Select(x => x.Id); IEnumerable propertyTypeToDeleteIds = dbPropertyTypeIds.Except(entityPropertyTypes); @@ -465,10 +504,12 @@ AND umbracoNode.id <> @id", // delete tabs that do not exist anymore // get the tabs that are currently existing (in the db), get the tabs that we want, // now, and derive the tabs that we want to delete - var existingPropertyGroups = Database - .Fetch("WHERE contentTypeNodeId = @id", new { id = entity.Id }) - .Select(x => x.Id) - .ToList(); + Sql sqlPropTypeGrp1 = Sql() + .Select(x => x.Id) + .From() + .Where(x => x.ContentTypeNodeId == entity.Id); + List existingPropertyGroups = Database.Fetch(sqlPropTypeGrp1); + var newPropertyGroups = entity.PropertyGroups.Select(x => x.Id).ToList(); var groupsToDelete = existingPropertyGroups .Except(newPropertyGroups) @@ -481,16 +522,21 @@ AND umbracoNode.id <> @id", // - move them to 'generic properties' so they remain consistent // - keep track of them, later on we'll figure out what to do with them // see http://issues.umbraco.org/issue/U4-8663 - orphanPropertyTypeIds = Database.Fetch( - "WHERE propertyTypeGroupId IN (@ids)", - new { ids = groupsToDelete }) - .Select(x => x.Id).ToList(); - Database.Update( - "SET propertyTypeGroupId = NULL WHERE propertyTypeGroupId IN (@ids)", - new { ids = groupsToDelete }); + Sql sqlPropTypeGrp2 = Sql() + .Select(x => x.Id) + .From() + .WhereIn(x => x.PropertyTypeGroupId, groupsToDelete); + orphanPropertyTypeIds = Database.Fetch(sqlPropTypeGrp2); + Sql sqlPropTypeGrp3 = Sql() + .Update(u => u.Set(x => x.PropertyTypeGroupId, null)) + .WhereIn(x => x.PropertyTypeGroupId, groupsToDelete); + Database.Execute(sqlPropTypeGrp3); // now we can delete the tabs - Database.Delete("WHERE id IN (@ids)", new { ids = groupsToDelete }); + Sql sqlPropTypeGrp4 = Sql() + .Delete() + .WhereIn(x => x.Id, groupsToDelete); + Database.Execute(sqlPropTypeGrp4); } } @@ -905,59 +951,59 @@ AND umbracoNode.id <> @id", // there's 2x tables to update // clear out the versionCultureVariation table - Sql sqlSelect = Sql().Select(x => x.Id) + Sql sqlSelectContentVersion = Sql().Select(x => x.Id) .From() .InnerJoin() .On(x => x.Id, x => x.VersionId) .InnerJoin().On(x => x.NodeId, x => x.NodeId) .Where(x => x.ContentTypeId == contentType.Id) .Where(x => x.LanguageId == defaultLanguageId); - Sql sqlDelete = Sql() + Sql sqlDeleteContentVersion = Sql() .Delete() - .WhereIn(x => x.Id, sqlSelect); + .WhereIn(x => x.Id, sqlSelectContentVersion); - Database.Execute(sqlDelete); + Database.Execute(sqlDeleteContentVersion); // clear out the documentCultureVariation table - sqlSelect = Sql().Select(x => x.Id) + Sql sqlDocumentCulture = Sql().Select(x => x.Id) .From() .InnerJoin().On(x => x.NodeId, x => x.NodeId) .Where(x => x.ContentTypeId == contentType.Id) .Where(x => x.LanguageId == defaultLanguageId); - sqlDelete = Sql() + Sql sqlDeleteDocumentCulture = Sql() .Delete() - .WhereIn(x => x.Id, sqlSelect); + .WhereIn(x => x.Id, sqlDocumentCulture); - Database.Execute(sqlDelete); + Database.Execute(sqlDeleteDocumentCulture); // now we need to insert names into these 2 tables based on the invariant data // insert rows into the versionCultureVariationDto table based on the data from contentVersionDto for the default lang var cols = Sql().ColumnsForInsert(x => x.VersionId, x => x.Name, x => x.UpdateUserId, x => x.UpdateDate, x => x.LanguageId); - sqlSelect = Sql().Select(x => x.Id, x => x.Text, x => x.UserId, x => x.VersionDate) + Sql sqlSelect2 = Sql().Select(x => x.Id, x => x.Text, x => x.UserId, x => x.VersionDate) .Append($", {defaultLanguageId}") // default language ID .From() .InnerJoin().On(x => x.NodeId, x => x.NodeId) .Where(x => x.ContentTypeId == contentType.Id); - Sql? sqlInsert = Sql($"INSERT INTO {ContentVersionCultureVariationDto.TableName} ({cols})") - .Append(sqlSelect); + Sql? sqlInsertContentVersion = Sql($"INSERT INTO {SqlSyntax.GetQuotedTableName(ContentVersionCultureVariationDto.TableName)} ({cols})") + .Append(sqlSelect2); - Database.Execute(sqlInsert); + Database.Execute(sqlInsertContentVersion); // insert rows into the documentCultureVariation table cols = Sql().ColumnsForInsert(x => x.NodeId, x => x.Edited, x => x.Published, x => x.Name, x => x.Available, x => x.LanguageId); - sqlSelect = Sql().Select(x => x.NodeId, x => x.Edited, x => x.Published) + Sql sqlSelectDocument = Sql().Select(x => x.NodeId, x => x.Edited, x => x.Published) .AndSelect(x => x.Text) .Append($", 1, {defaultLanguageId}") // make Available + default language ID .From() .InnerJoin().On(x => x.NodeId, x => x.NodeId) .InnerJoin().On(x => x.NodeId, x => x.NodeId) .Where(x => x.ContentTypeId == contentType.Id); - sqlInsert = Sql($"INSERT INTO {DocumentCultureVariationDto.TableName} ({cols})").Append(sqlSelect); + Sql sqlInsertDocumentCulture = Sql($"INSERT INTO {SqlSyntax.GetQuotedTableName(DocumentCultureVariationDto.TableName)} ({cols})").Append(sqlSelectDocument); - Database.Execute(sqlInsert); + Database.Execute(sqlInsertDocumentCulture); } } @@ -977,28 +1023,28 @@ AND umbracoNode.id <> @id", // delete existing relations (for target language) // do *not* delete existing tags - Sql sqlSelectTagsToDelete = Sql() + Sql sqlSelectTagsToDelete1 = Sql() .Select(x => x.Id) .From() .InnerJoin().On((tag, rel) => tag.Id == rel.TagId); if (contentTypeIds != null) { - sqlSelectTagsToDelete + sqlSelectTagsToDelete1 .InnerJoin() .On((rel, content) => rel.NodeId == content.NodeId) .WhereIn(x => x.ContentTypeId, contentTypeIds); } - sqlSelectTagsToDelete + sqlSelectTagsToDelete1 .WhereIn(x => x.PropertyTypeId, propertyTypeIds) .Where(x => x.LanguageId.SqlNullableEquals(targetLanguageId, -1)); - Sql sqlDeleteRelations = Sql() + Sql sqlDeleteRelations1 = Sql() .Delete() - .WhereIn(x => x.TagId, sqlSelectTagsToDelete); + .WhereIn(x => x.TagId, sqlSelectTagsToDelete1); - Database.Execute(sqlDeleteRelations); + Database.Execute(sqlDeleteRelations1); // do *not* delete the tags - they could be used by other content types / property types /* @@ -1015,12 +1061,12 @@ AND umbracoNode.id <> @id", // and of source language, and where we cannot left join to an existing tag with same text, // group and languageId var targetLanguageIdS = targetLanguageId.HasValue ? targetLanguageId.ToString() : "NULL"; - Sql sqlSelectTagsToInsert = Sql() + Sql sqlSelectTagsToInsert1 = Sql() .SelectDistinct(x => x.Text, x => x.Group) .Append(", " + targetLanguageIdS) .From(); - sqlSelectTagsToInsert + sqlSelectTagsToInsert1 .InnerJoin().On((tag, rel) => tag.Id == rel.TagId) .LeftJoin("xtags") .On( @@ -1029,19 +1075,19 @@ AND umbracoNode.id <> @id", if (contentTypeIds != null) { - sqlSelectTagsToInsert + sqlSelectTagsToInsert1 .InnerJoin() .On((rel, content) => rel.NodeId == content.NodeId) .WhereIn(x => x.ContentTypeId, contentTypeIds); } - sqlSelectTagsToInsert + sqlSelectTagsToInsert1 .WhereIn(x => x.PropertyTypeId, propertyTypeIds) .WhereNull(x => x.Id, "xtags") // ie, not exists .Where(x => x.LanguageId.SqlNullableEquals(sourceLanguageId, -1)); var cols = Sql().ColumnsForInsert(x => x.Text, x => x.Group, x => x.LanguageId); - Sql? sqlInsertTags = Sql($"INSERT INTO {TagDto.TableName} ({cols})").Append(sqlSelectTagsToInsert); + Sql? sqlInsertTags = Sql($"INSERT INTO {SqlSyntax.GetQuotedTableName(TagDto.TableName)} ({cols})").Append(sqlSelectTagsToInsert1); Database.Execute(sqlInsertTags); @@ -1076,33 +1122,33 @@ AND umbracoNode.id <> @id", var relationColumnsToInsert = Sql().ColumnsForInsert(x => x.NodeId, x => x.PropertyTypeId, x => x.TagId); Sql? sqlInsertRelations = - Sql($"INSERT INTO {TagRelationshipDto.TableName} ({relationColumnsToInsert})") + Sql($"INSERT INTO {SqlSyntax.GetQuotedTableName(TagRelationshipDto.TableName)} ({relationColumnsToInsert})") .Append(sqlSelectRelationsToInsert); Database.Execute(sqlInsertRelations); // delete original relations - *not* the tags - all of them // cannot really "go back" with relations, would have to do it with property values - sqlSelectTagsToDelete = Sql() + Sql sqlSelectTagsToDelete2 = Sql() .Select(x => x.Id) .From() .InnerJoin().On((tag, rel) => tag.Id == rel.TagId); if (contentTypeIds != null) { - sqlSelectTagsToDelete + sqlSelectTagsToDelete2 .InnerJoin() .On((rel, content) => rel.NodeId == content.NodeId) .WhereIn(x => x.ContentTypeId, contentTypeIds); } - sqlSelectTagsToDelete + sqlSelectTagsToDelete2 .WhereIn(x => x.PropertyTypeId, propertyTypeIds) .Where(x => !x.LanguageId.SqlNullableEquals(targetLanguageId, -1)); - sqlDeleteRelations = Sql() + Sql sqlDeleteRelations = Sql() .Delete() - .WhereIn(x => x.TagId, sqlSelectTagsToDelete); + .WhereIn(x => x.TagId, sqlSelectTagsToDelete2); Database.Execute(sqlDeleteRelations); @@ -1142,15 +1188,14 @@ AND umbracoNode.id <> @id", // .From() // .InnerJoin().On((pdata, cversion) => pdata.VersionId == cversion.Id) // .InnerJoin().On((cversion, c) => cversion.NodeId == c.NodeId); - Sql? inSql = null; - if (contentTypeIds != null) + if (contentTypeIds is not null) { - inSql = Sql() - .Select(x => x.Id) - .From() - .InnerJoin() - .On((cversion, c) => cversion.NodeId == c.NodeId) - .WhereIn(x => x.ContentTypeId, contentTypeIds); + Sql inSql = Sql() + .Select(x => x.Id) + .From() + .InnerJoin() + .On((cversion, c) => cversion.NodeId == c.NodeId) + .WhereIn(x => x.ContentTypeId, contentTypeIds); sqlDelete.WhereIn(x => x.VersionId, inSql); } @@ -1196,7 +1241,7 @@ AND umbracoNode.id <> @id", .WhereIn(x => x.ContentTypeId, contentTypeIds); } - Sql? sqlInsert = Sql($"INSERT INTO {PropertyDataDto.TableName} ({cols})").Append(sqlSelectData); + Sql? sqlInsert = Sql($"INSERT INTO {SqlSyntax.GetQuotedTableName(PropertyDataDto.TableName)} ({cols})").Append(sqlSelectData); Database.Execute(sqlInsert); @@ -1209,6 +1254,12 @@ AND umbracoNode.id <> @id", if (contentTypeIds != null) { + Sql inSql = Sql() + .Select(x => x.Id) + .From() + .InnerJoin() + .On((cversion, c) => cversion.NodeId == c.NodeId) + .WhereIn(x => x.ContentTypeId, contentTypeIds); sqlDelete.WhereIn(x => x.VersionId, inSql); } @@ -1412,25 +1463,35 @@ AND umbracoNode.id <> @id", private void DeletePropertyType(IContentTypeComposition contentType, int propertyTypeId) { - // First clear dependencies. - Database.Delete("WHERE propertyTypeId = @Id", new { Id = propertyTypeId }); - Database.Delete("WHERE propertyTypeId = @Id", new { Id = propertyTypeId }); + // first clear dependencies + Sql sqlTagRelationship = Sql() + .Delete() + .Where(x => x.PropertyTypeId == propertyTypeId); + Database.Execute(sqlTagRelationship); - // Clear the property value permissions, which aren't a hard dependency with a foreign key, but we want to ensure - // that any for removed property types are cleared. - var uniqueIdAsString = string.Format(SqlContext.SqlSyntax.ConvertUniqueIdentifierToString, "uniqueId"); - var permissionSearchString = SqlContext.SqlSyntax.GetConcat( - "(SELECT " + uniqueIdAsString + " FROM " + Constants.DatabaseSchema.Tables.PropertyType + " WHERE id = @PropertyTypeId)", - "'|%'"); + Sql sqlPropertyData = Sql() + .Delete() + .Where(x => x.PropertyTypeId == propertyTypeId); + Database.Execute(sqlPropertyData); - Database.Delete( - "WHERE uniqueId = @ContentTypeKey AND permission LIKE " + permissionSearchString, - new { ContentTypeKey = contentType.Key, PropertyTypeId = propertyTypeId }); + Sql delSql = Sql() + .Delete() + .Where(c => c.UniqueId == contentType.Key) + .WhereLike( + c => c.Permission, + Sql() + .SelectClosure(c => c.ConvertUniqueIdentifierToString(x => x.UniqueId)) + .From() + .WhereClosure(c => c.Id == propertyTypeId), + $"'|{SqlSyntax.GetWildcardPlaceholder()}'"); + + Database.Execute(delSql); // Finally delete the property type. - Database.Delete( - "WHERE contentTypeId = @Id AND id = @PropertyTypeId", - new { contentType.Id, PropertyTypeId = propertyTypeId }); + Sql sqlPropertyType = Sql() + .Delete() + .Where(x => x.ContentTypeId == contentType.Id && x.Id == propertyTypeId); + Database.Execute(sqlPropertyType); } protected void ValidateAlias(TEntity entity) @@ -1486,9 +1547,7 @@ AND umbracoNode.id <> @id", .Select(dt => dt.Select(x => x.NodeDto)) .From() .InnerJoin().On((dt, n) => dt.NodeId == n.NodeId) - .Where( - "propertyEditorAlias = @propertyEditorAlias", - new { propertyEditorAlias = propertyType.PropertyEditorAlias }) + .Where(c => c.EditorAlias == propertyType.PropertyEditorAlias) .OrderBy(typeDto => typeDto.NodeId); DataTypeDto? datatype = Database.FirstOrDefault(sql); @@ -1516,12 +1575,13 @@ AND umbracoNode.id <> @id", public string GetUniqueAlias(string alias) { // alias is unique across ALL content types! - var aliasColumn = SqlSyntax.GetQuotedColumnName("alias"); - List? aliases = Database.Fetch( - @"SELECT cmsContentType." + aliasColumn + @" FROM cmsContentType -INNER JOIN umbracoNode ON cmsContentType.nodeId = umbracoNode.id -WHERE cmsContentType." + aliasColumn + @" LIKE @pattern", - new { pattern = alias + "%", objectType = NodeObjectTypeId }); + Sql sql = Sql() + .Select(c => c.Alias) + .From() + .InnerJoin().On((ct, n) => ct.NodeId == n.NodeId) + .WhereLike(c => c.Alias, $"{alias}{SqlSyntax.GetWildcardPlaceholder()}"); + List aliases = Database.Fetch(sql); + var i = 1; string test; while (aliases.Contains(test = alias + i)) @@ -1541,10 +1601,13 @@ WHERE cmsContentType." + aliasColumn + @" LIKE @pattern", public bool HasContainerInPath(params int[] ids) { - var sql = new Sql( - $@"SELECT COUNT(*) FROM cmsContentType -INNER JOIN {Constants.DatabaseSchema.Tables.Content} ON cmsContentType.nodeId={Constants.DatabaseSchema.Tables.Content}.contentTypeId -WHERE {Constants.DatabaseSchema.Tables.Content}.nodeId IN (@ids) AND cmsContentType.listView IS NULL", new { ids }); + Sql sql = Sql() + .SelectCount() + .From() + .InnerJoin() + .On((ct, c) => ct.NodeId == c.ContentTypeId) + .WhereIn(x => x.NodeId, ids) + .Where(x => x.ListView == null); return Database.ExecuteScalar(sql) > 0; } @@ -1554,7 +1617,7 @@ WHERE {Constants.DatabaseSchema.Tables.Content}.nodeId IN (@ids) AND cmsContentT public bool HasContentNodes(int id) { var sql = new Sql( - $"SELECT CASE WHEN EXISTS (SELECT * FROM {Constants.DatabaseSchema.Tables.Content} WHERE contentTypeId = @id) THEN 1 ELSE 0 END", + $"SELECT CASE WHEN EXISTS (SELECT * FROM {SqlSyntax.GetQuotedTableName(ContentDto.TableName)} WHERE {SqlSyntax.GetQuotedColumnName("contentTypeId")} = @id) THEN 1 ELSE 0 END", new { id }); return Database.ExecuteScalar(sql) == 1; } @@ -1566,16 +1629,18 @@ WHERE {Constants.DatabaseSchema.Tables.Content}.nodeId IN (@ids) AND cmsContentT // is included here just to be 100% sure since it has a FK on cmsPropertyType. var list = new List { - "DELETE FROM " + Constants.DatabaseSchema.Tables.User2NodeNotify + " WHERE nodeId = @id", - "DELETE FROM " + Constants.DatabaseSchema.Tables.UserGroup2GranularPermission + " WHERE uniqueId IN (SELECT uniqueId FROM umbracoNode WHERE id = @id)", - "DELETE FROM " + Constants.DatabaseSchema.Tables.TagRelationship + " WHERE nodeId = @id", - "DELETE FROM " + Constants.DatabaseSchema.Tables.ContentChildType + " WHERE Id = @id", - "DELETE FROM " + Constants.DatabaseSchema.Tables.ContentChildType + " WHERE AllowedId = @id", - "DELETE FROM " + Constants.DatabaseSchema.Tables.ContentTypeTree + " WHERE parentContentTypeId = @id", - "DELETE FROM " + Constants.DatabaseSchema.Tables.ContentTypeTree + " WHERE childContentTypeId = @id", - "DELETE FROM " + Constants.DatabaseSchema.Tables.PropertyData + " WHERE propertyTypeId IN (SELECT id FROM cmsPropertyType WHERE contentTypeId = @id)", - "DELETE FROM " + Constants.DatabaseSchema.Tables.PropertyType + " WHERE contentTypeId = @id", - "DELETE FROM " + Constants.DatabaseSchema.Tables.PropertyTypeGroup + " WHERE contenttypeNodeId = @id", + $"DELETE FROM {SqlSyntax.GetQuotedTableName(Constants.DatabaseSchema.Tables.User2NodeNotify)} WHERE {SqlSyntax.GetQuotedColumnName("nodeId")} = @id", + $@"DELETE FROM {SqlSyntax.GetQuotedTableName(Constants.DatabaseSchema.Tables.UserGroup2GranularPermission)} WHERE {SqlSyntax.GetQuotedColumnName("uniqueId")} IN + (SELECT {SqlSyntax.GetQuotedColumnName("uniqueId")} FROM {SqlSyntax.GetQuotedTableName(NodeDto.TableName)} WHERE id = @id)", + $"DELETE FROM {SqlSyntax.GetQuotedTableName(Constants.DatabaseSchema.Tables.TagRelationship)} WHERE {SqlSyntax.GetQuotedColumnName("nodeId")} = @id", + $"DELETE FROM {SqlSyntax.GetQuotedTableName(Constants.DatabaseSchema.Tables.ContentChildType)} WHERE {SqlSyntax.GetQuotedColumnName("Id")} = @id", + $"DELETE FROM {SqlSyntax.GetQuotedTableName(Constants.DatabaseSchema.Tables.ContentChildType)} WHERE {SqlSyntax.GetQuotedColumnName("AllowedId")} = @id", + $"DELETE FROM {SqlSyntax.GetQuotedTableName(Constants.DatabaseSchema.Tables.ContentTypeTree)} WHERE {SqlSyntax.GetQuotedColumnName("parentContentTypeId")} = @id", + $"DELETE FROM {SqlSyntax.GetQuotedTableName(Constants.DatabaseSchema.Tables.ContentTypeTree)} WHERE {SqlSyntax.GetQuotedColumnName("childContentTypeId")} = @id", + $@"DELETE FROM {SqlSyntax.GetQuotedTableName(PropertyDataDto.TableName)} WHERE {SqlSyntax.GetQuotedColumnName("propertyTypeId")} IN + (SELECT id FROM {SqlSyntax.GetQuotedTableName(Constants.DatabaseSchema.Tables.PropertyType)} WHERE {SqlSyntax.GetQuotedColumnName("contentTypeId")} = @id)", + $"DELETE FROM {SqlSyntax.GetQuotedTableName(Constants.DatabaseSchema.Tables.PropertyType)} WHERE {SqlSyntax.GetQuotedColumnName("contentTypeId")} = @id", + $"DELETE FROM {SqlSyntax.GetQuotedTableName(Constants.DatabaseSchema.Tables.PropertyTypeGroup)} WHERE {SqlSyntax.GetQuotedColumnName("contenttypeNodeId")} = @id", }; return list; } diff --git a/src/Umbraco.Infrastructure/Persistence/SqlSyntax/ISqlSyntaxProvider.cs b/src/Umbraco.Infrastructure/Persistence/SqlSyntax/ISqlSyntaxProvider.cs index 1b01a74535..2593f52337 100644 --- a/src/Umbraco.Infrastructure/Persistence/SqlSyntax/ISqlSyntaxProvider.cs +++ b/src/Umbraco.Infrastructure/Persistence/SqlSyntax/ISqlSyntaxProvider.cs @@ -90,6 +90,13 @@ public interface ISqlSyntaxProvider string GetWildcardPlaceholder(); + /// + /// This ensures that GetWildcardPlaceholder() character is surronded by '' when used inside a LIKE statement. E.g. in WhereLike() extension and the defaultConcat is used. + /// + /// When provided this overides the GetWildcardPlaceholder() default. + /// + string GetWildcardConcat(string concatDefault = ""); + string GetStringColumnEqualComparison(string column, int paramIndex, TextColumnType columnType); string GetStringColumnWildcardComparison(string column, int paramIndex, TextColumnType columnType); diff --git a/src/Umbraco.Infrastructure/Persistence/SqlSyntax/SqlSyntaxProviderBase.cs b/src/Umbraco.Infrastructure/Persistence/SqlSyntax/SqlSyntaxProviderBase.cs index 75eeebda9b..df56d36da6 100644 --- a/src/Umbraco.Infrastructure/Persistence/SqlSyntax/SqlSyntaxProviderBase.cs +++ b/src/Umbraco.Infrastructure/Persistence/SqlSyntax/SqlSyntaxProviderBase.cs @@ -112,6 +112,21 @@ public abstract class SqlSyntaxProviderBase : ISqlSyntaxProvider public string GetWildcardPlaceholder() => "%"; + public virtual string GetWildcardConcat(string concatDefault = "") + { + if (string.IsNullOrEmpty(concatDefault)) + { + return $"'{GetWildcardPlaceholder()}'"; + } + + if (!concatDefault.StartsWith('\'') || !concatDefault.EndsWith('\'')) + { + return $"'{concatDefault.Trim()}'"; + } + + return concatDefault; + } + public virtual DatabaseType GetUpdatedDatabaseType(DatabaseType current, string? connectionString) => current; public abstract string ProviderName { get; } @@ -126,7 +141,7 @@ public abstract class SqlSyntaxProviderBase : ISqlSyntaxProvider //use the 'upper' method to always ensure strings are matched without case sensitivity no matter what the db setting. $"upper({column}) LIKE upper(@{paramIndex})"; - public virtual string GetConcat(params string[] args) => "concat(" + string.Join(",", args) + ")"; + public virtual string GetConcat(params string[] args) => "CONCAT(" + string.Join(",", args) + ")"; public virtual string GetQuotedTableName(string? tableName) => $"\"{tableName}\""; diff --git a/tests/Umbraco.Tests.UnitTests/Umbraco.Infrastructure/Persistence/Querying/ContentTypeRepositorySqlClausesTest.cs b/tests/Umbraco.Tests.UnitTests/Umbraco.Infrastructure/Persistence/Querying/ContentTypeRepositorySqlClausesTest.cs index 168e510ed4..62306f4175 100644 --- a/tests/Umbraco.Tests.UnitTests/Umbraco.Infrastructure/Persistence/Querying/ContentTypeRepositorySqlClausesTest.cs +++ b/tests/Umbraco.Tests.UnitTests/Umbraco.Infrastructure/Persistence/Querying/ContentTypeRepositorySqlClausesTest.cs @@ -2,11 +2,15 @@ // See LICENSE for more details. using System.Diagnostics; +using NPoco; using NUnit.Framework; using Umbraco.Cms.Core; +using Umbraco.Cms.Core.Models; +using Umbraco.Cms.Infrastructure.Persistence; using Umbraco.Cms.Infrastructure.Persistence.Dtos; using Umbraco.Cms.Tests.UnitTests.TestHelpers; using Umbraco.Extensions; +using static Umbraco.Cms.Core.Constants; namespace Umbraco.Cms.Tests.UnitTests.Umbraco.Infrastructure.Persistence.Querying; @@ -164,4 +168,33 @@ public class ContentTypeRepositorySqlClausesTest : BaseUsingSqlSyntax Debug.Print(sql.SQL); } + + [Test] + public void Can_Verify_WhereLike_Clause() + { + var key = Guid.NewGuid(); + var propertyTypeId = 1234; + Sql sql = Sql() + .Delete() + .Where(c => c.UniqueId == key) + .WhereLike( + c => c.Permission, + Sql() + .SelectClosure(c => c.ConvertUniqueIdentifierToString(x => x.UniqueId)) + .From() + .WhereClosure(c => c.Id == propertyTypeId), + $"'|{SqlContext.SqlSyntax.GetWildcardPlaceholder()}'"); + + string expectedSQL = +@"DELETE FROM [umbracoUserGroup2GranularPermission] +WHERE (([umbracoUserGroup2GranularPermission].[uniqueId] = @0)) +AND ([umbracoUserGroup2GranularPermission].[permission] LIKE CONCAT((SELECT + CONVERT(nvarchar(36), [cmsPropertyType].[UniqueID]) + +FROM [cmsPropertyType] +WHERE (([cmsPropertyType].[id] = @1)) +),'|%'))".Replace("\r", string.Empty); + var typedSql = sql.SQL; + Assert.That(typedSql, Is.EqualTo(expectedSQL)); + } }