Typica is a free program for professional coffee roasters. https://typica.us
You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

itemtransactions.xml 22KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366
  1. <window id="item_transactions">
  2. <reporttitle>Inventory:->Item Transactions</reporttitle>
  3. <layout type="vertical">
  4. <layout type="horizontal">
  5. <daterange id="dates" initial="23" /><!-- Lifetime-->
  6. <label>Item:</label>
  7. <sqldrop id="item" data="0" display="1" showdata="true">
  8. <null />
  9. <query>SELECT id, name FROM items WHERE category = 'Coffee: Unroasted' ORDER BY name</query>
  10. </sqldrop>
  11. <label>Weight Unit:</label>
  12. <sqldrop id="unit" />
  13. <stretch />
  14. </layout>
  15. <webview id="report" />
  16. </layout>
  17. <menu name="File">
  18. <item id="print" shortcut="Ctrl+P">Print</item>
  19. </menu>
  20. <program>
  21. <![CDATA[
  22. this.windowTitle = TTR("item_transactions", "Typica - Item Transactions");
  23. var dateSelect = findChildObject(this, 'dates');
  24. var dateQuery = new QSqlQuery();
  25. 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");
  26. dateQuery.next();
  27. var lifetimeStartDate = dateQuery.value(0);
  28. var lifetimeEndDate;
  29. if(dateQuery.next()) {
  30. lifetimeEndDate = dateQuery.value(0);
  31. } else {
  32. lifetimeEndDate = lifetimeStartDate;
  33. }
  34. dateSelect.setLifetimeRange(lifetimeStartDate, lifetimeEndDate);
  35. dateQuery = dateQuery.invalidate();
  36. dateSelect.rangeUpdated.connect(function() {
  37. refresh();
  38. });
  39. var itemBox = findChildObject(this, 'item');
  40. var unitBox = findChildObject(this, 'unit');
  41. unitBox.addItem(TTR("item_transactions", "Kg"));
  42. unitBox.addItem(TTR("item_transactions", "Lb"));
  43. unitBox.currentIndex = QSettings.value("script/report_unit", 1);
  44. unitBox['currentIndexChanged(int)'].connect(function() {
  45. QSettings.setValue("script/report_unit", unitBox.currentIndex);
  46. refresh();
  47. });
  48. var view = findChildObject(this, 'report');
  49. var printMenu = findChildObject(this, 'print');
  50. printMenu.triggered.connect(function() {
  51. view.print();
  52. });
  53. itemBox['currentIndexChanged(int)'].connect(function() {
  54. refresh();
  55. });
  56. function refresh() {
  57. var dateRange = dateSelect.currentRange();
  58. var startDate = dateRange[0];
  59. var endDate = dateRange[dateRange.length - 1];
  60. var buffer = new QBuffer;
  61. buffer.open(3);
  62. var output = new XmlWriter(buffer);
  63. output.writeStartDocument("1.0");
  64. output.writeDTD('<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.1 plus MathML 2.0 plus SVG 1.1//EN" "http://www.w3.org/2002/04/xhtml-math-svg.dtd">');
  65. output.writeStartElement("html");
  66. output.writeAttribute("xmlns", "http://www.w3.org/1999/xhtml");
  67. output.writeStartElement("head");
  68. output.writeTextElement("title", TTR("item_transactions", "Item Transactions"));
  69. output.writeStartElement("script");
  70. var scriptFile = new QFile(QSettings.value("config") + "/Scripts/d3.min.js");
  71. scriptFile.open(1);
  72. output.writeCDATA(scriptFile.readToString());
  73. scriptFile.close();
  74. output.writeEndElement();
  75. output.writeStartElement("style");
  76. output.writeAttribute("type", "text/css");
  77. output.writeCDATA("tr.PURCHASE {background-color: #77FF77}");
  78. output.writeCDATA("tr.USE {background-color: #FFFFFF}");
  79. output.writeCDATA("tr.INVENTORY {background-color: #7777FF}");
  80. output.writeCDATA("tr.SALE {background-color: #FF77FF}");
  81. output.writeCDATA("tr.LOSS {background-color: #FF7777}");
  82. output.writeCDATA("tr.MAKE {background-color: #FFFF77}");
  83. output.writeEndElement(); // style
  84. output.writeEndElement();
  85. output.writeStartElement("body");
  86. var cdt = new Date(Date.now());
  87. output.writeTextElement("p", cdt.toLocaleDateString(TTR("reports", "en-US")) + " " + cdt.toLocaleTimeString(TTR("reports", "en-US")));
  88. output.writeTextElement("h1", TTR("item_transactions", "Item Transactions:"));
  89. output.writeStartElement("table");
  90. output.writeStartElement("tr");
  91. output.writeStartElement("td");
  92. output.writeTextElement("strong", "Item: ")
  93. output.writeTextElement("span", itemBox.currentText);
  94. output.writeEndElement(); // td
  95. var query = new QSqlQuery();
  96. query.prepare("SELECT reference, category FROM items WHERE id = :item");
  97. query.bind(":item", itemBox.currentData());
  98. query.exec();
  99. if(query.next()) {
  100. output.writeStartElement("td");
  101. output.writeTextElement("strong", TTR("item_transactions", "Reference: "));
  102. output.writeTextElement("span", query.value(0));
  103. output.writeEndElement(); // td
  104. output.writeStartElement("td");
  105. output.writeTextElement("strong", TTR("item_transactions", "Category: "));
  106. output.writeTextElement("span", query.value(1));
  107. output.writeEndElement(); //td
  108. output.writeEndElement(); //tr
  109. query.prepare("SELECT origin, region, producer, grade, milling, drying FROM coffees WHERE id = :item");
  110. query.bind(":item", itemBox.currentData());
  111. query.exec();
  112. if(query.next()) {
  113. output.writeStartElement("tr");
  114. output.writeStartElement("td");
  115. output.writeTextElement("strong", TTR("item_transactions", "Origin: "));
  116. output.writeTextElement("span", query.value(0));
  117. output.writeEndElement(); // td
  118. output.writeStartElement("td");
  119. output.writeTextElement("strong", TTR("item_transactions", "Region: "));
  120. output.writeTextElement("span", query.value(1));
  121. output.writeEndElement(); // td
  122. output.writeStartElement("td");
  123. output.writeTextElement("strong", TTR("item_transactions", "Producer: "));
  124. output.writeTextElement("span", query.value(2));
  125. output.writeEndElement(); // td
  126. output.writeEndElement(); // tr
  127. output.writeStartElement("tr");
  128. output.writeStartElement("td");
  129. output.writeTextElement("strong", TTR("item_transactions", "Grade: "));
  130. output.writeTextElement("span", query.value(3));
  131. output.writeEndElement(); // td
  132. output.writeStartElement("td");
  133. output.writeTextElement("strong", TTR("item_transactions", "Milling: "));
  134. output.writeTextElement("span", query.value(4));
  135. output.writeEndElement(); // td
  136. output.writeStartElement("td");
  137. output.writeTextElement("strong", TTR("item_transactions", "Drying: "));
  138. output.writeTextElement("span", query.value(5));
  139. output.writeEndElement(); // td
  140. output.writeEndElement(); // tr
  141. query.prepare("SELECT decaf_method FROM decaf_coffees WHERE id = :item");
  142. query.bind(":item", itemBox.currentData());
  143. query.exec();
  144. if(query.next()) {
  145. output.writeStartElement("tr");
  146. output.writeStartElement("td");
  147. output.writeAttribute("colspan", "3");
  148. output.writeTextElement("strong", TTR("item_transactions", "Decaffeination Method: "));
  149. output.writeTextElement("span", query.value(0));
  150. output.writeEndElement(); // td
  151. output.writeEndElement(); // tr
  152. }
  153. }
  154. output.writeEndElement() // table
  155. output.writeStartElement("div");
  156. output.writeAttribute("id", "chart");
  157. output.writeEndElement();
  158. query.prepare("WITH q AS (SELECT roasted_id, unroasted_id, unroasted_quantity, unroasted_total_quantity, roasted_quantity, generate_subscripts(unroasted_quantity, 1) AS s FROM roasting_log WHERE time >= :sd AND time < :ed ::date + interval '1 day') SELECT (SELECT name FROM items WHERE id = roasted_id) AS name, roasted_id, SUM(unroasted_quantity[s]) AS total, COUNT(unroasted_quantity[s]), SUM((unroasted_quantity[s]/unroasted_total_quantity)*roasted_quantity)::numeric(12,3) AS roast_proportion FROM q WHERE unroasted_id[s] = :item1 GROUP BY roasted_id UNION SELECT 'Green Sales', NULL, SUM(quantity), COUNT(1), NULL FROM sale WHERE item = :item2 UNION SELECT 'Inventory Adjustment', NULL, ((SELECT SUM(quantity) FROM purchase WHERE item = :item3) - (SELECT quantity FROM items WHERE id = :item4) - (SELECT SUM(quantity) FROM all_transactions WHERE type != 'PURCHASE' AND type != 'INVENTORY' AND item = :item5)), (SELECT COUNT(1) FROM inventory WHERE item = :item6), NULL UNION SELECT 'Loss', NULL, SUM(quantity), COUNT(1), NULL FROM loss WHERE item = :item7 UNION SELECT 'Current Inventory', NULL, (SELECT quantity FROM items WHERE id = :item8), NULL, NULL ORDER BY total DESC");
  159. query.bind(":sd", startDate);
  160. query.bind(":ed", endDate);
  161. query.bind(":item1", itemBox.currentData());
  162. query.bind(":item2", itemBox.currentData());
  163. query.bind(":item3", itemBox.currentData());
  164. query.bind(":item4", itemBox.currentData());
  165. query.bind(":item5", itemBox.currentData());
  166. query.bind(":item6", itemBox.currentData());
  167. query.bind(":item7", itemBox.currentData());
  168. query.bind(":item8", itemBox.currentData());
  169. query.exec();
  170. var chartData = "var data = [";
  171. var roastedCoffeeLines = "";
  172. var adjustmentLines = "";
  173. var currentInventoryLine = "";
  174. var conversion = 1;
  175. if(unitBox.currentIndex == 0) {
  176. conversion = 2.2;
  177. }
  178. while(query.next()) {
  179. if(Number(query.value(1)) > 0) {
  180. roastedCoffeeLines += "['" + query.value(0).replace(/\'/g, "\\x27") + "'," + query.value(2) / conversion + "," + query.value(3) + "," + query.value(4) / conversion + "],";
  181. } else if (query.value(0) == "Current Inventory") {
  182. currentInventoryLine = "['Current Inventory'," + query.value(2) / conversion + "," + query.value(3) + "," + query.value(4) / conversion + "]";
  183. } else {
  184. if(Number(query.value(3)) > 0) {
  185. adjustmentLines += "['" + query.value(0) + "'," + query.value(2) / conversion + "," + query.value(3) + "," + query.value(4) / conversion + "],";
  186. }
  187. }
  188. }
  189. chartData = chartData + roastedCoffeeLines + adjustmentLines + currentInventoryLine + "];";
  190. output.writeTextElement("script", chartData);
  191. output.writeStartElement("script");
  192. scriptFile = new QFile(QSettings.value("config") + "/Scripts/greenusechart.js");
  193. scriptFile.open(1);
  194. output.writeCDATA(scriptFile.readToString());
  195. scriptFile.close();
  196. output.writeEndElement();
  197. eval(chartData);
  198. output.writeStartElement("table");
  199. output.writeStartElement("tr");
  200. output.writeTextElement("th", "Item");
  201. output.writeTextElement("th", "Green");
  202. output.writeTextElement("th", "Roasted");
  203. output.writeTextElement("th", "Transactions");
  204. output.writeEndElement();
  205. for(var r = 0; r < data.length; r++)
  206. {
  207. output.writeStartElement("tr");
  208. output.writeTextElement("td", data[r][0]);
  209. output.writeTextElement("td", data[r][1]);
  210. output.writeTextElement("td", data[r][3]);
  211. output.writeTextElement("td", data[r][2]);
  212. output.writeEndElement();
  213. }
  214. output.writeStartElement("tr");
  215. output.writeTextElement("th", "Totals:");
  216. output.writeTextElement("td", data.reduce(function(prev, current){
  217. return +(current[1]) + prev;
  218. }, 0));
  219. output.writeTextElement("td", data.reduce(function(prev, current){
  220. return +(current[3]) + prev;
  221. }, 0));
  222. output.writeTextElement("td", data.reduce(function(prev, current){
  223. return +(current[2]) + prev;
  224. }, 0));
  225. output.writeEndElement();
  226. output.writeEndElement();
  227. query.prepare("SELECT time::date, type, quantity / :c1, balance / :c2, (SELECT files FROM roasting_log WHERE roasting_log.time = item_history.time AND item = ANY(unroasted_id)), (SELECT invoice_id FROM invoice_items WHERE item = item_id AND item_history.type = 'PURCHASE'), (SELECT vendor || ' ' || invoice FROM invoices WHERE id = (SELECT invoice_id FROM invoice_items WHERE item = item_id AND item_history.type = 'PURCHASE')), (SELECT name FROM items WHERE id = (SELECT roasted_id FROM roasting_log WHERE roasting_log.time = item_history.time AND item = ANY(unroasted_id))), customer, reason, (SELECT person FROM transactions WHERE time = item_history.time AND item = item_history.item), (SELECT machine || '@' || time FROM roasting_log WHERE roasting_log.time = item_history.time AND item = ANY(unroasted_id)) AS link FROM item_history(:item) WHERE time >= :sd AND time < :ed ::date + interval '1 day'");
  228. query.bind(":sd", startDate);
  229. query.bind(":ed", endDate);
  230. switch(unitBox.currentIndex)
  231. {
  232. case 0:
  233. query.bind(":c1", 2.2);
  234. query.bind(":c2", 2.2);
  235. break;
  236. case 1:
  237. query.bind(":c1", 1);
  238. query.bind(":c2", 1);
  239. break;
  240. }
  241. query.bind(":item", itemBox.currentData());
  242. query.exec();
  243. output.writeStartElement("table");
  244. output.writeStartElement("tr");
  245. output.writeTextElement("th", TTR("item_transactions", "Date"));
  246. output.writeTextElement("th", TTR("item_transactions", "Type"));
  247. output.writeTextElement("th", TTR("item_transactions", "Quantity"));
  248. output.writeTextElement("th", TTR("item_transactions", "Balance"));
  249. output.writeTextElement("th", TTR("item_transactions", "Record"));
  250. output.writeTextElement("th", TTR("item_transactions", "Person"));
  251. output.writeEndElement(); // tr
  252. var prev_balance = "0";
  253. var prev_prec = 0;
  254. var cur_prec = 0;
  255. var max_prec = 3;
  256. while(query.next()) {
  257. output.writeStartElement("tr");
  258. output.writeAttribute("class", query.value(1));
  259. output.writeTextElement("td", query.value(0));
  260. output.writeTextElement("td", query.value(1));
  261. var split = prev_balance.split('.');
  262. if(split.length > 1) {
  263. prev_prec = split[1].length;
  264. } else {
  265. prev_prec = 0;
  266. }
  267. split = query.value(2).split('.');
  268. if(split.length > 1) {
  269. cur_prec = split[1].length;
  270. } else {
  271. cur_prec = 0;
  272. }
  273. var prec = prev_prec > cur_prec ? prev_prec : cur_prec;
  274. var prec = (prec > max_prec ? max_prec : prec);
  275. if(query.value(1) == "INVENTORY") {
  276. output.writeTextElement("td", (Number(query.value(2)) - Number(prev_balance)).toFixed(prec));
  277. } else {
  278. output.writeTextElement("td", (Number(query.value(2)).toFixed(prec)));
  279. }
  280. output.writeTextElement("td", (Number(query.value(3)).toFixed(prec)));
  281. prev_balance = query.value(3);
  282. if(query.value(1) == "PURCHASE") {
  283. output.writeStartElement("td");
  284. output.writeStartElement("a");
  285. output.writeAttribute("href", "typica://script/i" + query.value(5));
  286. output.writeCDATA(query.value(6) + " (" + query.value(5) + ")");
  287. output.writeEndElement();
  288. output.writeEndElement();
  289. } else if(query.value(1) == "USE") {
  290. output.writeStartElement("td");
  291. output.writeStartElement("a");
  292. output.writeAttribute("href", "typica://script/b/" + query.value(11));
  293. output.writeCDATA(query.value(7) + " " + query.value(4));
  294. output.writeEndElement();
  295. output.writeEndElement();
  296. } else if(query.value(1) == "LOSS") {
  297. output.writeTextElement("td", query.value(9));
  298. } else if(query.value(1) == "SALE") {
  299. output.writeTextElement("td", query.value(8));
  300. } else {
  301. output.writeTextElement("td", "");
  302. }
  303. output.writeTextElement("td", query.value(10));
  304. output.writeEndElement(); // tr
  305. }
  306. output.writeEndElement(); // table
  307. /* Put the rest of the report here. No sense running queries if
  308. the item doesn't exist. */
  309. } else {
  310. /* Close tags if item data not found. */
  311. output.writeEndElement(); // tr
  312. output.writeEndElement(); // table
  313. }
  314. output.writeEndElement(); // body
  315. output.writeEndElement(); // html
  316. output.writeEndDocument();
  317. view.setContent(buffer);
  318. buffer.close();
  319. query = query.invalidate();
  320. }
  321. if(itemBox.currentData() > 0) {
  322. refresh();
  323. }
  324. var notifier = Application.subscribe("transactionschange");
  325. notifier.notify.connect(function() {
  326. refresh();
  327. });
  328. /* Open invoices */
  329. var openInvoice = function(url) {
  330. var arg = url.slice(1, url.length);
  331. var info = createWindow("invoiceinfo");
  332. info.setInvoiceID(arg);
  333. var query = new QSqlQuery();
  334. query.exec("SELECT time, invoice, vendor FROM invoices WHERE id = " + arg);
  335. query.next();
  336. var timefield = findChildObject(info, 'date');
  337. timefield.text = query.value(0);
  338. var vendorfield = findChildObject(info, 'vendor');
  339. vendorfield.text = query.value(2);
  340. var invoicefield = findChildObject(info, 'invoice');
  341. invoicefield.text = query.value(1);
  342. var itemtable = findChildObject(info, 'itemtable');
  343. itemtable.setQuery("SELECT record_type, item_id, description, (SELECT reference FROM items WHERE id = item_id) AS reference, (SELECT cost FROM purchase WHERE item = item_id) AS unit_cost, (SELECT quantity FROM purchase WHERE item = item_id) AS quantity, ((SELECT quantity FROM purchase WHERE item = item_id)/(SELECT conversion FROM lb_bag_conversion WHERE item = item_id))::numeric(12,2) AS sacks, cost FROM invoice_items WHERE invoice_id = " + arg + " AND record_type = 'PURCHASE' UNION SELECT record_type, NULL, description, NULL, NULL, NULL, NULL, cost FROM invoice_items WHERE invoice_id = " + arg + " AND record_type = 'FEE' ORDER BY item_id");
  344. query = query.invalidate();
  345. };
  346. /* Open batch data */
  347. var openProfile = function(url) {
  348. var arg = decodeURI(url.slice(2, url.length));
  349. var key = arg.split("@");
  350. var details = createWindow("batchDetails");
  351. details.loadBatch(key[0], key[1]);
  352. };
  353. view.scriptLinkClicked.connect(function(url) {
  354. var linkType = url[0];
  355. switch(linkType) {
  356. case 'i':
  357. openInvoice(url);
  358. break;
  359. case 'b':
  360. openProfile(url);
  361. break;
  362. }
  363. });
  364. ]]>
  365. </program>
  366. </window>