July 8, 2010 (Modified July 9, 2010)
I thought that I would try something a little different today – build an auto-scaling HTML bar chart using nothing more than a SQL statement. I mentioned in this book review that I was impressed with the HTML chart that was included in the book, but I felt that it might be more interesting if the example used absolute positioning, rather than an HTML table. So, I built an example using dynamic positioning that is not based on what appears in that book.
We will use the sample table from this blog article (side note: this is an interesting article that shows how a VBS script can generate a 10046 trace file, and then transform that trace file back into a VBS script), just with the table renamed to T1.
CREATE TABLE T1 AS SELECT DECODE(TRUNC(DBMS_RANDOM.VALUE(0,5)), 0,'MIKE', 1,'ROB', 2,'SAM', 3,'JOE', 4,'ERIC') EMPLOYEE_ID, TRUNC(SYSDATE)-ROUND(DBMS_RANDOM.VALUE(0,1000)) SHIFT_DATE, DECODE(TRUNC(DBMS_RANDOM.VALUE(0,10)), 0,'VAC', 1,'HOL', 2,'BEREAVE', 3,'JURY', 4,'ABS', 5,'EXCUSE', 6,'MIL', 'OTHER') INDIRECT_ID FROM DUAL CONNECT BY LEVEL<=1000; COMMIT;
Now that we have 1000 rows in the sample table, let’s see how many entries fall into each week in the table (the week starts on a Monday) for those indirect entries that are either VAC, ABS, or EXCUSE:
SELECT NEXT_DAY(SHIFT_DATE,'MONDAY')-7 WEEK_OF, COUNT(*) IND FROM T1 WHERE INDIRECT_ID IN ('VAC','ABS','EXCUSE') GROUP BY NEXT_DAY(SHIFT_DATE,'MONDAY')-7 ORDER BY 1;
Your results of course will be different from what follows due to the randomization of the data, but this is what was returned from my database:
WEEK_OF IND --------- --- 08-OCT-07 1 15-OCT-07 2 22-OCT-07 4 29-OCT-07 3 05-NOV-07 3 03-DEC-07 2 10-DEC-07 3 24-DEC-07 2 ... 05-JAN-09 1 12-JAN-09 3 19-JAN-09 7 02-FEB-09 1 ... 21-JUN-10 3 28-JUN-10 2 05-JUL-10 2
The above SQL statement should work for the base query, now we need to start manipulating the data so that we are able to calculate the size and location of the bars in the chart. We will slide the above SQL statement into an inline view:
SELECT WEEK_OF, IND, MAX(IND) OVER () MAX_IND, COUNT(WEEK_OF) OVER () COUNT_WEEK_OF, ROWNUM RN FROM (SELECT NEXT_DAY(SHIFT_DATE,'MONDAY')-7 WEEK_OF, COUNT(*) IND FROM T1 WHERE INDIRECT_ID IN ('VAC','ABS','EXCUSE') GROUP BY NEXT_DAY(SHIFT_DATE,'MONDAY')-7 ORDER BY 1);
In addition to returning the original data from the SQL statement, we are now also returning the maximum data value, the total number of weeks with at least one entry, and a row counter:
WEEK_OF IND MAX_IND COUNT_WEEK_OF RN --------- --- ------- ------------- ----- 08-OCT-07 1 7 126 1 15-OCT-07 2 7 126 2 22-OCT-07 4 7 126 3 29-OCT-07 3 7 126 4 05-NOV-07 3 7 126 5 03-DEC-07 2 7 126 6 10-DEC-07 3 7 126 7 ... 05-JAN-09 1 7 126 57 12-JAN-09 3 7 126 58 19-JAN-09 7 7 126 59 02-FEB-09 1 7 126 60 ... 14-JUN-10 2 7 126 123 21-JUN-10 3 7 126 124 28-JUN-10 2 7 126 125 05-JUL-10 2 7 126 126
Next, we need to calculate the position and size of each of the bars in the chart, so we will again slide the above into an inline view:
SELECT WEEK_OF, IND, MAX_IND, COUNT_WEEK_OF, RN, TRUNC(300 * IND/MAX_IND) BAR_WIDTH, TRUNC(800 * 1/COUNT_WEEK_OF) BAR_HEIGHT, TRUNC(800 * 1/COUNT_WEEK_OF * (RN-1)) BAR_TOP, 100 BAR_LEFT FROM (SELECT WEEK_OF, IND, MAX(IND) OVER () MAX_IND, COUNT(WEEK_OF) OVER () COUNT_WEEK_OF, ROWNUM RN FROM (SELECT NEXT_DAY(SHIFT_DATE,'MONDAY')-7 WEEK_OF, COUNT(*) IND FROM T1 WHERE INDIRECT_ID IN ('VAC','ABS','EXCUSE') GROUP BY NEXT_DAY(SHIFT_DATE,'MONDAY')-7 ORDER BY 1));
You might notice in the above that I specified that the maximum width of the chart will be 300 (pixels) and the maximum height will be 800 (pixels). Here is the output:
WEEK_OF IND MAX_IND COUNT_WEEK_OF RN BAR_WIDTH BAR_HEIGHT BAR_TOP BAR_LEFT --------- --- ------- ------------- ----- ---------- ---------- ------- -------- 08-OCT-07 1 7 126 1 42 6 0 100 15-OCT-07 2 7 126 2 85 6 6 100 22-OCT-07 4 7 126 3 171 6 12 100 29-OCT-07 3 7 126 4 128 6 19 100 05-NOV-07 3 7 126 5 128 6 25 100 03-DEC-07 2 7 126 6 85 6 31 100 10-DEC-07 3 7 126 7 128 6 38 100 24-DEC-07 2 7 126 8 85 6 44 100 ... 05-JAN-09 1 7 126 57 42 6 355 100 12-JAN-09 3 7 126 58 128 6 361 100 19-JAN-09 7 7 126 59 300 6 368 100 02-FEB-09 1 7 126 60 42 6 374 100 ... 14-JUN-10 2 7 126 123 85 6 774 100 21-JUN-10 3 7 126 124 128 6 780 100 28-JUN-10 2 7 126 125 85 6 787 100 05-JUL-10 2 7 126 126 85 6 793 100
Now what? We need to convert the above into HTML using DIV tags to position the bars as calculated. Prior to the first row we need to write a couple of HTML tags to set the page title, and after the last row we need to write a couple more HTML tags to close the BODY and HTML section of the document. The transformed SQL statement looks like this:
SET TRIMSPOOL ON SET LINESIZE 400 SET ECHO OFF SET FEEDBACK OFF SET VERIFY OFF SET PAGESIZE 0 SET SQLPROMPT '' SPOOL C:\CUSTOM_CHART.HTM SELECT DECODE(RN,1,'<html><head><title>Custom Chart</title></head><body>' || CHR(13) || CHR(10),' ') || '<div style="position:absolute;' || 'top:' || TO_CHAR(TRUNC(800 * 1/COUNT_WEEK_OF * (RN-1))) || 'px;' || 'left:' || TO_CHAR(5) || 'px;' || 'width:' || TO_CHAR(100) || 'px;' || 'height:' || TO_CHAR(TRUNC(800 * 1/COUNT_WEEK_OF)) || 'px;' || '"><font size="1px" color="#0000FF">' || TO_CHAR(WEEK_OF,'MM/DD/YY') || REPLACE(' ',' ',CHR(38) || 'nbsp;') || TO_CHAR(IND) || '</font></div>' || '<div style="background:#444466;position:absolute;' || 'top:' || TO_CHAR(TRUNC(800 * 1/COUNT_WEEK_OF * (RN-1))) || 'px;' || 'left:' || TO_CHAR(100) || 'px;' || 'width:' || TO_CHAR(TRUNC(300 * IND/MAX_IND)) || 'px;' || 'height:' || TO_CHAR(TRUNC(800 * 1/COUNT_WEEK_OF)) || 'px;' || '"><font size="1px" color="#FFFFFF"></font></div>' || DECODE(RN,COUNT_WEEK_OF, CHR(13) || CHR(10) || '</body></html>',' ') HTML_LINE FROM (SELECT WEEK_OF, IND, MAX(IND) OVER () MAX_IND, COUNT(WEEK_OF) OVER () COUNT_WEEK_OF, ROWNUM RN FROM (SELECT NEXT_DAY(SHIFT_DATE,'MONDAY')-7 WEEK_OF, COUNT(*) IND FROM T1 WHERE INDIRECT_ID IN ('VAC','ABS','EXCUSE') GROUP BY NEXT_DAY(SHIFT_DATE,'MONDAY')-7 ORDER BY 1)); SPOOL OFF
There is a slight problem with the above, the SQL statement and SPOOL OFF are printed in the resulting HTML file – if someone knows how to avoid that behavior (without placing the above into another script file), I would like to see how it is done (Oracle’s documentation did not help).
This is what the resulting HTML file looks like:
The number of result rows from the query was a bit high (126) so the bars are significantly compressed in height. Just to see what happens, let’s add the following to the WHERE clause in the inner-most inline view:
AND SHIFT_DATE >= TO_DATE('01-JAN-2010','DD-MON-YYYY')
The resulting chart now looks like this:
Of course it is possible to adjust the colors of the font (#0000FF) and the bars (#444466), which are specified in hex in the format of RRGGBB (red green blue). It is also possible to adjust the color of the bars to reflect the value represented by the bar, but that is an exercise for the reader. For those who need to feel creative, it is also possible to display pictures in the bars, but that is also an exercise left for the reader.
—-
Edit: The sample output from the SQL statement displays correctly on Red Hat Enterprise Linux 3 using Firefox 0.8:
Very good post, I’m acually looking into something similar myself. I bought the SQL Recipes book after your review and it’s pretty good, thanks.
One question: What is that strange looking web browser you’re using 😉 Just kidding.
I agree that the SQL Recipes book is a pretty good book as long as you keep in mind that the book is showing you what is possible with SQL statements – but not necessarily showing you exactly the correct way to retrieve some of the information. For people just learning SQL coding, the book is certainly helpful just to come to grasp with the scope of SQL statements on the Oracle platform. I am happy to hear that my review helped.
Regarding the web browser, I considered providing a screen shot of a different web browser just to verify that the output displays as expected, but it just didn’t look right on Windows 95.
Next week I have another article planned that will use multiple vertical oriented bar charts, rather than the single horizontal bar chart. That article, of course, will require more than just a SQL statement.