Skip to content

Commit

Permalink
Add columns to eligible_households table to keep track of selection s…
Browse files Browse the repository at this point in the history
…tatus. Will have to make breaking changes and change the flow of pre-eligiblity verification runs
  • Loading branch information
kamfosica committed May 4, 2022
1 parent c910cfe commit 6f8ed6f
Show file tree
Hide file tree
Showing 10 changed files with 306 additions and 14 deletions.
2 changes: 1 addition & 1 deletion pom.xml
Original file line number Diff line number Diff line change
Expand Up @@ -7,7 +7,7 @@
<groupId>org.cga</groupId>
<artifactId>sctp</artifactId>
<packaging>pom</packaging>
<version>1.4.3</version>
<version>1.4.4</version>

<parent>
<groupId>org.springframework.boot</groupId>
Expand Down
2 changes: 1 addition & 1 deletion sctp-api/pom.xml
Original file line number Diff line number Diff line change
Expand Up @@ -5,7 +5,7 @@
<parent>
<artifactId>sctp</artifactId>
<groupId>org.cga</groupId>
<version>1.4.3</version>
<version>1.4.4</version>
</parent>
<modelVersion>4.0.0</modelVersion>

Expand Down
2 changes: 1 addition & 1 deletion sctp-core/pom.xml
Original file line number Diff line number Diff line change
Expand Up @@ -5,7 +5,7 @@
<parent>
<artifactId>sctp</artifactId>
<groupId>org.cga</groupId>
<version>1.4.3</version>
<version>1.4.4</version>
</parent>

<modelVersion>4.0.0</modelVersion>
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -38,15 +38,12 @@
* TODO: Review the conversion, at the time of writing Hibernate is using the ORDINAL value
* when mapping to the database. So I (zikani03) have applied a sick sick hack of just re-ordering
* the enum values so that they correspond to some of the stored procedures.
*
*
*
*/
public enum CbtStatus {
NonRecertified(4),
PreEligible(6),
Ineligible(2),
Eligible( 1),
Eligible(1),
Selected(3),
Enrolled(5);

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -36,6 +36,7 @@
import org.hibernate.annotations.Immutable;

import javax.persistence.*;
import java.time.LocalDateTime;
import java.util.List;

@Entity
Expand All @@ -46,6 +47,9 @@ public class EligibleHouseholdDetails {
@Column(name = "household_id")
private Long householdId;

@Column(name = "ml_code")
private String mlCode;

@Column(name = "session_id")
private Long sessionId;

Expand Down Expand Up @@ -91,14 +95,41 @@ public class EligibleHouseholdDetails {
@Column(name = "household_head", length = 201)
private String householdHead;

@Column
private Integer ranking;

@Column(name = "last_cbt_ranking")
private LocalDateTime lastRankingDate;

@Column(name = "selection")
@Convert(disableConversion = true)
@Enumerated(EnumType.STRING)
private CbtStatus selection;

public Integer getRanking() {
return ranking;
}

public LocalDateTime getLastRankingDate() {
return lastRankingDate;
}

public CbtStatus getSelection() {
return selection;
}

public String getMlCode() {
return mlCode;
}

/*@Column(name = "member_details")
@Type(type = "com.vladmihalcea.hibernate.type.json.JsonNodeStringType")
@JsonSubTypes.Type(value = IndividualDetails.class)
private JsonNode memberDetailsJson;
@Type(type = "com.vladmihalcea.hibernate.type.json.JsonNodeStringType")
@JsonSubTypes.Type(value = IndividualDetails.class)
private JsonNode memberDetailsJson;
public JsonNode getMemberDetailsJson() {
return memberDetailsJson;
}*/
public JsonNode getMemberDetailsJson() {
return memberDetailsJson;
}*/
@Column(name = "member_details")
@Convert(converter = HouseholdJsonMemberDataConverter.class)
@JsonIgnore
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,60 @@
DROP VIEW IF EXISTS eligible_households_v;

CREATE VIEW eligible_households_v
AS
SELECT eh.session_id
, h.household_id
, h.ml_code
, h.ubr_code AS form_number
, (SELECT count(id) FROM individuals i WHERE i.household_id = h.household_id) AS members
, l.name AS district
, l.code AS district_code
, l2.name AS ta
, l2.code AS ta_code
, l3.name AS cluster
, l3.code AS cluster_code
, l4.name AS "zone"
, l4.code AS zone_code
, l6.name AS village
, l6.code AS village_code
, h.group_village_head_name AS village_head
, CONCAT(i2.first_name, ' ', i2.last_name) AS household_head
, (SELECT JSON_ARRAYAGG(
JSON_OBJECT(
'id', id
, 'created_at', created_at
, 'deleted_at', deleted_at
, 'modified_at', modified_at
, 'first_name', first_name
, 'last_name', last_name
, 'date_of_birth', date_of_birth
, 'gender', gender
, 'relationship', relationship_to_head
, 'household_code', household_code
, 'household_id', household_id
, 'individual_id', individual_id
, 'id_issue_date', id_issue_date
, 'id_expiry_date', id_expiry_date
, 'phone_number', phone_number
, 'education_level', highest_education_level
, 'grade_level', grade_level
, 'school_name', school_name
, 'disability', disability
, 'orphan_status', orphan_status
, 'fit_for_work', fit_for_work
, 'chronic_illness', chronic_illness
, 'status', status
, 'marital_status', marital_status
))
FROM individuals WHERE household_id = eh.household_id
) AS member_details
FROM eligible_households eh
LEFT JOIN households h ON h.household_id = eh.household_id
LEFT JOIN locations l ON l.code = h.location_code
LEFT JOIN locations l2 ON l2.code = h.ta_code
LEFT JOIN locations l3 ON l3.code = h.cluster_code
LEFT JOIN locations l4 ON l4.code = h.zone_code
LEFT JOIN locations l5 ON l5.code = h.group_village_head_code
LEFT JOIN locations l6 ON l6.code = h.village_code
LEFT JOIN individuals i2 ON i2.household_id = h.household_id AND i2.relationship_to_head = 1
;
Original file line number Diff line number Diff line change
@@ -0,0 +1,63 @@
DROP VIEW IF EXISTS eligible_households_v;

CREATE VIEW eligible_households_v
AS
SELECT eh.session_id
, h.household_id
, h.ml_code
, h.ubr_code AS form_number
, (SELECT count(id) FROM individuals i WHERE i.household_id = h.household_id) AS members
, l.name AS district
, l.code AS district_code
, l2.name AS ta
, l2.code AS ta_code
, l3.name AS cluster
, l3.code AS cluster_code
, l4.name AS "zone"
, l4.code AS zone_code
, l6.name AS village
, l6.code AS village_code
, h.group_village_head_name AS village_head
, "PreEligible" AS selection
, h.cbt_rank AS ranking
, h.last_cbt_ranking
, CONCAT(i2.first_name, ' ', i2.last_name) AS household_head
, (SELECT JSON_ARRAYAGG(
JSON_OBJECT(
'id', id
, 'created_at', created_at
, 'deleted_at', deleted_at
, 'modified_at', modified_at
, 'first_name', first_name
, 'last_name', last_name
, 'date_of_birth', date_of_birth
, 'gender', gender
, 'relationship', relationship_to_head
, 'household_code', household_code
, 'household_id', household_id
, 'individual_id', individual_id
, 'id_issue_date', id_issue_date
, 'id_expiry_date', id_expiry_date
, 'phone_number', phone_number
, 'education_level', highest_education_level
, 'grade_level', grade_level
, 'school_name', school_name
, 'disability', disability
, 'orphan_status', orphan_status
, 'fit_for_work', fit_for_work
, 'chronic_illness', chronic_illness
, 'status', status
, 'marital_status', marital_status
))
FROM individuals WHERE household_id = eh.household_id
) AS member_details
FROM eligible_households eh
LEFT JOIN households h ON h.household_id = eh.household_id
LEFT JOIN locations l ON l.code = h.location_code
LEFT JOIN locations l2 ON l2.code = h.ta_code
LEFT JOIN locations l3 ON l3.code = h.cluster_code
LEFT JOIN locations l4 ON l4.code = h.zone_code
LEFT JOIN locations l5 ON l5.code = h.group_village_head_code
LEFT JOIN locations l6 ON l6.code = h.village_code
LEFT JOIN individuals i2 ON i2.household_id = h.household_id AND i2.relationship_to_head = 1
;
Original file line number Diff line number Diff line change
@@ -0,0 +1,74 @@
DROP VIEW IF EXISTS eligible_households_v;

ALTER table eligible_households
ADD COLUMN ranking int,
ADD COLUMN selection_status varchar(50),
ADD COLUMN second_community_selection_by bigint,
ADD COLUMN second_community_selection_date timestamp,
ADD COLUMN district_community_selection_by bigint,
ADD COLUMN district_community_selection_date timestamp
;

ALTER TABLE eligible_households ADD INDEX(household_id);

CREATE VIEW eligible_households_v
AS
SELECT eh.session_id
, h.household_id
, h.ml_code
, h.ubr_code AS form_number
, (SELECT count(id) FROM individuals i WHERE i.household_id = h.household_id) AS members
, l.name AS district
, l.code AS district_code
, l2.name AS ta
, l2.code AS ta_code
, l3.name AS cluster
, l3.code AS cluster_code
, l4.name AS "zone"
, l4.code AS zone_code
, l6.name AS village
, l6.code AS village_code
, h.group_village_head_name AS village_head
, "PreEligible" AS selection
, h.cbt_rank AS ranking
, h.last_cbt_ranking
, CONCAT(i2.first_name, ' ', i2.last_name) AS household_head
, (SELECT JSON_ARRAYAGG(
JSON_OBJECT(
'id', id
, 'created_at', created_at
, 'deleted_at', deleted_at
, 'modified_at', modified_at
, 'first_name', first_name
, 'last_name', last_name
, 'date_of_birth', date_of_birth
, 'gender', gender
, 'relationship', relationship_to_head
, 'household_code', household_code
, 'household_id', household_id
, 'individual_id', individual_id
, 'id_issue_date', id_issue_date
, 'id_expiry_date', id_expiry_date
, 'phone_number', phone_number
, 'education_level', highest_education_level
, 'grade_level', grade_level
, 'school_name', school_name
, 'disability', disability
, 'orphan_status', orphan_status
, 'fit_for_work', fit_for_work
, 'chronic_illness', chronic_illness
, 'status', status
, 'marital_status', marital_status
))
FROM individuals WHERE household_id = eh.household_id
) AS member_details
FROM eligible_households eh
LEFT JOIN households h ON h.household_id = eh.household_id
LEFT JOIN locations l ON l.code = h.location_code
LEFT JOIN locations l2 ON l2.code = h.ta_code
LEFT JOIN locations l3 ON l3.code = h.cluster_code
LEFT JOIN locations l4 ON l4.code = h.zone_code
LEFT JOIN locations l5 ON l5.code = h.group_village_head_code
LEFT JOIN locations l6 ON l6.code = h.village_code
LEFT JOIN individuals i2 ON i2.household_id = h.household_id AND i2.relationship_to_head = 1
;
Original file line number Diff line number Diff line change
@@ -0,0 +1,67 @@
DROP VIEW IF EXISTS eligible_households_v;

ALTER table eligible_households
ADD COLUMN reason varchar(200) after selection_status
;

CREATE VIEW eligible_households_v
AS
SELECT eh.session_id
, h.household_id
, h.ml_code
, h.ubr_code AS form_number
, (SELECT count(id) FROM individuals i WHERE i.household_id = h.household_id) AS members
, l.name AS district
, l.code AS district_code
, l2.name AS ta
, l2.code AS ta_code
, l3.name AS cluster
, l3.code AS cluster_code
, l4.name AS "zone"
, l4.code AS zone_code
, l6.name AS village
, l6.code AS village_code
, h.group_village_head_name AS village_head
, "PreEligible" AS selection
, h.cbt_rank AS ranking
, h.last_cbt_ranking
, CONCAT(i2.first_name, ' ', i2.last_name) AS household_head
, (SELECT JSON_ARRAYAGG(
JSON_OBJECT(
'id', id
, 'created_at', created_at
, 'deleted_at', deleted_at
, 'modified_at', modified_at
, 'first_name', first_name
, 'last_name', last_name
, 'date_of_birth', date_of_birth
, 'gender', gender
, 'relationship', relationship_to_head
, 'household_code', household_code
, 'household_id', household_id
, 'individual_id', individual_id
, 'id_issue_date', id_issue_date
, 'id_expiry_date', id_expiry_date
, 'phone_number', phone_number
, 'education_level', highest_education_level
, 'grade_level', grade_level
, 'school_name', school_name
, 'disability', disability
, 'orphan_status', orphan_status
, 'fit_for_work', fit_for_work
, 'chronic_illness', chronic_illness
, 'status', status
, 'marital_status', marital_status
))
FROM individuals WHERE household_id = eh.household_id
) AS member_details
FROM eligible_households eh
LEFT JOIN households h ON h.household_id = eh.household_id
LEFT JOIN locations l ON l.code = h.location_code
LEFT JOIN locations l2 ON l2.code = h.ta_code
LEFT JOIN locations l3 ON l3.code = h.cluster_code
LEFT JOIN locations l4 ON l4.code = h.zone_code
LEFT JOIN locations l5 ON l5.code = h.group_village_head_code
LEFT JOIN locations l6 ON l6.code = h.village_code
LEFT JOIN individuals i2 ON i2.household_id = h.household_id AND i2.relationship_to_head = 1
;
2 changes: 1 addition & 1 deletion sctp-mis/pom.xml
Original file line number Diff line number Diff line change
Expand Up @@ -5,7 +5,7 @@
<parent>
<artifactId>sctp</artifactId>
<groupId>org.cga</groupId>
<version>1.4.3</version>
<version>1.4.4</version>
</parent>
<modelVersion>4.0.0</modelVersion>

Expand Down

0 comments on commit 6f8ed6f

Please sign in to comment.