Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Feat: ETL Updates Org Users #1612

Merged
merged 5 commits into from
Jan 9, 2025
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
5 changes: 4 additions & 1 deletion etl/nifi_scripts/compliance_report.groovy
Original file line number Diff line number Diff line change
Expand Up @@ -849,6 +849,9 @@ def prepareStatements(Connection conn) {
* @return Inserted compliance_report_id.
*/
def insertComplianceReport(PreparedStatement stmt, Map report, String groupUuid, int version, String supplementalInitiator, String reportingFrequency, Integer currentStatusId, String createUser, String updateUser) {
// Generate nickname based on version
def nickname = (version == 0) ? "Original Report" : "Supplemental Report ${version}"

stmt.setInt(1, report.compliance_period_id)
stmt.setInt(2, report.organization_id)

Expand All @@ -862,7 +865,7 @@ def insertComplianceReport(PreparedStatement stmt, Map report, String groupUuid,
stmt.setInt(5, version)
stmt.setObject(6, supplementalInitiator)
stmt.setString(7, reportingFrequency)
stmt.setString(8, report.nickname)
stmt.setString(8, nickname)
stmt.setString(9, report.supplemental_note)
stmt.setString(10, createUser)
stmt.setTimestamp(11, report.create_timestamp ?: Timestamp.valueOf("1970-01-01 00:00:00"))
Expand Down
88 changes: 74 additions & 14 deletions etl/nifi_scripts/user.groovy
Original file line number Diff line number Diff line change
Expand Up @@ -5,23 +5,83 @@ import groovy.json.JsonSlurper

log.warn('**** STARTING USER ETL ****')

// SQL query to extract user profiles
def userProfileQuery = """
SELECT id as user_profile_id,
keycloak_user_id,
COALESCE(NULLIF(email, ''), '[email protected]') as keycloak_email,
username as keycloak_username,
COALESCE(NULLIF(email, ''), '[email protected]') as email,
title,
phone,
cell_phone as mobile_phone,
first_name,
last_name,
is_active,
CASE WHEN organization_id = 1 THEN NULL ELSE organization_id END as organization_id
FROM public.user;
WITH ranked_users AS (
SELECT
u.id AS user_profile_id,
u.keycloak_user_id,

-- If external_username is empty or null, make it null for easier handling
CASE WHEN COALESCE(NULLIF(ucr.external_username, ''), NULL) IS NULL THEN NULL
ELSE ucr.external_username
END AS raw_external_username,

-- Use a window function to identify duplicates within each external_username group
ROW_NUMBER() OVER (
PARTITION BY COALESCE(NULLIF(ucr.external_username, ''), '___EMPTY___')
ORDER BY
CASE WHEN u.keycloak_user_id IS NOT NULL THEN 0 ELSE 1 END,
u.id
) AS occurrence,

COALESCE(NULLIF(ucr.keycloak_email, ''), u.email) AS keycloak_email,
COALESCE(NULLIF(u.email, ''), '') AS email,
u.title,
u.phone,
u.cell_phone AS mobile_phone,
u.first_name,
u.last_name,
u.is_active,
CASE WHEN u.organization_id = 1 THEN NULL ELSE u.organization_id END AS organization_id
FROM public.user u
LEFT JOIN user_creation_request ucr ON ucr.user_id = u.id
),
resolved_users AS (
SELECT
user_profile_id,
keycloak_user_id,

CASE
-- 1) No external_username => "FIXME<n>"
WHEN raw_external_username IS NULL THEN
CONCAT('FIXME', occurrence)

-- 2) Duplicate external_username => add "_<occurrence>"
WHEN occurrence > 1 THEN
CONCAT(raw_external_username, '_', occurrence)

-- 3) Unique or first occurrence => use raw_external_username
ELSE raw_external_username
END AS keycloak_username,

keycloak_email,
email,
title,
phone,
mobile_phone,
first_name,
last_name,
is_active,
organization_id
FROM ranked_users
)
SELECT
user_profile_id,
keycloak_user_id,
keycloak_username,
keycloak_email,
email,
title,
phone,
mobile_phone,
first_name,
last_name,
is_active,
organization_id
FROM resolved_users;
"""


// SQL query to extract user roles
def userRoleQuery = """
WITH RoleData AS (
Expand Down