Skip to content

Commit

Permalink
Merge pull request #783 from Som-Energia/fix_llistat_socis_sql
Browse files Browse the repository at this point in the history
Fix llistat socis sql (get first address, check baixa soci)
  • Loading branch information
anxodio authored Dec 19, 2024
2 parents 92f53c2 + 57bb42e commit faef8d2
Showing 1 changed file with 27 additions and 21 deletions.
48 changes: 27 additions & 21 deletions som_polissa_soci/sql/llistat_socis.sql
Original file line number Diff line number Diff line change
@@ -1,22 +1,28 @@
SELECT pc.name categoria,
m.name municipi,
p.ref num_soci,
p.vat nif,
pa.email email,
pa.name nom,
prov.name provincia,
pa.zip codi_postal,
p.lang idioma,
com.name comarca,
ccaa.name comunitat_autonoma
FROM res_partner_address AS pa
LEFT JOIN res_partner AS p ON (p.id=pa.partner_id)
LEFT JOIN res_partner_category_rel AS p__c ON (pa.partner_id=p__c.partner_id)
LEFT JOIN res_partner_category AS pc ON (pc.id=p__c.category_id and pc.name='Soci')
LEFT JOIN res_municipi AS m ON (m.id=pa.id_municipi)
LEFT JOIN res_country_state AS prov ON (prov.id=pa.state_id)
LEFT JOIN res_comunitat_autonoma AS ccaa ON (ccaa.id=prov.comunitat_autonoma)
LEFT JOIN res_comarca AS com ON (com.id=m.comarca)
WHERE pa.active AND p__c.category_id IS NOT NULL AND
p__c.category_id = (SELECT id FROM res_partner_category WHERE name='Soci')
WITH FirstAddress AS (
SELECT pa.*, ROW_NUMBER() OVER (PARTITION BY pa.partner_id ORDER BY pa.id) AS rn
FROM res_partner_address AS pa
WHERE pa.active
)
SELECT
pc.name AS categoria,
m.name AS municipi,
p.ref AS num_soci,
p.vat AS nif,
fa.email AS email,
fa.name AS nom,
prov.name AS provincia,
fa.zip AS codi_postal,
p.lang AS idioma,
com.name AS comarca,
ccaa.name AS comunitat_autonoma
FROM res_partner AS p
INNER JOIN FirstAddress AS fa ON (p.id = fa.partner_id AND fa.rn = 1)
INNER JOIN res_partner_category_rel AS p__c ON (fa.partner_id = p__c.partner_id)
INNER JOIN res_partner_category AS pc ON (pc.id = p__c.category_id AND pc.name = 'Soci')
INNER JOIN somenergia_soci AS ss ON (ss.partner_id = p.id AND ss.baixa IS False)
LEFT JOIN res_municipi AS m ON (m.id = fa.id_municipi)
LEFT JOIN res_country_state AS prov ON (prov.id = fa.state_id)
LEFT JOIN res_comunitat_autonoma AS ccaa ON (ccaa.id = prov.comunitat_autonoma)
LEFT JOIN res_comarca AS com ON (com.id = m.comarca)
WHERE p.active
ORDER BY p.ref

0 comments on commit faef8d2

Please sign in to comment.