using System.Collections.Generic; using System.Text; using System.Linq; using AyaNova.Biz; using AyaNova.Util; namespace AyaNova.PickList { internal static class PickListSqlBuilder { /*Example select awidget.id as plId, awidget.active as plActive, awidget.name || ' ' || awidget.serial || ' ' || auser.name as plname, awidget.tags from awidget left outer join auser on (awidget.userid=auser.id) where array_to_string(awidget.tags,',') like '%zone-8%' and awidget.active = true and ((awidget.name like '%we%') or (cast (awidget.serial as text) like '%we%') or (auser.name like '%we%')) order by awidget.name,awidget.serial,auser.name limit 100 */ //Maximum number of results to return at any given time //did a little research and may adjust this but it can be fairly girthy in this day and age //and many people might not want or need to autocomplete type if we provide enough leeway. //for example, if you're selecting a const int MAXIMUM_RESULT_COUNT = 100; //Build the query for a picklist request internal static string Build(IAyaPickList pickList, List templateColumnNames, string autoCompleteQuery, string tagSpecificQuery, bool IncludeInactive, long preId) { //determine this in advance as it will be used in a loop later bool HasAutoCompleteQuery = !string.IsNullOrWhiteSpace(autoCompleteQuery); bool HasTagSpecificQuery = !string.IsNullOrWhiteSpace(tagSpecificQuery); //Variables to collect the data needed to create the actual clauses later List lSelect = new List(); List lWhere = new List(); List lOrderBy = new List(); string PlIdSelectFragment = string.Empty; string ActiveSelectFragment = string.Empty; string ActiveWhereFragment = string.Empty; string TagSpecificWhereFragment = string.Empty; string PredefinedOnlyWhereFragment = string.Empty; //PROCESS ROW ID "VALUE" COLUMN // AyaPickListFieldDefinition rowIdColumn = pickList.ColumnDefinitions.FirstOrDefault(x => x.IsRowId == true); //this should only happen with a development error if (rowIdColumn == null) throw new System.ArgumentNullException($"DEV ERROR in PickListSqlBuilder.cs: picklist for {pickList.DefaultListObjectType.ToString()} has no rowId column specified in columnDefinitions list"); PlIdSelectFragment = rowIdColumn.SqlIdColumnName + " as plId"; if (preId != 0) { PredefinedOnlyWhereFragment = rowIdColumn.SqlIdColumnName + " = " + preId.ToString(); } //PROCESS ACTIVE COLUMN // //NOTE: default is to filter *out* inactive objects because that's the most common need at the Client //but we provide the override for that if necessary as there are often (management usually) cases where user needs to select inactive records //add active column, fake it if necessary AyaPickListFieldDefinition activeColumn = pickList.ColumnDefinitions.FirstOrDefault(x => x.IsActiveColumn == true); if (activeColumn == null) { //no active column which is normal for some types of objects //so make a fake one and return them all as active=true as all lists must return the same format ActiveSelectFragment = "true as plActive"; } else { //we have an active column, set accordingly //regardless of wanting to see inactive, we always want to see the column itself ActiveSelectFragment = activeColumn.SqlValueColumnName + " as plActive"; //this is the normal path unless there is an override //if there is an override to see inactive too then we just don't set the filter on active if (!IncludeInactive) { ActiveWhereFragment = activeColumn.SqlValueColumnName + " = true"; } } //PROCESS TAG SPECIFIC QUERY // if (HasTagSpecificQuery) { //get the tag column AyaPickListFieldDefinition tagColumn = pickList.ColumnDefinitions.FirstOrDefault(x => x.ColumnDataType == UiFieldDataType.Tags); TagSpecificWhereFragment = $"(array_to_string({tagColumn.GetSqlValueColumnName()},',') like '%{tagSpecificQuery}%')"; } //PROCESS TEMPLATED COLUMNS TO BE RETURNED IN RESULTS // foreach (string ColumnName in templateColumnNames) { AyaPickListFieldDefinition o = pickList.ColumnDefinitions.FirstOrDefault(x => x.FieldKey == ColumnName); #if (DEBUG) if (o == null) { throw new System.ArgumentNullException($"DEV ERROR in PickListSqlBuilder.cs: field {ColumnName} specified in template was NOT found in columnDefinitions list"); } #endif if (o != null) {//Ignore missing fields in production var valueColumnName = o.GetSqlValueColumnName(); string sWhere = string.Empty; //TAGS COLUMN // if (o.ColumnDataType == UiFieldDataType.Tags) { lSelect.Add($"(array_to_string({valueColumnName},','))"); //tags can order by without the arraytostring lOrderBy.Add(valueColumnName); //THIS is the best filter method for a like comparison to each individual tag: //(array_to_string(awidget.tags,',') like '%zo%') //Note that a tag specific query takes precendence over this which exists //in cases where there are tags in the template and the user has not specified a tag specific query //so this will handle it as a like query against all tags as a composite string of text just like //all the other templated fields if (HasAutoCompleteQuery && !HasTagSpecificQuery) { if (ServerGlobalBizSettings.SearchCaseSensitiveOnly) sWhere = $"(array_to_string({valueColumnName},',') like '%{autoCompleteQuery}%')"; else sWhere = $"(lower(array_to_string({valueColumnName},',')) like lower('%{autoCompleteQuery}%'))"; } } else if (o.ColumnDataType == UiFieldDataType.Text || o.ColumnDataType == UiFieldDataType.EmailAddress || o.ColumnDataType == UiFieldDataType.HTTP) { //TEXT COLUMN // lSelect.Add(valueColumnName); lOrderBy.Add(valueColumnName); if (HasAutoCompleteQuery) if (ServerGlobalBizSettings.SearchCaseSensitiveOnly) sWhere = $"({valueColumnName} like '%{autoCompleteQuery}%')"; else sWhere = $"(lower({valueColumnName}) like lower('%{autoCompleteQuery}%'))"; } else { //NON-TEXT COLUMN // //Note: if any part of a select contatenation query using the || postgres concat is text then all fields are automatically converted to text //so no need to make it text here as the automatic spacing character will force the whole thing to a text concat anyway //ref: https://stackoverflow.com/a/19943343/8939 lSelect.Add(valueColumnName); //order by for now seems to be best as just order by it's value whatever it is lOrderBy.Add(valueColumnName); //Where fragment is different for non text fields: it needs to be cast to text to like query on it //(cast (awidget.serial as text) like '%some%') if (HasAutoCompleteQuery) if (ServerGlobalBizSettings.SearchCaseSensitiveOnly) sWhere = $"(cast ({valueColumnName} as text) like '%{autoCompleteQuery}%')"; else sWhere = $"(lower(cast ({valueColumnName} as text)) like lower('%{autoCompleteQuery}%'))"; } if (HasAutoCompleteQuery && !string.IsNullOrWhiteSpace(sWhere))//swhere can be empty on a tag in a tag specific query lWhere.Add(sWhere); } } StringBuilder sb = new StringBuilder(); //SELECT sb.Append("select "); //ID COLUMN sb.Append(PlIdSelectFragment); sb.Append(", "); //ACTIVE COLUMN sb.Append(ActiveSelectFragment); sb.Append(", "); //nope, this will return null if any of the values are null, very bad for this use, instead //select name || ' ' || serial || ' ' || array_to_string(tags,',') as display from awidget //this, on the other hand will work even if all of them are null //concat_ws(' ', awidget.name, awidget.serial, auser.name) sb.Append("concat_ws(' ', "); foreach (string s in lSelect) { sb.Append(s); sb.Append(","); } //clear trailing comma sb.Length -= 1; sb.Append(") as plname"); //FROM sb.Append(" "); sb.Append(pickList.SQLFrom); //WHERE //there is a condition where there is no where (inactive=true and no query of any kind) if (preId > 0 || lWhere.Count > 0 || HasTagSpecificQuery || IncludeInactive == false) { sb.Append(" where "); if (HasTagSpecificQuery) { sb.Append(TagSpecificWhereFragment); sb.Append(" and "); } if (!IncludeInactive) { sb.Append(ActiveWhereFragment); sb.Append(" and "); } if (preId > 0) { sb.Append(PredefinedOnlyWhereFragment); sb.Append(" and "); } if (lWhere.Count > 0) { //Put all the regular query terms in parenthesis to ensure it's all treated as one criteria sb.Append("("); foreach (string s in lWhere) { sb.Append(s); sb.Append(" or "); } //clear trailing or sb.Length -= 4; //enclosing parenthesis sb.Append(")"); } else { //we might have a trailing and to remove //jesus this stuff sucks, there must be a better way, it seems so fragile if (!IncludeInactive || HasTagSpecificQuery) { //trailing " and " to remove sb.Length -= 5; } } } //ORDER BY sb.Append(" order by "); foreach (string s in lOrderBy) { sb.Append(s); sb.Append(","); } //clear trailing comma sb.Length--; //LIMIT sb.Append($" limit {MAXIMUM_RESULT_COUNT}"); return sb.ToString(); } //"select awidget.id as plId || ' 'awidget.active as plActive || ' 'awidget.name || ' 'awidget.serial || ' 'auser.name as plname from awidget left outer join auser on (awidget.userid=auser.id) //where awidget.active = true and ((awidget.name like '%on%') or (cast (awidget.serial as text) like '%on%') or (auser.name like '%on%')) order by awidget.name,awidget.serial,auser.name limit 100" }//eoc }//ens