Skip to content

Commit

Permalink
Merge pull request #65 from EyeSeeTea/feature/rename-username-8696kv0dn
Browse files Browse the repository at this point in the history
Rename usernames (SQL)
  • Loading branch information
adrianq authored Dec 9, 2024
2 parents 4584e98 + 91c5583 commit f6181b2
Show file tree
Hide file tree
Showing 10 changed files with 327 additions and 3 deletions.
20 changes: 20 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -399,6 +399,26 @@ yarn start users migrate \
}
```

### Rename username

DHIS2 does not support renaming usernames directly. While it is possible to update usernames through the API, this only modifies the main table. References in other tables, which rely on the hardcoded username (not `userinfoid` or `userinfo.uid`), will remain unchanged.

To fully rename a username across all references, you need to execute a SQL script. Start by generating the script using the following command:

```bash
yarn start users rename-username \
--mapping=user1old:user1new,user2old:user2new \
[--dry-run] --output=rename.sql
```

And then run the generated SQL script in your database to perform the actual renaming:

```bash
psql -U dhis dhis2 -f rename.sql
```

Replace `dhis` with your database username and `dhis2` with your database name if they differ. Ensure you have a backup of the database before applying the changes.

## User monitoring

### Users Permissions Fixer and 2FA Reporter
Expand Down
1 change: 1 addition & 0 deletions package.json
Original file line number Diff line number Diff line change
Expand Up @@ -33,6 +33,7 @@
"loglevel": "^1.8.0",
"luxon": "3.4.2",
"nodemailer": "^6.7.5",
"psqlformat": "^1.21.0",
"purify-ts": "2.0.1",
"random-seed": "^0.3.0",
"simple-node-logger": "^21.8.12",
Expand Down
63 changes: 63 additions & 0 deletions src/data/UsernameRenameSqlRepository.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,63 @@
import { Path } from "domain/entities/Base";
import { UsernameRename } from "domain/entities/UsernameRename";
import path from "path";
import fs from "fs";
import { UsernameRenameRepository } from "domain/repositories/UsernameRenameRepository";
import logger from "utils/log";
import _ from "lodash";
import * as psqlformat from "psqlformat";

export class UsernameRenameSqlRepository implements UsernameRenameRepository {
constructor(private sqlFile: Path) {}

async run(mapping: UsernameRename[], options: { dryRun: boolean }): Promise<void> {
if (_.isEmpty(mapping)) {
logger.warn("No usernames to rename");
return;
}

logger.info(`Mapping: ${JSON.stringify(mapping)}`);
const sqlMapping = getSqlForTemporalMappingTable(mapping);
const sqlRename = getRenamingSql();

const fullSql = [
sqlMapping, //
"BEGIN;",
sqlRename,
options.dryRun ? "ROLLBACK;" : "COMMIT;",
].join("\n");

const formattedSql = formatSql(fullSql);
logger.info(`Writing SQL: ${this.sqlFile}`);
fs.writeFileSync(this.sqlFile, formattedSql + "\n");
}
}

function getRenamingSql() {
const sqlPath = path.join(__dirname, "./sql", "rename-usernames.sql");
logger.debug(`Template SQL: ${sqlPath}`);
const sqlRename = fs.readFileSync(sqlPath, "utf8");
return sqlRename;
}

function getSqlForTemporalMappingTable(mapping: UsernameRename[]) {
return `
CREATE TEMP TABLE
username_mapping (old_username TEXT, new_username TEXT);
INSERT INTO
username_mapping (old_username, new_username)
VALUES
${mapping.map(x => `('${x.from}', '${x.to}')`).join(",\n")}
;
`;
}

function formatSql(fullSql: string) {
return psqlformat.formatSql(fullSql, {
commaStart: false,
commaEnd: true,
commaBreak: false,
formatType: true,
noSpaceFunction: true,
});
}
143 changes: 143 additions & 0 deletions src/data/sql/rename-usernames.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,143 @@
-- Functions
--
-- Rename plain string username in 'table_name.column_name'
CREATE OR REPLACE FUNCTION _update_username_string(table_name TEXT, column_name TEXT) RETURNS VOID AS $$
DECLARE rows_updated INTEGER;
BEGIN EXECUTE format(
'UPDATE %I
SET %I = username_mapping.new_username
FROM username_mapping
WHERE %I.%I = username_mapping.old_username',
table_name,
column_name,
table_name,
column_name
);
GET DIAGNOSTICS rows_updated = ROW_COUNT;
RAISE NOTICE '%.%: %',
table_name,
column_name,
rows_updated;
END;
$$ LANGUAGE plpgsql;
--
-- Rename plain string username in aggregated data values if dataElement.valuetype is 'USERNAME'
CREATE OR REPLACE FUNCTION _update_username_values() RETURNS VOID AS $$
DECLARE rows_updated INTEGER;
BEGIN
UPDATE datavalue dv
SET value = username_mapping.new_username
FROM username_mapping,
dataelement de
WHERE dv.dataelementid = de.dataelementid
AND de.valuetype = 'USERNAME'
AND dv.value = username_mapping.old_username;
GET DIAGNOSTICS rows_updated = ROW_COUNT;
RAISE NOTICE 'datavalue.value[dataelement.type="USERNAME"]: %',
rows_updated;
END;
$$ LANGUAGE plpgsql;
---
-- Update string username in events data values if dataElement.valuetype is 'USERNAME'
CREATE OR REPLACE FUNCTION _update_event_datavalues() RETURNS VOID AS $$
DECLARE rows_updated INTEGER;
BEGIN
UPDATE programstageinstance
SET eventdatavalues = jsonb_set(
eventdatavalues,
array [de.uid, 'value'],
to_jsonb(um.new_username::text)
)
FROM dataelement de,
username_mapping um
WHERE de.valuetype = 'USERNAME'
AND programstageinstance.eventdatavalues->de.uid->>'value' = um.old_username;
GET DIAGNOSTICS rows_updated = ROW_COUNT;
RAISE NOTICE 'programstageinstance.eventdatavalues[dataelement.type="USERNAME"]: %',
rows_updated;
END;
$$ LANGUAGE plpgsql;
--
-- Update tracked entity attributes values if the dataElement valuetype is 'USERNAME'
CREATE OR REPLACE FUNCTION _update_tracked_entity_attributes_values() RETURNS VOID AS $$
DECLARE rows_updated INTEGER;
BEGIN WITH updated_values AS (
SELECT teav.trackedentityattributeid,
username_mapping.new_username
FROM trackedentityattributevalue teav
JOIN trackedentityattribute tea ON teav.trackedentityattributeid = tea.trackedentityattributeid
JOIN username_mapping ON teav.value = username_mapping.old_username
WHERE tea.valuetype = 'USERNAME'
)
UPDATE trackedentityattributevalue teav
SET value = updated_values.new_username
FROM updated_values
WHERE teav.trackedentityattributeid = updated_values.trackedentityattributeid;
GET DIAGNOSTICS rows_updated = ROW_COUNT;
RAISE NOTICE 'trackedentityattributevalue.value[trackedentityattribute.type="USERNAME"]: %',
rows_updated;
END;
$$ LANGUAGE plpgsql;
--
-- Rename username in JSONB table_name.column_name (key: "username")
CREATE OR REPLACE FUNCTION _update_username_jsonb(table_name TEXT, column_name TEXT) RETURNS VOID AS $$
DECLARE rows_updated INTEGER;
BEGIN EXECUTE format(
'UPDATE %I
SET %I = jsonb_set(%I, ''{username}'', to_jsonb(username_mapping.new_username::TEXT), true)
FROM username_mapping
WHERE %I->>''username'' = username_mapping.old_username',
table_name,
column_name,
column_name,
column_name
);
GET DIAGNOSTICS rows_updated = ROW_COUNT;
RAISE NOTICE '%.%[username]: %',
table_name,
column_name,
rows_updated;
END;
$$ LANGUAGE plpgsql;
--
-- Actions
--
SELECT _update_username_string('audit', 'createdby');
SELECT _update_username_string('completedatasetregistration', 'lastupdatedby');
SELECT _update_username_string('completedatasetregistration', 'storedby');
SELECT _update_username_string('datastatisticsevent', 'username');
SELECT _update_username_string('datavalue', 'storedby');
SELECT _update_username_string('datavalueaudit', 'modifiedby');
SELECT _update_username_string('deletedobject', 'deleted_by');
SELECT _update_username_string('externalnotificationlogentry', 'triggerby');
SELECT _update_username_string('potentialduplicate', 'createdbyusername');
SELECT _update_username_string('potentialduplicate', 'lastupdatebyusername');
SELECT _update_username_string('programinstance', 'completedby');
SELECT _update_username_jsonb('programinstance', 'createdbyuserinfo');
SELECT _update_username_jsonb('programinstance', 'lastupdatedbyuserinfo');
SELECT _update_username_string('programinstance', 'storedby');
SELECT _update_username_string('programownershiphistory', 'createdby');
SELECT _update_username_string('programstageinstance', 'completedby');
SELECT _update_username_jsonb('programstageinstance', 'createdbyuserinfo');
SELECT _update_username_jsonb('programstageinstance', 'lastupdatedbyuserinfo');
SELECT _update_username_string('programstageinstance', 'storedby');
SELECT _update_username_string('programtempownershipaudit', 'accessedby');
SELECT _update_username_string('trackedentityattributevalue', 'storedby');
SELECT _update_username_string('trackedentityattributevalueaudit', 'modifiedby');
SELECT _update_username_string('trackedentitydatavalueaudit', 'modifiedby');
SELECT _update_username_jsonb('trackedentityinstance', 'createdbyuserinfo');
SELECT _update_username_jsonb('trackedentityinstance', 'lastupdatedbyuserinfo');
SELECT _update_username_string('trackedentityinstance', 'storedby');
SELECT _update_username_string('trackedentityinstanceaudit', 'accessedby');
SELECT _update_username_string('trackedentityprogramowner', 'createdby');
SELECT _update_username_string('userinfo', 'username');
SELECT _update_username_values();
SELECT _update_event_datavalues();
SELECT _update_tracked_entity_attributes_values();
-- Delete all functions
SELECT pg_catalog.pg_get_function_identity_arguments(p.oid) AS arguments,
p.proname AS function_name,
n.nspname AS schema_name
FROM pg_proc p
JOIN pg_namespace n ON p.pronamespace = n.oid
WHERE p.proname LIKE '_update_%';
4 changes: 4 additions & 0 deletions src/domain/entities/UsernameRename.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
export type UsernameRename = {
from: string;
to: string;
};
5 changes: 5 additions & 0 deletions src/domain/repositories/UsernameRenameRepository.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
import { UsernameRename } from "domain/entities/UsernameRename";

export interface UsernameRenameRepository {
run(mapping: UsernameRename[], options: { dryRun: boolean }): Promise<void>;
}
10 changes: 10 additions & 0 deletions src/domain/usecases/RenameUsernamesUseCase.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
import { UsernameRename } from "domain/entities/UsernameRename";
import { UsernameRenameRepository } from "domain/repositories/UsernameRenameRepository";

export class RenameUsernameUseCase {
constructor(private repository: UsernameRenameRepository) {}

async execute(mapping: UsernameRename[], options: { dryRun: boolean }): Promise<void> {
return this.repository.run(mapping, options);
}
}
Original file line number Diff line number Diff line change
@@ -1,4 +1,3 @@
import { UserMonitoringProgramMetadata } from "domain/entities/user-monitoring/common/UserMonitoringProgramMetadata";
import { TwoFactorUser } from "domain/entities/user-monitoring/two-factor-monitoring/TwoFactorUser";
import { TwoFactorUserOptions } from "domain/entities/user-monitoring/two-factor-monitoring/TwoFactorUserOptions";

Expand Down
46 changes: 45 additions & 1 deletion src/scripts/commands/users.ts
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,10 @@ import { StringsSeparatedByCommas, getApiUrlOption, getD2Api } from "scripts/com
import { MigrateUserNameUseCase } from "domain/usecases/MigrateUserNameUseCase";
import { NotificationsEmailRepository } from "data/NotificationsEmailRepository";
import logger from "utils/log";
import { RenameUsernameUseCase } from "domain/usecases/RenameUsernamesUseCase";
import { UsernameRenameSqlRepository } from "data/UsernameRenameSqlRepository";
import { Maybe } from "utils/ts-utils";
import { UsernameRename } from "domain/entities/UsernameRename";

export function getCommand() {
const migrateUser = command({
Expand Down Expand Up @@ -99,8 +103,48 @@ export function getCommand() {
},
});

const renameUsername = command({
name: "Rename username",
description: "Rename occurences of a username in the DHIS2 database",
args: {
mapping: option({
type: string,
long: "mapping",
description: "oldusername:newusername,...",
}),
dryRun: flag({
type: boolean,
long: "dry-run",
description: "The SQL will be executed within a rollback transaction",
}),
sqlFilePath: option({
type: string,
long: "output",
description: "Path to the output file (SQL)",
}),
},
handler: async args => {
const mapping = getMappingFromCommaSeparatedKeyValues(args.mapping);
const repository = new UsernameRenameSqlRepository(args.sqlFilePath);
await new RenameUsernameUseCase(repository).execute(mapping, { dryRun: args.dryRun });
},
});

return subcommands({
name: "users",
cmds: { migrate: migrateUser },
cmds: {
migrate: migrateUser,
"rename-username": renameUsername,
},
});
}

function getMappingFromCommaSeparatedKeyValues(strMapping: string) {
return _(strMapping.split(","))
.map((mapping: string): Maybe<UsernameRename> => {
const [from, to] = mapping.split(":");
return from && to ? { from, to } : undefined;
})
.compact()
.value();
}
Loading

0 comments on commit f6181b2

Please sign in to comment.