Skip to content

Instantly share code, notes, and snippets.

@iamfotx
Last active January 17, 2025 23:51
Show Gist options
  • Save iamfotx/9ea6afaeee806983cfab39b82b67b313 to your computer and use it in GitHub Desktop.
Save iamfotx/9ea6afaeee806983cfab39b82b67b313 to your computer and use it in GitHub Desktop.
TypeORM
export const customLocationRepositoryMethods = {
async findWithFilter(
limit: number,
offset: number,
search: string,
buIds: number[],
order: any,
getEverything: boolean
): Promise<[Location[], number]> {
const managersSortDirection = order['managers'] ?? 'ASC';
let query = dataSource
.createQueryBuilder(Location, 'location')
.leftJoinAndSelect('location.businessUnit', 'businessUnit')
.leftJoin(UserRole, 'roles', 'roles.role = :wm', { wm: Role.WAREHOUSE_MANAGER })
.leftJoinAndMapMany('location.managers', 'location.users', 'locationUsers', 'locationUsers.role = roles.id')
.loadRelationCountAndMap('location.prodCount', 'location.products')
.loadRelationCountAndMap('location.orderCount', 'location.orders')
.where(
` (
location.name LIKE :search OR
location.created LIKE :search OR
businessUnit.id LIKE :search OR
businessUnit.name LIKE :search
)`,
{ search }
)
.addSelect(this.applyNaturalSortOnField('location.name'), 'name')
.addSelect(this.applyNaturalSortOnField('location.ioNumber'), 'ioNumber')
.addSelect(
subQuery =>
subQuery
.select(
`GROUP_CONCAT(
CONCAT(
TRIM(IFNULL(users.firstName, '')),
' ',
TRIM(IFNULL(users.lastName, ''))
)
ORDER BY
TRIM(IFNULL(users.firstName, '')) ${managersSortDirection},
TRIM(IFNULL(users.lastName, '')) ${managersSortDirection}
SEPARATOR ', '
)`
)
.from(UserLocation, 'userLocation')
.innerJoin('userLocation.user', 'users')
.leftJoin(UserRole, 'roles', 'roles.role = :wm', { wm: Role.WAREHOUSE_MANAGER })
.where('userLocation.location = location.id AND users.role = roles.id'),
'managers'
)
.addSelect(
subQuery =>
subQuery
.select('COUNT(*)', 'totalLocationProducts')
.from(LocationProduct, 'locationProducts')
.where('locationProducts.location = location.id'),
'prodCount'
)
.addSelect(
subQuery =>
subQuery
.select('COUNT(*)', 'totalLocationOrders')
.from(Order, 'order')
.where('order.location = location.id'),
'orderCount'
);
if (buIds?.length) {
query = query.andWhere('businessUnit.id IN (:buIds)', { buIds });
}
if (!getEverything) {
query = query.take(limit).skip(offset);
}
return query.orderBy(order).getManyAndCount();
},
// Sorts field by numeric values first, then alphabetically, and finally by alphanumeric characters, handling mixed data types naturally.
applyNaturalSortOnField(field: string): string {
return `
CASE
WHEN TRIM(${field}) REGEXP '^[0-9]+$' THEN 1
WHEN TRIM(${field}) REGEXP '^[A-Za-z]' THEN 2
WHEN TRIM(${field}) REGEXP '^[^A-Za-z0-9]' THEN 4 -- Special characters come last
ELSE 3
END,
CASE
WHEN TRIM(${field}) REGEXP '^[0-9]+$'
THEN CAST(TRIM(${field}) AS UNSIGNED)
ELSE 0
END,
TRIM(
REGEXP_REPLACE(
REGEXP_REPLACE(
LOWER(TRIM(${field})),
'([0-9]+)',
LPAD(CAST(SUBSTRING(REGEXP_REPLACE(TRIM(${field}), '[^0-9]+', ''), 1) AS UNSIGNED), 20, '0')
),
'[^a-z0-9]',
''
)
)
`;
},
}
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment