From d940839e9d2e2765bd94b9ce783cd8d3c49c91c1 Mon Sep 17 00:00:00 2001 From: JezzDiego Date: Mon, 25 Nov 2024 16:43:27 -0300 Subject: [PATCH 1/3] add Inconsistent field to AgencyMonthlyInfo and AnnualSummary --- models/monthlyInfo.go | 2 ++ repo/database/dto/annuaISummary.go | 3 +++ repo/database/dto/monthlyInfoDTO.go | 3 +++ repo/database/postgres.go | 28 +++++++++++++++++++++++++--- repo/database/postgres_test.go | 2 ++ 5 files changed, 35 insertions(+), 3 deletions(-) diff --git a/models/monthlyInfo.go b/models/monthlyInfo.go index c90d0c7..e1e42ff 100644 --- a/models/monthlyInfo.go +++ b/models/monthlyInfo.go @@ -37,6 +37,7 @@ type AgencyMonthlyInfo struct { Score *Score `json:"score,omitempty"` Duration float64 `json:"duration,omitempty"` // Crawling duration (seconds) ManualCollection bool `json:"coleta_manual,omitempty"` // If the data was collected manually + Inconsistent bool `json:"inconsistent"` // If the data is inconsistent } type Meta struct { @@ -94,6 +95,7 @@ type AnnualSummary struct { NumMonthsWithData int `json:"months_with_data,omitempty"` Package *Backup `json:"package,omitempty"` ItemSummary ItemSummary `json:"item_summary,omitempty"` + Inconsistent bool `json:"inconsistent,omitempty"` // If the data is inconsistent } type RemmunerationSummary struct { diff --git a/repo/database/dto/annuaISummary.go b/repo/database/dto/annuaISummary.go index d527bd3..4d4d18e 100644 --- a/repo/database/dto/annuaISummary.go +++ b/repo/database/dto/annuaISummary.go @@ -18,6 +18,7 @@ type AnnualSummaryDTO struct { RemunerationsPerCapita float64 `gorm:"column:remuneracoes_membro"` NumMonthsWithData int `gorm:"column:meses_com_dados"` ItemSummary ItemSummary `gorm:"embedded"` + Inconsistent bool `gorm:"column:inconsistente"` } func NewAnnualSummaryDTO(ami models.AnnualSummary) *AnnualSummaryDTO { @@ -44,6 +45,7 @@ func NewAnnualSummaryDTO(ami models.AnnualSummary) *AnnualSummaryDTO { HealthAllowance: ami.ItemSummary.HealthAllowance, Others: ami.ItemSummary.Others, }, + Inconsistent: ami.Inconsistent, } } @@ -71,5 +73,6 @@ func (ami *AnnualSummaryDTO) ConvertToModel() *models.AnnualSummary { HealthAllowance: ami.ItemSummary.HealthAllowance, Others: ami.ItemSummary.Others, }, + Inconsistent: ami.Inconsistent, } } diff --git a/repo/database/dto/monthlyInfoDTO.go b/repo/database/dto/monthlyInfoDTO.go index 18b2f6d..af82645 100644 --- a/repo/database/dto/monthlyInfoDTO.go +++ b/repo/database/dto/monthlyInfoDTO.go @@ -32,6 +32,7 @@ type AgencyMonthlyInfoDTO struct { Meta Score ManualCollection bool `gorm:"column:manual"` // Tempo de execução da coleta em segundos + Inconsistent bool `gorm:"column:inconsistente"` } func (AgencyMonthlyInfoDTO) TableName() string { @@ -133,6 +134,7 @@ func (a AgencyMonthlyInfoDTO) ConvertToModel() (*models.AgencyMonthlyInfo, error Package: &pkg, Duration: a.Duration, ManualCollection: a.ManualCollection, + Inconsistent: a.Inconsistent, }, nil } @@ -212,6 +214,7 @@ func NewAgencyMonthlyInfoDTO(agmi models.AgencyMonthlyInfo) (*AgencyMonthlyInfoD Package: pkg, Duration: agmi.Duration, ManualCollection: agmi.ManualCollection, + Inconsistent: agmi.Inconsistent, }, nil } diff --git a/repo/database/postgres.go b/repo/database/postgres.go index 1fc1d13..76be3c5 100644 --- a/repo/database/postgres.go +++ b/repo/database/postgres.go @@ -284,7 +284,14 @@ func (p *PostgresDB) GetMonthlyInfo(agencies []models.Agency, year int) (map[str for _, agency := range agencies { var dtoAgmis []dto.AgencyMonthlyInfoDTO //Pegando as coletas do postgres, filtrando por órgão, ano e a coleta atual. - m := p.db.Model(&dto.AgencyMonthlyInfoDTO{}) + m := p.db.Model(&dto.AgencyMonthlyInfoDTO{}).Select(`coletas.*, EXISTS ( + SELECT 1 + FROM remuneracoes r + WHERE inconsistente = TRUE + AND r.orgao = coletas.id_orgao + AND r.ano = coletas.ano + and r.mes = coletas.mes + ) AS inconsistente`) m = m.Where("id_orgao = ? AND ano = ? AND atual = TRUE AND (procinfo::text = 'null' OR procinfo IS NULL) ", agency.ID, year) m = m.Order("mes ASC") if err := m.Find(&dtoAgmis).Error; err != nil { @@ -327,7 +334,14 @@ func (p *PostgresDB) GetAnnualSummary(agency string) ([]models.AnnualSummary, er MAX(media_por_membro.salario) AS remuneracao_base_membro, MAX(media_por_membro.beneficios) AS outras_remuneracoes_membro, MAX(media_por_membro.descontos) AS descontos_membro, - MAX(media_por_membro.remuneracao) AS remuneracoes_membro` + MAX(media_por_membro.remuneracao) AS remuneracoes_membro, + EXISTS ( + SELECT 1 + FROM remuneracoes r + WHERE inconsistente = TRUE + AND r.orgao = coletas.id_orgao + AND r.ano = coletas.ano + ) AS inconsistente` join := `LEFT JOIN media_por_membro on coletas.ano = media_por_membro.ano and coletas.id_orgao = media_por_membro.orgao` m := p.db.Model(&dtoAgmi).Select(query).Joins(join) @@ -346,7 +360,15 @@ func (p *PostgresDB) GetAnnualSummary(agency string) ([]models.AnnualSummary, er func (p *PostgresDB) GetOMA(month int, year int, agency string) (*models.AgencyMonthlyInfo, *models.Agency, error) { var dtoAgmi dto.AgencyMonthlyInfoDTO id := fmt.Sprintf("%s/%s/%d", strings.ToLower(agency), dto.AddZeroes(month), year) - m := p.db.Model(dto.AgencyMonthlyInfoDTO{}).Where("id = ? AND atual = true", id).First(&dtoAgmi) + m := p.db.Model(dto.AgencyMonthlyInfoDTO{}).Select(`coletas.*, EXISTS ( + SELECT 1 + FROM remuneracoes r + WHERE inconsistente = TRUE + AND r.orgao = coletas.id_orgao + AND r.ano = coletas.ano + and r.mes = coletas.mes + ) AS inconsistente`) + m = m.Where("id = ? AND atual = true", id).First(&dtoAgmi) if err := m.Error; err != nil { if err == gorm.ErrRecordNotFound { return nil, nil, fmt.Errorf("there is no data with this parameters") diff --git a/repo/database/postgres_test.go b/repo/database/postgres_test.go index 4570a65..a4285c6 100644 --- a/repo/database/postgres_test.go +++ b/repo/database/postgres_test.go @@ -1142,6 +1142,8 @@ func (g getAnnualSummary) testWhenMonthlyInfoExists(t *testing.T) { assert.Equal(t, amis[1].ItemSummary.Vacation, returnedAmis[1].ItemSummary.Vacation) assert.Equal(t, 1000.0, returnedAmis[2].BaseRemunerationPerCapita) assert.Equal(t, 1200.0, returnedAmis[2].OtherRemunerationsPerCapita) + assert.Equal(t, amis[0].Inconsistent, returnedAmis[0].Inconsistent) + assert.Equal(t, false, returnedAmis[0].Inconsistent) truncateTables() } From 8fd1caa7d12ff52b42ad1f9a84875c30a73227be Mon Sep 17 00:00:00 2001 From: Joellensilva Date: Thu, 19 Dec 2024 15:31:17 -0300 Subject: [PATCH 2/3] Corrigindo problema nos testes e otimizando queries --- repo/database/dto/annuaISummary.go | 2 +- repo/database/dto/monthlyInfoDTO.go | 4 +- repo/database/postgres.go | 161 ++++++++++++++++++++-------- 3 files changed, 118 insertions(+), 49 deletions(-) diff --git a/repo/database/dto/annuaISummary.go b/repo/database/dto/annuaISummary.go index 4d4d18e..88d7e80 100644 --- a/repo/database/dto/annuaISummary.go +++ b/repo/database/dto/annuaISummary.go @@ -18,7 +18,7 @@ type AnnualSummaryDTO struct { RemunerationsPerCapita float64 `gorm:"column:remuneracoes_membro"` NumMonthsWithData int `gorm:"column:meses_com_dados"` ItemSummary ItemSummary `gorm:"embedded"` - Inconsistent bool `gorm:"column:inconsistente"` + Inconsistent bool `gorm:"column:inconsistente;<-:false"` } func NewAnnualSummaryDTO(ami models.AnnualSummary) *AnnualSummaryDTO { diff --git a/repo/database/dto/monthlyInfoDTO.go b/repo/database/dto/monthlyInfoDTO.go index af82645..d7e37df 100644 --- a/repo/database/dto/monthlyInfoDTO.go +++ b/repo/database/dto/monthlyInfoDTO.go @@ -31,8 +31,8 @@ type AgencyMonthlyInfoDTO struct { Duration float64 `gorm:"column:duracao_segundos"` // Tempo de execução da coleta em segundos Meta Score - ManualCollection bool `gorm:"column:manual"` // Tempo de execução da coleta em segundos - Inconsistent bool `gorm:"column:inconsistente"` + ManualCollection bool `gorm:"column:manual"` // A coleta foi realizada manualmente? + Inconsistent bool `gorm:"column:inconsistente;<-:false"` } func (AgencyMonthlyInfoDTO) TableName() string { diff --git a/repo/database/postgres.go b/repo/database/postgres.go index 76be3c5..56da037 100644 --- a/repo/database/postgres.go +++ b/repo/database/postgres.go @@ -283,18 +283,34 @@ func (p *PostgresDB) GetMonthlyInfo(agencies []models.Agency, year int) (map[str //Mapeando os órgãos for _, agency := range agencies { var dtoAgmis []dto.AgencyMonthlyInfoDTO - //Pegando as coletas do postgres, filtrando por órgão, ano e a coleta atual. - m := p.db.Model(&dto.AgencyMonthlyInfoDTO{}).Select(`coletas.*, EXISTS ( - SELECT 1 - FROM remuneracoes r - WHERE inconsistente = TRUE - AND r.orgao = coletas.id_orgao - AND r.ano = coletas.ano - and r.mes = coletas.mes - ) AS inconsistente`) - m = m.Where("id_orgao = ? AND ano = ? AND atual = TRUE AND (procinfo::text = 'null' OR procinfo IS NULL) ", agency.ID, year) - m = m.Order("mes ASC") - if err := m.Find(&dtoAgmis).Error; err != nil { + // Pegando as coletas do postgres, filtrando por órgão, ano e a coleta atual. + // GORM não suporta diretamente expressões como CTEs (WITH), mas é possível integrar a query bruta. + // Estamos utilizando essa estratégia a fim de não comprometer o desempenho da query + // devido a junção com a tabela de remuneracoes + query := ` + WITH remuneracoes_inconsistentes AS ( + SELECT DISTINCT orgao, ano, mes + FROM remuneracoes + WHERE inconsistente = TRUE + ) + SELECT c.*, + CASE + WHEN ri.orgao IS NOT NULL THEN TRUE + ELSE FALSE + END AS inconsistente + FROM coletas c + LEFT JOIN remuneracoes_inconsistentes ri + ON ri.orgao = c.id_orgao + AND ri.ano = c.ano + AND ri.mes = c.mes + WHERE c.id_orgao = ? + AND c.ano = ? + AND c.atual = TRUE + AND (c.procinfo::text = 'null' OR c.procinfo IS NULL) + ORDER BY c.mes ASC; + ` + + if err := p.db.Raw(query, agency.ID, year).Scan(&dtoAgmis).Error; err != nil { return nil, fmt.Errorf("error getting monthly info: %q", err) } //Convertendo os DTO's para modelos @@ -310,43 +326,96 @@ func (p *PostgresDB) GetMonthlyInfo(agencies []models.Agency, year int) (map[str } func (p *PostgresDB) GetAnnualSummary(agency string) ([]models.AnnualSummary, error) { - var dtoAgmi dto.AgencyMonthlyInfoDTO + // var dtoAgmi dto.AgencyMonthlyInfoDTO var dtoAmis []dto.AnnualSummaryDTO agency = strings.ToLower(agency) + + // GORM não suporta diretamente expressões como CTEs (WITH), mas é possível integrar a query bruta. + // Estamos utilizando essa estratégia a fim de não comprometer o desempenho da query + // devido a junção com a tabela de remuneracoes query := ` - coletas.ano, - id_orgao, - TRUNC(AVG((sumario -> 'membros')::text::int)) AS media_num_membros, - SUM((sumario -> 'membros')::text::int) AS total_num_membros, - SUM(CAST(sumario -> 'remuneracao_base' ->> 'total' AS DECIMAL)) AS remuneracao_base, - SUM(CAST(sumario -> 'outras_remuneracoes' ->> 'total' AS DECIMAL)) AS outras_remuneracoes, - SUM(CAST(sumario -> 'descontos' ->> 'total' AS DECIMAL)) AS descontos, - SUM(CAST(sumario -> 'remuneracoes' ->> 'total' AS DECIMAL)) AS remuneracoes, - SUM(CAST(sumario -> 'resumo_rubricas' ->> 'auxilio_alimentacao' AS DECIMAL)) AS auxilio_alimentacao, - SUM(CAST(sumario -> 'resumo_rubricas' ->> 'licenca_premio' AS DECIMAL)) AS licenca_premio, - SUM(CAST(sumario -> 'resumo_rubricas' ->> 'indenizacao_de_ferias' AS DECIMAL)) AS indenizacao_de_ferias, - SUM(CAST(sumario -> 'resumo_rubricas' ->> 'gratificacao_natalina' AS DECIMAL)) AS gratificacao_natalina, - SUM(CAST(sumario -> 'resumo_rubricas' ->> 'licenca_compensatoria' AS DECIMAL)) AS licenca_compensatoria, - SUM(CAST(sumario -> 'resumo_rubricas' ->> 'auxilio_saude' AS DECIMAL)) AS auxilio_saude, - SUM(CAST(sumario -> 'resumo_rubricas' ->> 'outras' AS DECIMAL)) AS outras, - SUM(CAST(sumario -> 'resumo_rubricas' ->> 'ferias' AS DECIMAL)) AS ferias, - COUNT(*) AS meses_com_dados, - MAX(media_por_membro.salario) AS remuneracao_base_membro, - MAX(media_por_membro.beneficios) AS outras_remuneracoes_membro, - MAX(media_por_membro.descontos) AS descontos_membro, - MAX(media_por_membro.remuneracao) AS remuneracoes_membro, - EXISTS ( - SELECT 1 - FROM remuneracoes r - WHERE inconsistente = TRUE - AND r.orgao = coletas.id_orgao - AND r.ano = coletas.ano - ) AS inconsistente` - - join := `LEFT JOIN media_por_membro on coletas.ano = media_por_membro.ano and coletas.id_orgao = media_por_membro.orgao` - m := p.db.Model(&dtoAgmi).Select(query).Joins(join) - m = m.Where("id_orgao = ? AND atual = TRUE AND (procinfo::text = 'null' OR procinfo IS NULL) ", agency) - m = m.Group("coletas.ano, id_orgao").Order("coletas.ano ASC") + WITH sumario_processado AS ( + SELECT + ano, + id_orgao, + (sumario ->> 'membros')::INT AS num_membros, + (sumario -> 'remuneracao_base' ->> 'total')::DECIMAL AS remuneracao_base_total, + (sumario -> 'outras_remuneracoes' ->> 'total')::DECIMAL AS outras_remuneracoes_total, + (sumario -> 'descontos' ->> 'total')::DECIMAL AS descontos_total, + (sumario -> 'remuneracoes' ->> 'total')::DECIMAL AS remuneracoes_total, + (sumario -> 'resumo_rubricas' ->> 'auxilio_alimentacao')::DECIMAL AS auxilio_alimentacao, + (sumario -> 'resumo_rubricas' ->> 'licenca_premio')::DECIMAL AS licenca_premio, + (sumario -> 'resumo_rubricas' ->> 'indenizacao_de_ferias')::DECIMAL AS indenizacao_de_ferias, + (sumario -> 'resumo_rubricas' ->> 'gratificacao_natalina')::DECIMAL AS gratificacao_natalina, + (sumario -> 'resumo_rubricas' ->> 'licenca_compensatoria')::DECIMAL AS licenca_compensatoria, + (sumario -> 'resumo_rubricas' ->> 'auxilio_saude')::DECIMAL AS auxilio_saude, + (sumario -> 'resumo_rubricas' ->> 'outras')::DECIMAL AS outras, + (sumario -> 'resumo_rubricas' ->> 'ferias')::DECIMAL AS ferias + FROM coletas + WHERE id_orgao = ? AND atual = TRUE AND (procinfo::TEXT = 'null' OR procinfo IS NULL) + ), + media_membro AS ( + SELECT + ano, + orgao, + MAX(salario) AS remuneracao_base_membro, + MAX(beneficios) AS outras_remuneracoes_membro, + MAX(descontos) AS descontos_membro, + MAX(remuneracao) AS remuneracoes_membro + FROM media_por_membro + WHERE orgao = ? + GROUP BY ano, orgao + ), + remuneracoes_inconsistentes AS ( + SELECT DISTINCT orgao, ano + FROM remuneracoes + WHERE inconsistente = TRUE AND orgao = ? + ) + SELECT + sp.ano, + sp.id_orgao, + TRUNC(AVG(sp.num_membros)) AS media_num_membros, + SUM(sp.num_membros) AS total_num_membros, + SUM(sp.remuneracao_base_total) AS remuneracao_base, + SUM(sp.outras_remuneracoes_total) AS outras_remuneracoes, + SUM(sp.descontos_total) AS descontos, + SUM(sp.remuneracoes_total) AS remuneracoes, + SUM(sp.auxilio_alimentacao) AS auxilio_alimentacao, + SUM(sp.licenca_premio) AS licenca_premio, + SUM(sp.indenizacao_de_ferias) AS indenizacao_de_ferias, + SUM(sp.gratificacao_natalina) AS gratificacao_natalina, + SUM(sp.licenca_compensatoria) AS licenca_compensatoria, + SUM(sp.auxilio_saude) AS auxilio_saude, + SUM(sp.outras) AS outras, + SUM(sp.ferias) AS ferias, + COUNT(*) AS meses_com_dados, + mm.remuneracao_base_membro, + mm.outras_remuneracoes_membro, + mm.descontos_membro, + mm.remuneracoes_membro, + CASE + WHEN ri.orgao IS NOT NULL THEN TRUE + ELSE FALSE + END AS inconsistente + FROM sumario_processado sp + LEFT JOIN media_membro mm + ON sp.ano = mm.ano + AND sp.id_orgao = mm.orgao + LEFT JOIN remuneracoes_inconsistentes ri + ON sp.ano = ri.ano + AND sp.id_orgao = ri.orgao + GROUP BY + sp.ano, + sp.id_orgao, + mm.remuneracao_base_membro, + mm.outras_remuneracoes_membro, + mm.descontos_membro, + mm.remuneracoes_membro, + ri.orgao + ORDER BY sp.ano ASC; + ` + + m := p.db.Raw(query, agency, agency, agency) if err := m.Scan(&dtoAmis).Error; err != nil { return nil, fmt.Errorf("error getting annual monthly info: %q", err) } From f6caec462c9800cb80f1311e9d5f4a624131c3de Mon Sep 17 00:00:00 2001 From: Joellensilva Date: Thu, 19 Dec 2024 15:42:00 -0300 Subject: [PATCH 3/3] atualizando testes --- repo/database/postgres.go | 1 - repo/database/postgres_test.go | 3 +++ 2 files changed, 3 insertions(+), 1 deletion(-) diff --git a/repo/database/postgres.go b/repo/database/postgres.go index 56da037..e3cf2f7 100644 --- a/repo/database/postgres.go +++ b/repo/database/postgres.go @@ -326,7 +326,6 @@ func (p *PostgresDB) GetMonthlyInfo(agencies []models.Agency, year int) (map[str } func (p *PostgresDB) GetAnnualSummary(agency string) ([]models.AnnualSummary, error) { - // var dtoAgmi dto.AgencyMonthlyInfoDTO var dtoAmis []dto.AnnualSummaryDTO agency = strings.ToLower(agency) diff --git a/repo/database/postgres_test.go b/repo/database/postgres_test.go index a4285c6..b45abd4 100644 --- a/repo/database/postgres_test.go +++ b/repo/database/postgres_test.go @@ -788,6 +788,7 @@ func (g getMonthlyInfo) testWhenMonthlyInfoExists(t *testing.T) { Month: 1, CrawlingTimestamp: timestamppb.Now(), ManualCollection: false, + Inconsistent: false, }, { AgencyID: "tjsp", @@ -795,6 +796,7 @@ func (g getMonthlyInfo) testWhenMonthlyInfoExists(t *testing.T) { Month: 1, CrawlingTimestamp: timestamppb.Now(), ManualCollection: true, + Inconsistent: false, }, } if err := insertMonthlyInfos(agmis); err != nil { @@ -1191,6 +1193,7 @@ func (g getOMA) testWhenDataExists(t *testing.T) { assert.Equal(t, agmi.Month, returnedAgmi.Month) assert.Equal(t, agmi.Year, returnedAgmi.Year) assert.Equal(t, agencies[0], *agency) + assert.Equal(t, returnedAgmi.Inconsistent, false) truncateTables() }