Skip to content

Commit 2607b8f

Browse files
authored
Merge pull request #107 from alejoroman0605/search-should-not-case-sensitive
Search Should not be Case-Sensitive
2 parents 805f47f + e8e8222 commit 2607b8f

File tree

4 files changed

+130
-1
lines changed

4 files changed

+130
-1
lines changed
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,104 @@
1+
/************************************************************/
2+
/***** SqlDataProvider *****/
3+
/************************************************************/
4+
5+
IF OBJECT_ID('{databaseOwner}{objectQualifier}UUM_GetUsers', 'P') IS NOT NULL
6+
BEGIN
7+
EXEC('DROP PROCEDURE ' + '{databaseOwner}{objectQualifier}UUM_GetUsers');
8+
END
9+
GO
10+
11+
CREATE PROCEDURE {databaseOwner}{objectQualifier}UUM_GetUsers
12+
@PageIndex INT,
13+
@PageSize INT,
14+
@SearchTerm NVARCHAR(100) = NULL,
15+
@SortColumn NVARCHAR(50) = 'UserID',
16+
@SortOrder NVARCHAR(4) = 'ASC',
17+
@IsSuperUser BIT = NULL,
18+
@Authorised BIT = NULL,
19+
@PortalId INT = NULL,
20+
@Deleted BIT = NULL,
21+
@AllUsers BIT = NULL,
22+
@TotalRecords INT OUTPUT
23+
AS
24+
BEGIN
25+
SET NOCOUNT ON;
26+
27+
DECLARE @Offset INT;
28+
SET @Offset = (@PageIndex - 1) * @PageSize;
29+
30+
DECLARE @SortExpression NVARCHAR(100);
31+
SET @SortExpression = QUOTENAME(@SortColumn) + ' ' + @SortOrder;
32+
33+
DECLARE @Results TABLE
34+
(
35+
UserID INT,
36+
FirstName NVARCHAR(100),
37+
Username NVARCHAR(100),
38+
Email NVARCHAR(100),
39+
DisplayName NVARCHAR(100),
40+
IsSuperUser BIT,
41+
RowNumber INT
42+
);
43+
44+
-- Perform total count
45+
IF @AllUsers = 0
46+
BEGIN
47+
SELECT @TotalRecords = COUNT(*)
48+
FROM [dbo].[Users] u
49+
LEFT JOIN [dbo].[UserPortals] up ON u.UserID = up.UserID
50+
WHERE (LOWER(u.[UserName]) COLLATE Latin1_General_CI_AI LIKE '%' + LOWER(@SearchTerm) COLLATE Latin1_General_CI_AI + '%' OR
51+
LOWER(u.[FirstName]) COLLATE Latin1_General_CI_AI LIKE '%' + LOWER(@SearchTerm) COLLATE Latin1_General_CI_AI + '%' OR
52+
LOWER(u.[Email]) COLLATE Latin1_General_CI_AI LIKE '%' + LOWER(@SearchTerm) COLLATE Latin1_General_CI_AI + '%' OR
53+
LOWER(u.[DisplayName]) COLLATE Latin1_General_CI_AI LIKE '%' + LOWER(@SearchTerm) COLLATE Latin1_General_CI_AI + '%')
54+
AND u.IsDeleted = 0
55+
AND (@IsSuperUser IS NULL OR u.IsSuperUser = @IsSuperUser)
56+
AND (@Deleted IS NULL OR up.IsDeleted = @Deleted)
57+
AND (@Authorised IS NULL OR (up.Authorised = @Authorised AND up.IsDeleted = 0))
58+
AND (@PortalId IS NULL OR up.PortalId = @PortalId);
59+
END
60+
ELSE
61+
BEGIN
62+
SELECT @TotalRecords = COUNT(*)
63+
FROM [dbo].[Users] u
64+
LEFT JOIN [dbo].[UserPortals] up ON u.UserID = up.UserID
65+
WHERE (LOWER(u.[UserName]) COLLATE Latin1_General_CI_AI LIKE '%' + LOWER(@SearchTerm) COLLATE Latin1_General_CI_AI + '%' OR
66+
LOWER(u.[FirstName]) COLLATE Latin1_General_CI_AI LIKE '%' + LOWER(@SearchTerm) COLLATE Latin1_General_CI_AI + '%' OR
67+
LOWER(u.[Email]) COLLATE Latin1_General_CI_AI LIKE '%' + LOWER(@SearchTerm) COLLATE Latin1_General_CI_AI + '%' OR
68+
LOWER(u.[DisplayName]) COLLATE Latin1_General_CI_AI LIKE '%' + LOWER(@SearchTerm) COLLATE Latin1_General_CI_AI + '%')
69+
AND (@PortalId IS NULL OR up.PortalId = @PortalId);
70+
END;
71+
72+
-- Get paginated results
73+
INSERT INTO @Results (UserID, FirstName, Username, Email, DisplayName, IsSuperUser, RowNumber)
74+
SELECT u.UserID, u.FirstName, u.Username, u.Email, u.DisplayName, u.IsSuperUser,
75+
ROW_NUMBER() OVER (
76+
ORDER BY
77+
CASE WHEN @SortOrder = 'ASC' AND @SortColumn = 'FirstName' THEN u.FirstName END ASC,
78+
CASE WHEN @SortOrder = 'DESC' AND @SortColumn = 'FirstName' THEN u.FirstName END DESC,
79+
CASE WHEN @SortOrder = 'ASC' AND @SortColumn = 'Username' THEN u.UserName END ASC,
80+
CASE WHEN @SortOrder = 'DESC' AND @SortColumn = 'Username' THEN u.UserName END DESC,
81+
CASE WHEN @SortOrder = 'ASC' AND @SortColumn = 'Email' THEN u.Email END ASC,
82+
CASE WHEN @SortOrder = 'DESC' AND @SortColumn = 'Email' THEN u.Email END DESC,
83+
CASE WHEN @SortOrder = 'ASC' AND @SortColumn = 'DisplayName' THEN u.DisplayName END ASC,
84+
CASE WHEN @SortOrder = 'DESC' AND @SortColumn = 'DisplayName' THEN u.DisplayName END DESC
85+
) AS RowNumber
86+
FROM [dbo].[Users] u
87+
LEFT JOIN [dbo].[UserPortals] up ON u.UserID = up.UserID
88+
WHERE
89+
(LOWER(u.[UserName]) COLLATE Latin1_General_CI_AI LIKE '%' + LOWER(@SearchTerm) COLLATE Latin1_General_CI_AI + '%' OR
90+
LOWER(u.[FirstName]) COLLATE Latin1_General_CI_AI LIKE '%' + LOWER(@SearchTerm) COLLATE Latin1_General_CI_AI + '%' OR
91+
LOWER(u.[Email]) COLLATE Latin1_General_CI_AI LIKE '%' + LOWER(@SearchTerm) COLLATE Latin1_General_CI_AI + '%' OR
92+
LOWER(u.[DisplayName]) COLLATE Latin1_General_CI_AI LIKE '%' + LOWER(@SearchTerm) COLLATE Latin1_General_CI_AI + '%')
93+
AND u.IsDeleted = 0
94+
AND (@IsSuperUser IS NULL OR u.IsSuperUser = @IsSuperUser)
95+
AND (@Deleted IS NULL OR up.IsDeleted = @Deleted)
96+
AND (@Authorised IS NULL OR (up.Authorised = @Authorised AND up.IsDeleted = 0))
97+
AND (@PortalId IS NULL OR up.PortalId = @PortalId)
98+
ORDER BY RowNumber;
99+
100+
-- Return paginated results
101+
SELECT UserID, FirstName, Username, Email, DisplayName, IsSuperUser
102+
FROM @Results
103+
WHERE RowNumber BETWEEN (@Offset + 1) AND (@Offset + @PageSize);
104+
END;

