Eminence Posted August 8, 2018 Posted August 8, 2018 Hello, Using SQLite, I was trying to select a specific column with having duplicate entries removed by using the DISTINCT function. Local $sQuery = "SELECT DISTINCT supervisor, COUNT(DISTINCT employee_name) FROM data_db What the above snippet does is just list only one supervisor but with the total count of unique employee names in the whole database when it should be listing out all supervisor entries from the database and list the total count of employees per each supervisors. If I remove the COUNT function, it does list out all unique entries of supervisor names from the list. Attached is a screenshot of an example database as well. Any help will be much appreciated. Thank you!
Danp2 Posted August 8, 2018 Posted August 8, 2018 A typical SQL Select statement would look like this -- SELECT supervisor, COUNT(DISTINCT employee_name) FROM your_db GROUP BY supervisor Eminence 1 Latest Webdriver UDF Release Webdriver Wiki FAQs
Eminence Posted August 8, 2018 Author Posted August 8, 2018 3 hours ago, Danp2 said: A typical SQL Select statement would look like this -- SELECT supervisor, COUNT(DISTINCT employee_name) FROM your_db GROUP BY supervisor There we go. Thanks a bunch!
Eminence Posted August 8, 2018 Author Posted August 8, 2018 (edited) Now I'm trying to count the number of employees per supervisor that has the attendance_status of Absent using this query. Local $sQuery = "SELECT DISTINCT supervisor, COUNT(DISTINCT employee_name), COUNT(attendance_status) FROM data_db WHERE attendance_status = 'ABSENT' GROUP BY supevisor" But what it does is it also affects the second row(total count of the employees name) only showing employees that has the tagging of absent when I just want it to affect the third column. Edited August 8, 2018 by Eminence
Danp2 Posted August 8, 2018 Posted August 8, 2018 There are several different ways to do this. Here's a link that give some possible solutions. https://stackoverflow.com/questions/19046812/multiple-count-for-multiple-conditions-in-one-query-mysql Skysnake and Eminence 1 1 Latest Webdriver UDF Release Webdriver Wiki FAQs
Eminence Posted August 8, 2018 Author Posted August 8, 2018 3 hours ago, Danp2 said: There are several different ways to do this. Here's a link that give some possible solutions. https://stackoverflow.com/questions/19046812/multiple-count-for-multiple-conditions-in-one-query-mysql Thanks! Will check on this.
Eminence Posted August 9, 2018 Author Posted August 9, 2018 Just another quick question related to this, do I need to have a separated column in the database if I want to calculate the difference of the count of the total employees' schedule status tagged as work and the count of the total employees' attendance status tagged as absent? What I want to do is calculate the absenteeism rate per supervisor based on the formula above however, I don' have a column for the absenteeism rate.
Danp2 Posted August 9, 2018 Posted August 9, 2018 If I understand correctly, then you should be able to perform a calculation as part of the overall query. Can you show us your existing SQL statement? Latest Webdriver UDF Release Webdriver Wiki FAQs
Eminence Posted August 9, 2018 Author Posted August 9, 2018 Below is my current SQL statement. I'm still figuring out how to calculate the percentage of the total count of scheduled vs absent employees though. Local $sQuery = "SELECT DISTINCT supervisor, COUNT(DISTINCT employee_name), COUNT(CASE WHEN attendance_status LIKE 'ABSENT' THEN 1 END) AS count1, COUNT(CASE WHEN late_hours > 0.00 THEN 1 END) AS count1 FROM data_db WHERE supervisor != '' GROUP BY supervisor"
Danp2 Posted August 9, 2018 Posted August 9, 2018 You have two different fields named 'count1'. Not sure what's up with that. I would try something like this -- Local $sQuery = "SELECT DISTINCT supervisor, COUNT(DISTINCT employee_name) as emp_count, COUNT(CASE WHEN attendance_status LIKE 'ABSENT' THEN 1 END) AS abs_count, COUNT(CASE WHEN late_hours > 0.00 THEN 1 END) AS late_count, abs_count / emp_count * 100 AS abs_rate FROM data_db WHERE supervisor != '' GROUP BY supervisor" Latest Webdriver UDF Release Webdriver Wiki FAQs
Eminence Posted August 9, 2018 Author Posted August 9, 2018 2 hours ago, Danp2 said: You have two different fields named 'count1'. Not sure what's up with that. I would try something like this -- Local $sQuery = "SELECT DISTINCT supervisor, COUNT(DISTINCT employee_name) as emp_count, COUNT(CASE WHEN attendance_status LIKE 'ABSENT' THEN 1 END) AS abs_count, COUNT(CASE WHEN late_hours > 0.00 THEN 1 END) AS late_count, abs_count / emp_count * 100 AS abs_rate FROM data_db WHERE supervisor != '' GROUP BY supervisor" Thanks @Danp2. After running, it says no such column: abs_count, do I also have to create a column for abs_count in SQLite instead?
Danp2 Posted August 9, 2018 Posted August 9, 2018 Not sure how to advise you from here. I believe the syntax I posted is correct. However, it's possible that SQLite doesn't support it. Latest Webdriver UDF Release Webdriver Wiki FAQs
Eminence Posted August 9, 2018 Author Posted August 9, 2018 3 hours ago, Danp2 said: Not sure how to advise you from here. I believe the syntax I posted is correct. However, it's possible that SQLite doesn't support it. Could be. I'll look into it. Thanks again @Danp2!
jchd Posted August 9, 2018 Posted August 9, 2018 There is very little limit on the complexity of SQL requests in SQLite. What remains unclear is the actual DB schema, the semantics of every column and the meaning of the data stored there. Post the schema and a sample data so that we can build a request satisfying your requirements. Be as clear and formal as possible. This wonderful site allows debugging and testing regular expressions (many flavors available). An absolute must have in your bookmarks.Another excellent RegExp tutorial. Don't forget downloading your copy of up-to-date pcretest.exe and pcregrep.exe hereRegExp tutorial: enough to get startedPCRE v8.33 regexp documentation latest available release and currently implemented in AutoIt beta. SQLitespeed is another feature-rich premier SQLite manager (includes import/export). Well worth a try.SQLite Expert (freeware Personal Edition or payware Pro version) is a very useful SQLite database manager.An excellent eBook covering almost every aspect of SQLite3: a must-read for anyone doing serious work.SQL tutorial (covers "generic" SQL, but most of it applies to SQLite as well)A work-in-progress SQLite3 tutorial. Don't miss other LxyzTHW pages!SQLite official website with full documentation (may be newer than the SQLite library that comes standard with AutoIt)
Eminence Posted August 9, 2018 Author Posted August 9, 2018 (edited) 2 hours ago, jchd said: There is very little limit on the complexity of SQL requests in SQLite. What remains unclear is the actual DB schema, the semantics of every column and the meaning of the data stored there. Post the schema and a sample data so that we can build a request satisfying your requirements. Be as clear and formal as possible. Here's what I have Edited August 9, 2018 by Eminence Corrected database screenshot
jchd Posted August 9, 2018 Posted August 9, 2018 I don't get it. This isn't the schema (list of all DDL statements). Please list all "CREATE TABLE ..." statements. What's the column "attendance_status" you're basing your request on? This wonderful site allows debugging and testing regular expressions (many flavors available). An absolute must have in your bookmarks.Another excellent RegExp tutorial. Don't forget downloading your copy of up-to-date pcretest.exe and pcregrep.exe hereRegExp tutorial: enough to get startedPCRE v8.33 regexp documentation latest available release and currently implemented in AutoIt beta. SQLitespeed is another feature-rich premier SQLite manager (includes import/export). Well worth a try.SQLite Expert (freeware Personal Edition or payware Pro version) is a very useful SQLite database manager.An excellent eBook covering almost every aspect of SQLite3: a must-read for anyone doing serious work.SQL tutorial (covers "generic" SQL, but most of it applies to SQLite as well)A work-in-progress SQLite3 tutorial. Don't miss other LxyzTHW pages!SQLite official website with full documentation (may be newer than the SQLite library that comes standard with AutoIt)
Eminence Posted August 9, 2018 Author Posted August 9, 2018 (edited) CREATE TABLE data_db ( id INTEGER PRIMARY KEY AUTOINCREMENT, employee_number STRING, employee_name STRING, supervisor STRING, date DATETIME, schedule_status STRING, attendance_status STRING, operational_minutes STRING, late_hours STRING ); My bad. Here's the DDL. The data comes from a .CSV file generated from an internal web application. So I'm trying to count the total number of employees' schedule_status tagged as WORK and their attendance_status tagged as ABSENT and from there, calculate the Abs. Rate %. Edited August 9, 2018 by Eminence
Eminence Posted August 9, 2018 Author Posted August 9, 2018 So I tried this: Dividing count of attendance_status tagged with absent over the count of shedule_status tagged with work. Local $sQuery = "SELECT DISTINCT supervisor, COUNT(DISTINCT employee_name) as emp_count, COUNT(CASE WHEN attendance_status LIKE 'ABSENT' THEN 1 END) AS abs_count, COUNT(CASE WHEN late_hours > 0.00 THEN 1 END) AS late_count, (COUNT(CASE WHEN attendance_status IS 'ABSENT' THEN 1 END) / COUNT(CASE WHEN schedule_status IS 'WORK' THEN 1 END) * 100) FROM data_db WHERE supervisor != '' GROUP BY supervisor" It does return a value of 0 though, whereas changing the order to schedule_status over the count of attendance_status it does return a different result. Any ideas?
jchd Posted August 9, 2018 Posted August 9, 2018 Ok I believe I get the picture, more or less. First there are some problems with your table design. 1) SQLite doesn't have datatypes STRING nor DATETIME. Those columns are parsed as being unknown datatypes with affinity BLOB. Probably not what you intended. 2) "operational_minutes" should probably call "operational_hours" 3) Both "operational_minutes" and "late_hours" should be REAL, not STRING (nor TEXT). 4) You can't make further use of result columns aliased. That's why "abs_count" is unknown. 5) You probably don't need to use "autoincrement" for the id primary key. That doesn't mean what you think it means. To fix this I defined a table like this: CREATE TABLE "data_db" ( "id" INTEGER PRIMARY KEY, "employee_number" TEXT, "employee_name" TEXT, "supervisor" TEXT, "date" TEXT, "schedule_status" TEXT, "attendance_status" TEXT, "operational_hours" REAL, "late_hours" REAL); I had to type (you pasted a picture) some random data in: id employee_number employee_name supervisor date schedule_status attendance_status operational_hours late_hours 1 100123 John Doe Bryan McGrath 2018-08-09 WORK WORK 7.47 1.55 2 100124 Jane Doe Bryan McGrath 2018-08-09 WORK ABSENT 0 0 3 178223 Joe Grifith Neil Grant 2018-08-09 WORK WORK 8 0 4 182123 Ryan Banks Summer Harley 2018-08-09 WORK ABSENT 0 0 5 143708 Paul Tanner Summer Harley 2018-08-08 WORK WORK 7.15 0.34 6 075891 Bill Moots Neil Grant 2018-08-09 WORK WORK 8.12 0 7 000156 Shirley Vroot Neil Grant 2018-08-07 WORK ABSENT 0 0 8 000163 Shirley Wok Neil Grant 2018-08-07 WORK WORK 7.52 0 9 542980 Dan Vroot Neil Grant 2018-08-07 WORK WORK 6.45 0 10 514802 Sheila Vroot Neil Grant 2018-08-07 WORK WORK 8.33 1.06 Then this statement should be close to what you want: SELECT supervisor, COUNT(employee_name) emp_count, SUM(CASE WHEN attendance_status LIKE 'ABSENT' THEN 1 else 0 END) abs_count, SUM(CASE WHEN late_hours > 0 THEN 1 else 0 END) late_count, printf('%2.2f', 100.0 * SUM(CASE WHEN attendance_status LIKE 'ABSENT' THEN 1 else 0 END) / COUNT(employee_name)) abs_rate FROM data_db WHERE supervisor != '' GROUP BY supervisor The result then is: supervisor emp_count abs_count late_count abs_rate Bryan McGrath 2 1 1 50.00 Neil Grant 6 1 1 16.67 Summer Harley 2 1 1 50.00 Note that your DB currently contains text instead of numeric values. Eminence 1 This wonderful site allows debugging and testing regular expressions (many flavors available). An absolute must have in your bookmarks.Another excellent RegExp tutorial. Don't forget downloading your copy of up-to-date pcretest.exe and pcregrep.exe hereRegExp tutorial: enough to get startedPCRE v8.33 regexp documentation latest available release and currently implemented in AutoIt beta. SQLitespeed is another feature-rich premier SQLite manager (includes import/export). Well worth a try.SQLite Expert (freeware Personal Edition or payware Pro version) is a very useful SQLite database manager.An excellent eBook covering almost every aspect of SQLite3: a must-read for anyone doing serious work.SQL tutorial (covers "generic" SQL, but most of it applies to SQLite as well)A work-in-progress SQLite3 tutorial. Don't miss other LxyzTHW pages!SQLite official website with full documentation (may be newer than the SQLite library that comes standard with AutoIt)
Eminence Posted August 10, 2018 Author Posted August 10, 2018 Thanks, @jchd! That's a great help, learned as well. It is working as intended now.
Recommended Posts
Create an account or sign in to comment
You need to be a member in order to leave a comment
Create an account
Sign up for a new account in our community. It's easy!
Register a new accountSign in
Already have an account? Sign in here.
Sign In Now