Explorar el Código

Optimization for item history

Neal Wilson hace 11 años
padre
commit
421b2b7e11
Se han modificado 2 ficheros con 6 adiciones y 2 borrados
  1. 1
    0
      config/Reports/invchange.xml
  2. 5
    2
      config/Windows/navigation.xml

+ 1
- 0
config/Reports/invchange.xml Ver fichero

@@ -121,6 +121,7 @@
121 121
 				output.writeEndDocument();
122 122
 				view.setContent(buffer);
123 123
 				buffer.close();
124
+				query = query.invalidate();
124 125
 			}
125 126
 			refresh();
126 127
 			startDateField.dateChanged.connect(function() {

+ 5
- 2
config/Windows/navigation.xml Ver fichero

@@ -269,10 +269,13 @@ type="push" />
269 269
 			query = query.invalidate();
270 270
 		};
271 271
 		
272
-		/* Bug fix for item_history */
272
+		/* Bug fix and optimization for item_history */
273 273
 		var DBUpdateHistory = function() {
274 274
 			var query = new QSqlQuery;
275
-			query.exec("CREATE OR REPLACE FUNCTION item_history(bigint) RETURNS SETOF item_transaction_with_balance AS $$ DECLARE r item_transaction_with_balance; q numeric; BEGIN CREATE TEMPORARY TABLE working(time timestamp without time zone, item bigint, quantity numeric, cost numeric, vendor text, reason text, customer text, type text, balance numeric) ON COMMIT DROP; INSERT INTO working SELECT time, item, quantity, cost, vendor, reason, customer, type, NULL AS balance FROM all_transactions WHERE item = $1 ORDER BY time ASC; q := 0; FOR r IN SELECT time, item, quantity, cost, vendor, reason, customer, type, balance FROM working LOOP CASE r.type WHEN 'PURCHASE', 'MAKE' THEN q := q + r.quantity; WHEN 'INVENTORY' THEN q := r.quantity; WHEN 'USE', 'SALE', 'LOSS' THEN q := q - r.quantity; END CASE; r.balance := q; RETURN NEXT r; END LOOP; DROP TABLE working; RETURN; END; $$ LANGUAGE plpgsql");
275
+			query.exec("CREATE TYPE transaction_type AS (type text, quantity numeric)");
276
+			query.exec("CREATE FUNCTION update_balance(numeric, transaction_type) RETURNS numeric AS $$ BEGIN CASE $2.type WHEN 'PURCHASE', 'MAKE' THEN RETURN $1 + $2.quantity; WHEN 'INVENTORY' THEN RETURN $2.quantity; WHEN 'USE', 'SALE', 'LOSS' THEN RETURN $1 - $2.quantity; END CASE; END; $$ LANGUAGE plpgsql STRICT");
277
+			query.exec("CREATE AGGREGATE transaction_balance (BASETYPE = transaction_type, SFUNC = update_balance, STYPE = numeric, INITCOND = '0')");
278
+			query.exec("CREATE OR REPLACE FUNCTION item_history(bigint) RETURNS SETOF item_transaction_with_balance AS $$ SELECT time, item, quantity, cost, vendor, customer, type, transaction_balance((type, quantity)::transaction_type) OVER (PARTITION BY item ORDER BY time ASC) AS balance FROM all_transactions WHERE item = $1; $$ LANGUAGE SQL");
276 279
 			query.exec("DROP FUNCTION calculate_inventory_balance()");
277 280
 		};
278 281
 		

Loading…
Cancelar
Guardar