Modules/UserManager/Upendo.Modules.UserManager.csproj

+1
Original file line numberDiff line numberDiff line change
@@ -176,6 +176,7 @@
176176
<Content Include="Providers\DataProviders\SqlDataProvider\01.01.01.SqlDataProvider" />
177177
<Content Include="Providers\DataProviders\SqlDataProvider\Uninstall.SqlDataProvider" />
178178
<Content Include="Views\UserManage\BulkDelete.cshtml" />
179+
<Content Include="Providers\DataProviders\SqlDataProvider\01.04.01.SqlDataProvider" />
179180
</ItemGroup>
180181
<ItemGroup>
181182
<Content Include="App_LocalResources\RolesManageController.resx" />

Modules/UserManager/Upendo.UserManager.dnn

+5
Original file line numberDiff line numberDiff line change
@@ -89,6 +89,11 @@
8989
<name>01.01.01.SqlDataProvider</name>
9090
<version>01.01.01</version>
9191
</script>
92+
<script type="Install">
93+
<path>Providers\DataProviders\SqlDataProvider</path>
94+
<name>01.04.01.SqlDataProvider</name>
95+
<version>01.04.01</version>
96+
</script>
9297
<script type="UnInstall">
9398
<path>Providers\DataProviders\SqlDataProvider</path>
9499
<name>Uninstall.SqlDataProvider</name>

Modules/UserManager/Utility/Functions.cs

+20-1
Original file line numberDiff line numberDiff line change
@@ -31,6 +31,8 @@ CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE.
3131
using DotNetNuke.Instrumentation;
3232
using DotNetNuke.Services.Localization;
3333
using DotNetNuke.Security.Roles;
34+
using System.Globalization;
35+
using System.Text;
3436

3537
namespace Upendo.Modules.UserManager.Utility
3638
{
@@ -127,7 +129,7 @@ public static DataTableResponse<Users> GetUsersProcedure(Pagination pagination,
127129
using (var connection = new SqlConnection(connectionString))
128130
{
129131
var pageIndex = pagination.PageIndex == 0 ? 1 : pagination.PageIndex;
130-
var search = string.IsNullOrWhiteSpace(pagination.Search) ? "" : pagination.Search;
132+
var search = RemoveDiacritics(string.IsNullOrWhiteSpace(pagination.Search) ? "" : pagination.Search.Replace(" ", string.Empty).ToLower());
131133
var totalRecordsParameter = new SqlParameter("@TotalRecords", SqlDbType.Int);
132134
totalRecordsParameter.Direction = ParameterDirection.Output;
133135
var command = new SqlCommand("UUM_GetUsers", connection);
@@ -254,5 +256,22 @@ public static bool HasPermission(DotNetNuke.UI.Modules.ModuleInstanceContext Mod
254256
ModulePermissionCollection permissions = ModulePermissionController.GetModulePermissions(moduleId, tabId);
255257
return ModulePermissionController.HasModulePermission(permissions, "EDIT");
256258
}
259+
260+
private static string RemoveDiacritics(string text)
261+
{
262+
var normalizedString = text.Normalize(NormalizationForm.FormD);
263+
var stringBuilder = new StringBuilder();
264+
265+
foreach (var c in normalizedString)
266+
{
267+
var unicodeCategory = CharUnicodeInfo.GetUnicodeCategory(c);
268+
if (unicodeCategory != UnicodeCategory.NonSpacingMark)
269+
{
270+
stringBuilder.Append(c);
271+
}
272+
}
273+
274+
return stringBuilder.ToString().Normalize(NormalizationForm.FormC);
275+
}
257276
}
258277
}

0 commit comments

Comments
 (0)