Parcourir la source

Add date range selector, count, per item cost, link to item transactions, and bug fix related to not clearing row data on sort change to AUCO report

Neal Wilson il y a 9 ans
Parent
révision
aabcf8b559
1 fichiers modifiés avec 168 ajouts et 132 suppressions
  1. 168
    132
      config/Reports/auco.xml

+ 168
- 132
config/Reports/auco.xml Voir le fichier

@@ -2,6 +2,7 @@
2 2
 	<reporttitle>Production:->Average Use and Cost by Origin</reporttitle>
3 3
     <layout type="vertical">
4 4
         <layout type="horizontal">
5
+            <daterange id="dates" initial="23" /><!-- Lifetime -->
5 6
             <label>Sort Order:</label>
6 7
             <sqldrop id="sort" />
7 8
 			<label>Weight Unit:</label>
@@ -29,18 +30,36 @@
29 30
             sortBox.addItem("Avg. Cost Ascending");
30 31
             sortBox.addItem("Avg. Cost Descending");
31 32
             sortBox.currentIndex = QSettings.value("auco_sort", 0);
32
-			var unitBox = findChildObject(this, 'unit');
33
-			unitBox.addItem("Kg");
34
-			unitBox.addItem("Lb");
35
-			unitBox.currentIndex = QSettings.value("script/report_unit", 1);
36
-			unitBox['currentIndexChanged(int)'].connect(function() {
37
-				QSettings.setValue("script/report_unit", unitBox.currentIndex);
38
-				refresh();
39
-			});
40
-			var rowData = new Array();
41
-			var rowIndex;
33
+            var unitBox = findChildObject(this, 'unit');
34
+            unitBox.addItem("Kg");
35
+            unitBox.addItem("Lb");
36
+            unitBox.currentIndex = QSettings.value("script/report_unit", 1);
37
+            unitBox['currentIndexChanged(int)'].connect(function() {
38
+                QSettings.setValue("script/report_unit", unitBox.currentIndex);
39
+                refresh();
40
+            });
41
+            var dateSelect = findChildObject(this, 'dates');
42
+            var dateQuery = new QSqlQuery;
43
+            dateQuery.exec("SELECT time::date FROM transactions WHERE time = (SELECT min(time) FROM transactions) OR time = (SELECT max(time) FROM transactions) ORDER BY time ASC");
44
+            dateQuery.next();
45
+            var lifetimeStartDate = dateQuery.value(0);
46
+            var lifetimeEndDate;
47
+            if(dateQuery.next()) {
48
+                lifetimeEndDate = dateQuery.value(0);
49
+            } else {
50
+                lifetimeEndDate = lifetimeStartDate;
51
+            }
52
+            dateSelect.setLifetimeRange(lifetimeStartDate, lifetimeEndDate);
53
+            dateQuery = dateQuery.invalidate();
54
+            dateSelect.rangeUpdated.connect(refresh);
55
+            var rowData = new Array();
56
+            var rowIndex;
42 57
             function refresh() {
43
-				rowIndex = 0;
58
+                rowData.length = 0;
59
+                var dateRange = dateSelect.currentRange();
60
+                var startDate = dateRange[0];
61
+                var endDate = dateRange[dateRange.length - 1];
62
+                rowIndex = 0;
44 63
                 var buffer = new QBuffer;
45 64
                 buffer.open(3);
46 65
                 var output = new XmlWriter(buffer);
@@ -52,23 +71,23 @@
52 71
                 output.writeTextElement("title", "Recent Use and Cost by Origin");
53 72
                 output.writeEndElement();
54 73
                 output.writeStartElement("body");
55
-                output.writeTextElement("h1", "Average Use and Cost by Origin");
56
-				switch(unitBox.currentIndex)
57
-				{
58
-					case 0:
59
-						output.writeTextElement("p", "This is a report of average rate of use in kilograms per day and cost of unroasted coffee.");
60
-						break;
61
-					case 1:
62
-						output.writeTextElement("p", "This is a report of average rate of use in pounds per day and cost of unroasted coffee.");
63
-						break;
64
-				}
74
+                output.writeTextElement("h1", "Average Use and Cost by Origin " + startDate + " - " + endDate);
75
+                switch(unitBox.currentIndex)
76
+                {
77
+                    case 0:
78
+                        output.writeTextElement("p", "This is a report of average rate of use in kilograms per day and cost of unroasted coffee.");
79
+                            break;
80
+                    case 1:
81
+                        output.writeTextElement("p", "This is a report of average rate of use in pounds per day and cost of unroasted coffee.");
82
+                    break;
83
+                }
65 84
                 output.writeStartElement("table");
66 85
                 output.writeAttribute("rules", "groups");
67 86
                 output.writeAttribute("cellpadding", "3px");
68 87
                 output.writeStartElement("thead");
69 88
                 output.writeStartElement("tr");
70 89
                 output.writeStartElement("th");
71
-                output.writeAttribute("colspan", "8");
90
+                output.writeAttribute("colspan", "9");
72 91
                 output.writeCharacters("Regular Coffees");
73 92
                 output.writeEndElement();
74 93
                 output.writeEndElement();
@@ -76,106 +95,109 @@
76 95
                 output.writeTextElement("th", "Origin");
77 96
                 output.writeTextElement("th", "Avg. Rate");
78 97
                 output.writeTextElement("th", "Avg. Cost");
79
-				output.writeTextElement("th", "Last Cost");
80
-				output.writeTextElement("th", "Last Purchase Date");
81
-				output.writeTextElement("th", "Bag Size (min)");
82
-				output.writeTextElement("th", "Bag Size (max)");
83
-				output.writeTextElement("th", "Bag Size (mean)");
98
+                output.writeTextElement("th", "Last Cost");
99
+                output.writeTextElement("th", "Last Purchase Date");
100
+                output.writeTextElement("th", "Bag Size (min)");
101
+                output.writeTextElement("th", "Bag Size (max)");
102
+                output.writeTextElement("th", "Bag Size (mean)");
103
+                output.writeTextElement("th", "Purchases");
84 104
                 output.writeEndElement();
85 105
                 output.writeEndElement();
86 106
                 output.writeStartElement("tbody");
87 107
                 var query = new QSqlQuery();
88
-				var conversion = 1;
89
-				if(unitBox.currentIndex == 0) {
90
-					conversion = 2.2;
91
-				}
92
-				var orderClause;
93
-				switch(sortBox.currentIndex)
94
-				{
95
-					case 0:
96
-						orderClause = "origin ASC";
97
-						break;
98
-					case 1:
99
-						orderClause = "origin DESC";
100
-						break;
101
-					case 2:
102
-						orderClause = "rate ASC";
103
-						break;
104
-					case 3:
105
-						orderClause = "rate DESC";
106
-						break;
107
-					case 4:
108
-						orderClause = "cost ASC";
109
-						break;
110
-					case 5:
111
-						orderClause = "cost DESC";
112
-						break;
113
-				}
114
-				query.prepare("SELECT DISTINCT origin, (avg(rate)/:conversion)::numeric(10,2) AS rate, (SELECT avg(cost)*:conversion2 FROM purchase WHERE item IN (SELECT id FROM regular_coffees WHERE origin = coffee_history.origin))::numeric(10,2) AS cost, (SELECT avg(cost)*:conversion3 FROM purchase WHERE item IN (SELECT id FROM regular_coffees WHERE origin = coffee_history.origin) AND time = (SELECT max(time) FROM purchase WHERE item IN (SELECT id FROM regular_coffees WHERE origin = coffee_history.origin))), (SELECT max(time)::date FROM purchase WHERE item IN (SELECT id FROM regular_coffees WHERE origin = coffee_history.origin)), (SELECT min(conversion)/:conversion4 FROM lb_bag_conversion WHERE item IN (SELECT id FROM regular_coffees WHERE origin = coffee_history.origin))::numeric(10,2) AS minbag, (SELECT max(conversion)/:conversion5 FROM lb_bag_conversion WHERE item IN (SELECT id FROM regular_coffees WHERE origin = coffee_history.origin))::numeric(10,2) AS maxbag, (SELECT avg(conversion)/:conversion6 FROM lb_bag_conversion WHERE item IN (SELECT id FROM regular_coffees WHERE origin = coffee_history.origin))::numeric(10,2) AS meanbag FROM coffee_history WHERE id IN (SELECT id FROM regular_coffees) GROUP BY origin ORDER BY " + orderClause);
115
-				query.bind(":conversion", conversion);
116
-				query.bind(":conversion2", conversion);
117
-				query.bind(":conversion3", conversion);
118
-				query.bind(":conversion4", conversion);
119
-				query.bind(":conversion5", conversion);
120
-				query.bind(":conversion6", conversion);
121
-				query.exec();
108
+                var conversion = 1;
109
+                if(unitBox.currentIndex == 0) {
110
+                    conversion = 2.2;
111
+                }
112
+                var orderClause;
113
+                switch(sortBox.currentIndex)
114
+                {
115
+                    case 0:
116
+                        orderClause = "origin ASC";
117
+                        break;
118
+                    case 1:
119
+                        orderClause = "origin DESC";
120
+                        break;
121
+                    case 2:
122
+                        orderClause = "rate ASC";
123
+                        break;
124
+                    case 3:
125
+                        orderClause = "rate DESC";
126
+                        break;
127
+                    case 4:
128
+                        orderClause = "cost ASC";
129
+                        break;
130
+                    case 5:
131
+                        orderClause = "cost DESC";
132
+                        break;
133
+                }
134
+                query.prepare("WITH q AS (SELECT id, origin, rate/:c1 AS rate, (SELECT cost*:c2 FROM purchase WHERE item = id) AS cost, (SELECT min(time) FROM purchase WHERE item = id) AS purchase_time, (SELECT conversion/:c3 FROM lb_bag_conversion WHERE item = id) AS bag_weight FROM coffee_history WHERE id IN (SELECT id FROM regular_coffees) AND id IN (SELECT item FROM transactions WHERE time >= :startDate AND time < :endDate::date + interval '1 day')) SELECT DISTINCT origin, avg(rate)::numeric(10,2) AS rate, avg(cost)::numeric(10,2) AS cost, (SELECT (cost*:c4)::numeric(10,2) FROM purchase WHERE item = max(q.id)) AS last_cost, max(purchase_time)::date AS last_purchase, min(bag_weight)::numeric(10,2) AS min_weight, max(bag_weight)::numeric(10,2) AS max_weight, avg(bag_weight)::numeric(10,2) AS mean_weight, count(1) AS n FROM q GROUP BY origin ORDER BY " + orderClause);
135
+                query.bind(":c1", conversion);
136
+                query.bind(":c2", conversion);
137
+                query.bind(":c3", conversion);
138
+                query.bind(":c4", conversion);
139
+                query.bind(":startDate", startDate);
140
+                query.bind(":endDate", endDate);
141
+                query.exec();
122 142
                 while(query.next())
123 143
                 {
124 144
                     output.writeStartElement("tr");
125
-					output.writeAttribute("id", "r" + rowIndex);
126
-					output.writeStartElement("td");
127
-					output.writeStartElement("a");
128
-					output.writeAttribute("href", "typica://script/r" + rowIndex);
129
-					rowIndex++;
130
-					rowData.push(query.value(0));
131
-					output.writeCharacters(query.value(0));
132
-					output.writeEndElement();
133
-					output.writeEndElement();
145
+                    output.writeAttribute("id", "r" + rowIndex);
146
+                    output.writeStartElement("td");
147
+                    output.writeStartElement("a");
148
+                    output.writeAttribute("href", "typica://script/r" + rowIndex);
149
+                    rowIndex++;
150
+                    rowData.push(query.value(0));
151
+                    output.writeCharacters(query.value(0));
152
+                    output.writeEndElement();
153
+                    output.writeEndElement();
134 154
                     output.writeTextElement("td", query.value(1));
135 155
                     output.writeTextElement("td", query.value(2));
136
-					output.writeTextElement("td", query.value(3));
137
-					output.writeTextElement("td", query.value(4));
138
-					output.writeTextElement("td", query.value(5));
139
-					output.writeTextElement("td", query.value(6));
140
-					output.writeTextElement("td", query.value(7));
156
+                    output.writeTextElement("td", query.value(3));
157
+                    output.writeTextElement("td", query.value(4));
158
+                    output.writeTextElement("td", query.value(5));
159
+                    output.writeTextElement("td", query.value(6));
160
+                    output.writeTextElement("td", query.value(7));
161
+                    output.writeTextElement("td", query.value(8));
141 162
                     output.writeEndElement();
142 163
                 }
143 164
                 output.writeStartElement("tr");
144 165
                 output.writeStartElement("th");
145
-                output.writeAttribute("colspan", "8");
166
+                output.writeAttribute("colspan", "9");
146 167
                 output.writeCharacters("Decaffeinated Coffees");
147 168
                 output.writeEndElement();
148 169
                 output.writeEndElement();
149
-				query.prepare("SELECT DISTINCT origin, (avg(rate)/:conversion)::numeric(10,2) AS rate, (SELECT avg(cost)*:conversion2 FROM purchase WHERE item IN (SELECT id FROM decaf_coffees WHERE origin = coffee_history.origin))::numeric(10,2) AS cost, (SELECT avg(cost)*:conversion3 FROM purchase WHERE item IN (SELECT id FROM decaf_coffees WHERE origin = coffee_history.origin) AND time = (SELECT max(time) FROM purchase WHERE item IN (SELECT id FROM decaf_coffees WHERE origin = coffee_history.origin))), (SELECT max(time)::date FROM purchase WHERE item IN (SELECT id FROM decaf_coffees WHERE origin = coffee_history.origin)), (SELECT min(conversion)/:conversion4 FROM lb_bag_conversion WHERE item IN (SELECT id FROM decaf_coffees WHERE origin = coffee_history.origin))::numeric(10,2) AS minbag, (SELECT max(conversion)/:conversion5 FROM lb_bag_conversion WHERE item IN (SELECT id FROM decaf_coffees WHERE origin = coffee_history.origin))::numeric(10,2) AS maxbag, (SELECT avg(conversion)/:conversion6 FROM lb_bag_conversion WHERE item IN (SELECT id FROM decaf_coffees WHERE origin = coffee_history.origin))::numeric(10,2) AS meanbag FROM coffee_history WHERE id IN (SELECT id FROM decaf_coffees) GROUP BY origin ORDER BY " + orderClause);
150
-				query.bind(":conversion", conversion);
151
-				query.bind(":conversion2", conversion);
152
-				query.bind(":conversion3", conversion);
153
-				query.bind(":conversion4", conversion);
154
-				query.bind(":conversion5", conversion);
155
-				query.bind(":conversion6", conversion);
156
-				query.exec();
170
+                query.prepare("WITH q AS (SELECT id, origin, rate/:c1 AS rate, (SELECT cost*:c2 FROM purchase WHERE item = id) AS cost, (SELECT min(time) FROM purchase WHERE item = id) AS purchase_time, (SELECT conversion/:c3 FROM lb_bag_conversion WHERE item = id) AS bag_weight FROM coffee_history WHERE id IN (SELECT id FROM decaf_coffees) AND id IN (SELECT item FROM transactions WHERE time >= :startDate AND time < :endDate::date + interval '1 day')) SELECT DISTINCT origin, avg(rate)::numeric(10,2) AS rate, avg(cost)::numeric(10,2) AS cost, (SELECT (cost*:c4)::numeric(10,2) FROM purchase WHERE item = max(q.id)) AS last_cost, max(purchase_time)::date AS last_purchase, min(bag_weight)::numeric(10,2) AS min_weight, max(bag_weight)::numeric(10,2) AS max_weight, avg(bag_weight)::numeric(10,2) AS mean_weight, count(1) AS n FROM q GROUP BY origin ORDER BY " + orderClause);
171
+                query.bind(":c1", conversion);
172
+                query.bind(":c2", conversion);
173
+                query.bind(":c3", conversion);
174
+                query.bind(":c4", conversion);
175
+                query.bind(":startDate", startDate);
176
+                query.bind(":endDate", endDate);
177
+                query.exec();
157 178
                 while(query.next())
158 179
                 {
159 180
                     output.writeStartElement("tr");
160
-					output.writeAttribute("id", "d" + rowIndex);
161
-					output.writeStartElement("td");
162
-					output.writeStartElement("a");
163
-					output.writeAttribute("href", "typica://script/d" + rowIndex);
164
-					rowIndex++;
165
-					rowData.push(query.value(0));
166
-					output.writeCharacters(query.value(0));
167
-					output.writeEndElement();
168
-					output.writeEndElement();
181
+                    output.writeAttribute("id", "d" + rowIndex);
182
+                    output.writeStartElement("td");
183
+                    output.writeStartElement("a");
184
+                    output.writeAttribute("href", "typica://script/d" + rowIndex);
185
+                    rowIndex++;
186
+                    rowData.push(query.value(0));
187
+                    output.writeCharacters(query.value(0));
188
+                    output.writeEndElement();
189
+                    output.writeEndElement();
169 190
                     output.writeTextElement("td", query.value(1));
170 191
                     output.writeTextElement("td", query.value(2));
171
-					output.writeTextElement("td", query.value(3));
172
-					output.writeTextElement("td", query.value(4));
173
-					output.writeTextElement("td", query.value(5));
174
-					output.writeTextElement("td", query.value(6));
175
-					output.writeTextElement("td", query.value(7));
192
+                    output.writeTextElement("td", query.value(3));
193
+                    output.writeTextElement("td", query.value(4));
194
+                    output.writeTextElement("td", query.value(5));
195
+                    output.writeTextElement("td", query.value(6));
196
+                    output.writeTextElement("td", query.value(7));
197
+                    output.writeTextElement("td", query.value(8));
176 198
                     output.writeEndElement();
177 199
                 }
178
-				query = query.invalidate();
200
+                query = query.invalidate();
179 201
                 output.writeEndElement();
180 202
                 output.writeEndElement();
181 203
                 output.writeEndElement();
@@ -189,39 +211,53 @@
189 211
                 QSettings.setValue("auco_sort", sortBox.currentIndex);
190 212
                 refresh();
191 213
             });
