gabucknall Posted June 15, 2018 Share Posted June 15, 2018 I have a mySQL database that records visits by clients to an advice centre. Various demographic data is gathered including ethnicity. The data is stored in a table 'client' which contains (amongst other fields) clientid and ethnicid. A client can visit any number of times. Their visits are stored in an 'advice' table which contains fields adviceid, clientid, advice date. I wish to extract a table showing totals of each ethnicity during a date period but each client should count only once no matter how many times they visit. The code I am using is: SELECT COUNT(DISTINCT client.clientid), COUNT(DISTINCT CASE WHEN client.ethnicid='5' THEN client.clientid END) AS wh, COUNT(DISTINCT CASE WHEN client.ethnicid='6' THEN client.clientid END) AS EN, COUNT(DISTINCT CASE WHEN client.ethnicid='7' THEN client.clientid END) AS ir, COUNT(DISTINCT CASE WHEN client.ethnicid='8' THEN client.clientid END) AS ow, COUNT(DISTINCT CASE WHEN client.ethnicid='9' THEN client.clientid END) AS bb, COUNT(DISTINCT CASE WHEN client.ethnicid='10' THEN client.clientid END) AS ca, COUNT(DISTINCT CASE WHEN client.ethnicid='11' THEN client.clientid END) AS af, COUNT(DISTINCT CASE WHEN client.ethnicid='12' THEN client.clientid END) AS so, COUNT(DISTINCT CASE WHEN client.ethnicid='13' THEN client.clientid END) AS ob, COUNT(DISTINCT CASE WHEN client.ethnicid='14' THEN client.clientid END) AS aab, COUNT(DISTINCT CASE WHEN client.ethnicid='15' THEN client.clientid END) AS ban, COUNT(DISTINCT CASE WHEN client.ethnicid='16' THEN client.clientid END) AS oas, COUNT(DISTINCT CASE WHEN client.ethnicid='17' THEN client.clientid END) AS chi, COUNT(DISTINCT CASE WHEN client.ethnicid='100' THEN client.clientid END) AS ind, COUNT(DISTINCT CASE WHEN client.ethnicid='101' THEN client.clientid END) AS pak, COUNT(DISTINCT CASE WHEN client.ethnicid='102' THEN client.clientid END) AS mix, COUNT(DISTINCT CASE WHEN client.ethnicid='18' THEN client.clientid END) AS oth, COUNT(DISTINCT CASE WHEN client.ethnicid='19' THEN client.clientid END) AS nk, COUNT(DISTINCT CASE WHEN client.ethnicid='99' THEN client.clientid END) AS na FROM advice INNER JOIN client ON client.clientid=advice.clientid followed by some 'where' parts to limit the date range. This doesn't seem to be giving the correct results and clients are being counted more than once. (I understand that this might not be the most elegant code but I am fairly new to this.) What am I doing wrong? Thanks. Quote Link to comment Share on other sites More sharing options...
Barand Posted June 15, 2018 Share Posted June 15, 2018 Assuming you have an "ethnicity" definition table, for example +----------+-----------------------------------------------+ | ethnicid | description | +----------+-----------------------------------------------+ | 1 | English/Welsh/Scottish/Northern Irish/British | | 2 | Irish | | 3 | Gypsy or Irish Traveller | | 4 | Any other White background | | 5 | White and Black Caribbean | | 6 | White and Black African | | 7 | White and Asian | | 8 | Any other Mixed/Multiple ethnic background | | 9 | Indian | | 10 | Pakistani | | 11 | Bangladeshi | | 12 | Chinese | | 13 | Any other Asian background | | 14 | African | | 15 | Caribbean | | 16 | Any other Black/African/Caribbean background | | 17 | Arab | | 18 | Any other ethnic group | +----------+-----------------------------------------------+ I would SELECT ethnicid , count(clientid) as clients FROM ethnicity e LEFT JOIN ( SELECT DISTINCT c.clientid , c.ethnicid FROM advice a JOIN client c USING (clientid) WHERE advicedate BETWEEN '2018-01-01' AND '2018-03-31' ) ca USING (ethnicid) GROUP BY ethnicid Quote Link to comment Share on other sites More sharing options...
Recommended Posts
Join the conversation
You can post now and register later. If you have an account, sign in now to post with your account.