-
Notifications
You must be signed in to change notification settings - Fork 102
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge remote-tracking branch 'upstream/release-1.5.1-temp' into relea…
…se-1.5.1-temp
- Loading branch information
Showing
9 changed files
with
148 additions
and
15 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
49 changes: 49 additions & 0 deletions
49
db_upgrade_script/mosip_esignet/sql/1.5.0_to_1.5.1_rollback.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,49 @@ | ||
\c mosip_esignet | ||
|
||
CREATE OR REPLACE FUNCTION is_column_jsonb( | ||
p_table_name text, | ||
p_column_name text, | ||
p_schema_name text DEFAULT current_schema() | ||
) RETURNS boolean AS $$ | ||
DECLARE | ||
v_column_type text; | ||
BEGIN | ||
-- Get the column data type | ||
SELECT data_type INTO v_column_type | ||
FROM information_schema.columns | ||
WHERE table_schema = p_schema_name | ||
AND table_name = p_table_name | ||
AND column_name = p_column_name; | ||
|
||
-- Handle case when column doesn't exist | ||
IF v_column_type IS NULL THEN | ||
RAISE EXCEPTION 'Column %.% does not exist', p_table_name, p_column_name; | ||
END IF; | ||
|
||
-- Return true if jsonb, false otherwise | ||
RETURN v_column_type = 'jsonb'; | ||
|
||
EXCEPTION | ||
WHEN undefined_table THEN | ||
RAISE EXCEPTION 'Table %.% does not exist', p_schema_name, p_table_name; | ||
WHEN OTHERS THEN | ||
RAISE EXCEPTION 'Error checking column type: %', SQLERRM; | ||
END; | ||
$$ LANGUAGE plpgsql; | ||
|
||
DO $$ | ||
BEGIN | ||
IF is_column_jsonb('client_detail', 'public_key') THEN | ||
IF EXISTS ( | ||
SELECT 1 FROM information_schema.tables | ||
WHERE table_name='client_detail_migr_bkp' | ||
) THEN | ||
DROP TABLE client_detail; | ||
CREATE TABLE client_detail (LIKE client_detail_migr_bkp including ALL); | ||
INSERT INTO client_detail SELECT * FROM client_detail_migr_bkp; | ||
DROP TABLE client_detail_migr_bkp; | ||
ELSE | ||
RAISE EXCEPTION 'Error: Backup doesn''t exist'; | ||
END IF; | ||
END IF; | ||
END $$ |
71 changes: 71 additions & 0 deletions
71
db_upgrade_script/mosip_esignet/sql/1.5.0_to_1.5.1_upgrade.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,71 @@ | ||
\c mosip_esignet | ||
|
||
CREATE OR REPLACE FUNCTION is_column_jsonb( | ||
p_table_name text, | ||
p_column_name text, | ||
p_schema_name text DEFAULT current_schema() | ||
) RETURNS boolean AS $$ | ||
DECLARE | ||
v_column_type text; | ||
BEGIN | ||
-- Get the column data type | ||
SELECT data_type INTO v_column_type | ||
FROM information_schema.columns | ||
WHERE table_schema = p_schema_name | ||
AND table_name = p_table_name | ||
AND column_name = p_column_name; | ||
|
||
-- Handle case when column doesn't exist | ||
IF v_column_type IS NULL THEN | ||
RAISE EXCEPTION 'Column %.% does not exist', p_table_name, p_column_name; | ||
END IF; | ||
|
||
-- Return true if jsonb, false otherwise | ||
RETURN v_column_type = 'jsonb'; | ||
|
||
EXCEPTION | ||
WHEN undefined_table THEN | ||
RAISE EXCEPTION 'Table %.% does not exist', p_schema_name, p_table_name; | ||
WHEN OTHERS THEN | ||
RAISE EXCEPTION 'Error checking column type: %', SQLERRM; | ||
END; | ||
$$ LANGUAGE plpgsql; | ||
|
||
|
||
DO $$ | ||
BEGIN | ||
IF NOT is_column_jsonb('client_detail', 'public_key') THEN | ||
|
||
-- create backup | ||
DROP TABLE IF EXISTS client_detail_migr_bkp; | ||
CREATE TABLE client_detail_migr_bkp (LIKE client_detail including ALL); | ||
INSERT into client_detail_migr_bkp SELECT * from client_detail; | ||
---- | ||
|
||
ALTER TABLE client_detail ADD COLUMN public_key_new jsonb; | ||
UPDATE client_detail SET public_key_new = public_key::jsonb; | ||
ALTER TABLE client_detail DROP COLUMN public_key; | ||
ALTER TABLE client_detail RENAME COLUMN public_key_new TO public_key; | ||
|
||
-- inactivating clients with same modulus in public key | ||
WITH duplicates AS ( | ||
SELECT public_key->>'n' as modulus | ||
FROM client_detail | ||
WHERE public_key->>'n' IS NOT NULL | ||
GROUP BY public_key->>'n' | ||
HAVING COUNT(*) > 1 | ||
) | ||
UPDATE client_detail SET status='INACTIVE', public_key='{}'::jsonb where id IN ( | ||
SELECT | ||
client_detail.id | ||
FROM client_detail | ||
JOIN duplicates ON client_detail.public_key->>'n' = duplicates.modulus); | ||
---- | ||
|
||
ALTER TABLE client_detail ALTER COLUMN public_key SET NOT NULL; | ||
CREATE UNIQUE INDEX unique_n_value ON client_detail ((public_key->>'n')); | ||
RAISE NOTICE 'Upgrade Successful'; | ||
ELSE | ||
RAISE NOTICE 'Database already uptodate'; | ||
END IF; | ||
END $$ |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters