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: PagoPA-2483 V3 DB debtor fields 2️⃣ ㏈ #278

Open
wants to merge 19 commits into
base: main
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
19 commits
Select commit Hold shift + click to select a range
de7d274
PAGOPA-2483 DB debtor fields: create new fields and enhance them
pagopa-github-bot Dec 16, 2024
73e25e5
PAGOPA-2483 DB debtor fields: fix
pagopa-github-bot Dec 16, 2024
78ed383
Merge branch 'PAGOPA-2483-v3-DB-debtor-fields' of
Dec 17, 2024
80d9750
Merge branch 'main' into PAGOPA-2483-v3-DB-debtor-fields
alessio-acitelli Dec 17, 2024
41b5649
[PAGOPA-2483] v3 DB debtor fields: procedure for standalone transaction
Dec 17, 2024
777f950
Merge branch 'PAGOPA-2483-v3-DB-debtor-fields' of
Dec 18, 2024
88e3942
Merge branch 'PAGOPA-2483-v3-DB-debtor-fields' of
Dec 18, 2024
57bc1f1
Merge branch 'PAGOPA-2483-v3-DB-debtor-fields' of
Dec 18, 2024
32e9916
[PAGOPA-2483] v3 DB debtor fields: update to version 23
Dec 18, 2024
132d892
Merge branch 'PAGOPA-2483-v3-DB-debtor-fields' of
Dec 18, 2024
c1457b8
[PAGOPA-2483] v3 DB debtor fields: added default value
Dec 18, 2024
942916e
Merge branch 'PAGOPA-2483-v3-DB-debtor-fields' of https://github.com/…
Dec 19, 2024
dd66962
Merge branch 'main' into PAGOPA-2483-v3-DB-debtor-fields
alessio-acitelli Dec 19, 2024
dac825f
[PAGOPA-2483] v3 DB debtor fields: only new fields without past data
Dec 19, 2024
4d0f116
[PAGOPA-2483] v3 DB debtor fields: added missing script
Dec 19, 2024
a53c9eb
Merge branch 'PAGOPA-2483-v3-DB-debtor-fields' of https://github.com/…
Dec 19, 2024
e7f8914
Merge branch 'main' into PAGOPA-2483-v3-DB-debtor-fields
alessio-acitelli Dec 19, 2024
83965b6
Merge branch 'main' into PAGOPA-2483-v3-DB-debtor-fields
cap-ang Jan 9, 2025
c868ccb
Merge branch 'main' into PAGOPA-2483-v3-DB-debtor-fields
cap-ang Jan 13, 2025
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
Original file line number Diff line number Diff line change
@@ -0,0 +1,31 @@
-- Primo step: aggiornamento per 'WISP'
DO $$
BEGIN
-- Aggiornamento per 'WISP'
UPDATE payment_position
SET service_type = 'WISP'
WHERE iupd ILIKE 'wisp_%';

EXCEPTION
WHEN OTHERS THEN
-- Gestione dell'errore
RAISE NOTICE 'Errore durante l''aggiornamento per WISP. Tipo di errore: %, Messaggio di errore: %', SQLSTATE, SQLERRM;
RAISE;
END;
$$;

-- Secondo step: aggiornamento per 'ACA'
DO $$
BEGIN
-- Aggiornamento per 'ACA'
UPDATE payment_position
SET service_type = 'ACA'
WHERE iupd ILIKE 'aca_%';

EXCEPTION
WHEN OTHERS THEN
-- Gestione dell'errore
RAISE NOTICE 'Errore durante l''aggiornamento per ACA. Tipo di errore: %, Messaggio di errore: %', SQLSTATE, SQLERRM;
RAISE;
END;
$$;
113 changes: 113 additions & 0 deletions src/main/resources/db/migration/V023__ALTER_PO_DEBTOR_FIELDS.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,113 @@
-- Adding new columns with DEFAULT and NOT NULL constraints in a single ALTER TABLE statement:
-- a. Performance: PostgreSQL optimizes the operation by virtually applying a DEFAULT value to existing rows without physically writing to them, reducing I/O overhead.
-- b. Better for Large Tables: minimizes the risk of performance degradation: PostgreSQL treats the
-- DEFAULT value as a "virtual" value for rows where the column has not been explicitly set.
-- This significantly reduces the amount of time and resources required to add the column,
-- making it more suitable for high-traffic environments or large-scale datasets.

ALTER TABLE payment_option
ADD COLUMN IF NOT EXISTS fiscal_code VARCHAR(255) DEFAULT 'NA' NOT NULL,
ADD COLUMN IF NOT EXISTS full_name VARCHAR(255) DEFAULT 'NA' NOT NULL,
ADD COLUMN IF NOT EXISTS "type" VARCHAR(255) DEFAULT 'F' NOT NULL,
ADD COLUMN IF NOT EXISTS street_name VARCHAR(255),
ADD COLUMN IF NOT EXISTS civic_number VARCHAR(255),
ADD COLUMN IF NOT EXISTS postal_code VARCHAR(255),
ADD COLUMN IF NOT EXISTS city VARCHAR(255),
ADD COLUMN IF NOT EXISTS province VARCHAR(255),
ADD COLUMN IF NOT EXISTS region VARCHAR(255),
ADD COLUMN IF NOT EXISTS country VARCHAR(255),
ADD COLUMN IF NOT EXISTS email VARCHAR(255),
ADD COLUMN IF NOT EXISTS phone VARCHAR(255);

/*

-- The decision was made not to adopt the script version that used a stored procedure
-- to populate the new columns of the 'payment_option' table based on data from the
-- 'payment_position' table. This choice was made because, during a transitional period,
-- the old APIs will still be used to create debtor positions, leading to data inconsistencies
-- between 'payment_position' and 'payment_option'.


-- Step 1: Added columns
ALTER TABLE payment_option
ADD COLUMN IF NOT exists fiscal_code VARCHAR(255),
alessio-acitelli marked this conversation as resolved.
Show resolved Hide resolved
ADD COLUMN IF NOT EXISTS full_name VARCHAR(255),
ADD COLUMN IF NOT EXISTS "type" VARCHAR(255),
ADD COLUMN IF NOT EXISTS street_name VARCHAR(255),
ADD COLUMN IF NOT EXISTS civic_number VARCHAR(255),
ADD COLUMN IF NOT EXISTS postal_code VARCHAR(255),
ADD COLUMN IF NOT EXISTS city VARCHAR(255),
ADD COLUMN IF NOT EXISTS province VARCHAR(255),
ADD COLUMN IF NOT EXISTS region VARCHAR(255),
ADD COLUMN IF NOT EXISTS country VARCHAR(255),
ADD COLUMN IF NOT EXISTS email VARCHAR(255),
ADD COLUMN IF NOT EXISTS phone VARCHAR(255);

-- Step 2: Batch update by procedure to minimize lock
CREATE OR replace PROCEDURE update_payment_option_batch(batch_size INT)
LANGUAGE plpgsql
AS
$$
DECLARE
rows_updated INT;
total_rows_updated INT := 0;
BEGIN
LOOP
-- Perform update in a standalone transaction
WITH rows_to_update AS
(
SELECT po.payment_position_id,
pp.fiscal_code,
pp.full_name,
pp."type",
pp.street_name,
pp.civic_number,
pp.postal_code,
pp.city,
pp.province,
pp.region,
pp.country,
pp.email,
pp.phone
FROM payment_option AS po
JOIN payment_position AS pp
ON po.payment_position_id = pp.id
WHERE po.fiscal_code IS NULL -- To update only the rows not yet processed
LIMIT batch_size )
UPDATE payment_option AS po
SET fiscal_code = rows_to_update.fiscal_code,
full_name = rows_to_update.full_name,
"type" = rows_to_update."type",
street_name = rows_to_update.street_name,
civic_number = rows_to_update.civic_number,
postal_code = rows_to_update.postal_code,
city = rows_to_update.city,
province = rows_to_update.province,
region = rows_to_update.region,
country = rows_to_update.country,
email = rows_to_update.email,
phone = rows_to_update.phone
FROM rows_to_update
WHERE po.payment_position_id = rows_to_update.payment_position_id;

GET diagnostics rows_updated = row_count;
total_rows_updated := total_rows_updated + rows_updated;
COMMIT;
EXIT WHEN rows_updated = 0;
-- Notify batch completion
RAISE notice 'Batch block completed: % updated rows.', rows_updated;
END LOOP;
ALTER TABLE payment_option
ALTER COLUMN fiscal_code SET NOT NULL,
ALTER COLUMN fiscal_code SET DEFAULT 'NA',
ALTER COLUMN full_name SET NOT NULL,
ALTER COLUMN full_name SET DEFAULT 'NA',
ALTER COLUMN "type" SET DEFAULT 'F',
ALTER COLUMN "type" SET NOT NULL;
RAISE NOTICE 'Total rows updated: %', total_rows_updated;
END $$;

CALL update_payment_option_batch(10000);

DROP PROCEDURE IF EXISTS update_payment_option_batch;
*/
Loading