192
-			report.scriptLinkClicked.connect(function(url) {
193
-				var element = new WebElement(report.findFirstElement("#" + url));
194
-				var regular = url[0] == 'r';
195
-				var index = url.slice(1, url.length);
196
-				var tableref;
197
-				if(regular) {
198
-					tableref = "regular_coffees";
199
-				} else {
200
-					tableref = "decaf_coffees";
201
-				}
202
-				var origin = rowData[Number(url.slice(1, url.length))];
203
-				var details = '<tr><td /><td colspan="6"><table><tr><th>Id</th><th>Name</th><th>Rate</th><th>Inventory</th><th>First Use</th><th>Last Use</th></tr>';
204
-				var query = new QSqlQuery();
205
-				query.prepare("SELECT id, name, (rate/:conversion1)::numeric(12,3), (stock/:conversion2)::numeric(12,3), (SELECT min(time)::date FROM use WHERE item = id) AS first_use, (SELECT max(time)::date FROM use WHERE item = id) AS last_use FROM coffee_history WHERE origin = :origin AND id IN (SELECT id FROM " + tableref + ") ORDER BY first_use DESC");
206
-				var conversion = 1;
207
-				if(unitBox.currentIndex == 0) {
208
-					conversion = 2.2;
209
-				}
210
-				query.bind(":conversion1", conversion);
211
-				query.bind(":conversion2", conversion);
212
-				query.bind(":origin", origin);
213
-				query.exec();
214
-				while(query.next()) {
215
-					details += "<tr>";
216
-					for(var i = 0; i < 6; i++) {
217
-						details += "<td>" + query.value(i) + "</td>";
218
-					}
219
-					details += "</tr>";
220
-				}
221
-				query = query.invalidate();
222
-				details += "</table></td></tr>";
223
-				element.appendOutside(details);
224
-			});
214
+            report.scriptLinkClicked.connect(function(url) {
215
+                if(url[0] == 'i') {
216
+                    url = url.slice(1, url.length);
217
+                    var itemReport = createReport("itemtransactions.xml");
218
+                    var sIB = findChildObject(itemReport, 'item');
219
+                    sIB.currentIndex = sIB.findData(url);
220
+                    return;
221
+                }
222
+                var element = new WebElement(report.findFirstElement("#" + url));
223
+                var regular = url[0] == 'r';
224
+                var index = url.slice(1, url.length);
225
+                var tableref;
226
+                if(regular) {
227
+                    tableref = "regular_coffees";
228
+                } else {
229
+                    tableref = "decaf_coffees";
230
+                }
231
+                var origin = rowData[Number(url.slice(1, url.length))];
232
+                var details = '<tr><td /><td colspan="6"><table><tr><th>Id</th><th>Name</th><th>Rate</th><th>Cost</th><th>Inventory</th><th>First Use</th><th>Last Use</th></tr>';
233
+                var query = new QSqlQuery();
234
+                query.prepare("SELECT id, name, (rate/:conversion1)::numeric(12,3), (SELECT (cost*:conversion2)::numeric(12,2) FROM purchase WHERE item = id), (stock/:conversion3)::numeric(12,3), (SELECT min(time)::date FROM use WHERE item = id) AS first_use, (SELECT max(time)::date FROM use WHERE item = id) AS last_use FROM coffee_history WHERE origin = :origin AND id IN (SELECT id FROM " + tableref + ") AND id IN (SELECT item FROM transactions WHERE time >= :startDate AND time < :endDate::date + interval '1 day') ORDER BY first_use DESC");
235
+                var conversion = 1;
236
+                if(unitBox.currentIndex == 0) {
237
+                    conversion = 2.2;
238
+                }
239
+                var dateRange = dateSelect.currentRange();
240
+                var startDate = dateRange[0];
241
+                var endDate = dateRange[dateRange.length - 1];
242
+                query.bind(":conversion1", conversion);
243
+                query.bind(":conversion2", conversion);
244
+                query.bind(":conversion3", conversion);
245
+                query.bind(":origin", origin);
246
+                query.bind(":startDate", startDate);
247
+                query.bind(":endDate", endDate);
248
+                query.exec();
249
+                while(query.next()) {
250
+                    details += "<tr>";
251
+                    details += '<td><a href="typica://script/i' + query.value(0) + '">' + query.value(0) + "</a></td>";
252
+                    for(var i = 1; i < 7; i++) {
253
+                        details += "<td>" + query.value(i) + "</td>";
254
+                    }
255
+                    details += "</tr>";
256
+                }
257
+                query = query.invalidate();
258
+                details += "</table></td></tr>";
259
+                element.appendOutside(details);
260
+            });
225 261
         ]]>
226 262
     </program>
227 263
 </window>

Chargement…
Annuler
Enregistrer