![]() ![]() |
|
![]() ![]() ![]() ![]() |
|
![]() |
![]() 8.7.1 Trouver tous les jumeaux non distribués8.7.1 Trouver tous les jumeaux non distribués Les requêtes suivantes sont utilisées pour sélectionner les couples de jumeaux qui accèderont à la deuxième phase : select concat(p1.id, p1.tvab) + 0 as tvid, concat(p1.christian_nom, " ", p1.surnom) as Nom, p1.postal_code as Code, p1.city as City, pg.abrev as Area, if(td.participation = "Aborted", "A", " ") as A, p1.dead as dead1, l.event as event1, td.suspect as tsuspect1, id.suspect as isuspect1, td.severe as tsevere1, id.severe as isevere1, p2.dead as dead2, l2.event as event2, h2.nurse as nurse2, h2.doctor as doctor2, td2.suspect as tsuspect2, id2.suspect as isuspect2, td2.severe as tsevere2, id2.severe as isevere2, l.finish_date from twin_project as tp /* For Twin 1 */ left join twin_data as td on tp.id = td.id and tp.tvab = td.tvab left join informant_data as id on tp.id = id.id and tp.tvab = id.tvab left join harmony as h on tp.id = h.id and tp.tvab = h.tvab left join lentus as l on tp.id = l.id and tp.tvab = l.tvab /* For Twin 2 */ left join twin_data as td2 on p2.id = td2.id and p2.tvab = td2.tvab left join informant_data as id2 on p2.id = id2.id and p2.tvab = id2.tvab left join harmony as h2 on p2.id = h2.id and p2.tvab = h2.tvab left join lentus as l2 on p2.id = l2.id and p2.tvab = l2.tvab, person_data as p1, person_data as p2, postal_groups as pg where /* p1 gets main twin and p2 gets his/her twin. */ /* ptvab is a field inverted from tvab */ p1.id = tp.id and p1.tvab = tp.tvab and p2.id = p1.id and p2.ptvab = p1.tvab and /* Just the sceening survey */ tp.survey_no = 5 and /* Skip if partner died before 65 but allow emigration (dead=9) */ (p2.dead = 0 or p2.dead = 9 or (p2.dead = 1 and (p2.mort_date = 0 or (((to_days(p2.mort_date) - to_days(p2.naissanceday)) / 365) >= 65)))) and ( /* Twin is suspect */ (td.future_contact = 'Yes' and td.suspect = 2) or /* Twin is suspect - Informant is Blessed */ (td.future_contact = 'Yes' and td.suspect = 1 and id.suspect = 1) or /* No twin - Informant is Blessed */ (ISNULL(td.suspect) and id.suspect = 1 and id.future_contact = 'Yes') or /* Twin broken off - Informant is Blessed */ (td.participation = 'Aborted' and id.suspect = 1 and id.future_contact = 'Yes') or /* Twin broken off - No inform - Have partner */ (td.participation = 'Aborted' and ISNULL(id.suspect) and p2.dead = 0)) and l.event = 'Finished' /* Get at area code */ and substring(p1.postal_code, 1, 2) = pg.code /* Not already distributed */ and (h.nurse is NULL or h.nurse=00 or h.doctor=00) /* Has not refused or been aborted */ and not (h.status = 'Refused' or h.status = 'Aborted' or h.status = 'Died' or h.status = 'Other') order by tvid; Quelques explications s'imposent : concat(p1.id, p1.tvab) + 0 as tvid
On veut trier les valeurs avec la concaténation de
column Ceci identifiera un couple de jumeaux. C'est une clé commune à toutes les tables.
column
Cette colonne identifie un des jumeaux dans un couple. Il prend la valeur de
column
C'est le complémentaire de la colonne précédente. Quand
Cette requête démontre, entre autres choses, comment faire des recherches dans une table à partir de la même table, grce à un regroupement ( (
Toutes les informations ci-dessus existent dans les tables sur les jumeaux. Il y a toujours une clé sur Sur notre serveur de production (une station Sun UltraSPARC 200MHz), cettre requête retourne entre 150 et 200 lignes, et prend moins d'une seconde. Le nombre courant de ligne dans les tables sont les suivants : |