Merged changes in main trunk up to 2.0.6 (see CHANGELOG)
[fa-stable.git] / reporting / rep302.php
1 <?php
2
3 $page_security = 2;
4 // ----------------------------------------------------------------
5 // $ Revision:  2.0 $
6 // Creator:     Joe Hunt
7 // date_:       2005-05-19
8 // Title:       Inventory Planning
9 // ----------------------------------------------------------------
10 $path_to_root="../";
11
12 include_once($path_to_root . "includes/session.inc");
13 include_once($path_to_root . "includes/date_functions.inc");
14 include_once($path_to_root . "includes/data_checks.inc");
15 include_once($path_to_root . "gl/includes/gl_db.inc");
16 include_once($path_to_root . "inventory/includes/db/items_category_db.inc");
17
18 //----------------------------------------------------------------------------------------------------
19
20 // trial_inquiry_controls();
21 print_inventory_planning();
22
23 function getTransactions($category, $location)
24 {
25         $sql = "SELECT ".TB_PREF."stock_master.category_id,
26                         ".TB_PREF."stock_category.description AS cat_description,
27                         ".TB_PREF."stock_master.stock_id,
28                         ".TB_PREF."stock_master.description,
29                         IF(".TB_PREF."stock_moves.stock_id IS NULL, '', ".TB_PREF."stock_moves.loc_code) AS loc_code,
30                         SUM(IF(".TB_PREF."stock_moves.stock_id IS NULL,0,".TB_PREF."stock_moves.qty)) AS qty_on_hand
31                 FROM (".TB_PREF."stock_master,
32                         ".TB_PREF."stock_category)
33                 LEFT JOIN ".TB_PREF."stock_moves ON
34                         (".TB_PREF."stock_master.stock_id=".TB_PREF."stock_moves.stock_id OR ".TB_PREF."stock_master.stock_id IS NULL)
35                 WHERE ".TB_PREF."stock_master.category_id=".TB_PREF."stock_category.category_id
36                 AND (".TB_PREF."stock_master.mb_flag='B' OR ".TB_PREF."stock_master.mb_flag='M')";
37         if ($category != 0)
38                 $sql .= " AND ".TB_PREF."stock_master.category_id = '$category'";
39         if ($location != 'all')
40                 $sql .= " AND ".TB_PREF."stock_moves.loc_code = '$location'";
41         $sql .= " GROUP BY ".TB_PREF."stock_master.category_id,
42                 ".TB_PREF."stock_category.description,
43                 ".TB_PREF."stock_master.stock_id,
44                 ".TB_PREF."stock_master.description
45                 ORDER BY ".TB_PREF."stock_master.category_id,
46                 ".TB_PREF."stock_master.stock_id";
47
48     return db_query($sql,"No transactions were returned");
49
50 }
51
52 function getCustQty($stockid, $location)
53 {
54         $sql = "SELECT SUM(".TB_PREF."sales_order_details.quantity - ".TB_PREF."sales_order_details.qty_sent) AS qty_demand
55                                 FROM ".TB_PREF."sales_order_details,
56                                         ".TB_PREF."sales_orders
57                                 WHERE ".TB_PREF."sales_order_details.order_no=".TB_PREF."sales_orders.order_no AND ";
58         if ($location != "")
59                 $sql .= TB_PREF."sales_orders.from_stk_loc ='$location' AND ";
60         $sql .= TB_PREF."sales_order_details.stk_code = '$stockid'";
61
62     $TransResult = db_query($sql,"No transactions were returned");
63         $DemandRow = db_fetch($TransResult);
64         return $DemandRow['qty_demand'];
65 }
66
67 function getCustAsmQty($stockid, $location)
68 {
69         $sql = "SELECT SUM((".TB_PREF."sales_order_details.quantity-".TB_PREF."sales_order_details.qty_sent)*".TB_PREF."bom.quantity)
70                                    AS Dem
71                                    FROM ".TB_PREF."sales_order_details,
72                                                 ".TB_PREF."sales_orders,
73                                                 ".TB_PREF."bom,
74                                                 ".TB_PREF."stock_master
75                                    WHERE ".TB_PREF."sales_order_details.stk_code=".TB_PREF."bom.parent AND
76                                    ".TB_PREF."sales_orders.order_no = ".TB_PREF."sales_order_details.order_no AND ";
77         if ($location != "")
78                 $sql .= TB_PREF."sales_orders.from_stk_loc ='$location' AND ";
79         $sql .= TB_PREF."sales_order_details.quantity-".TB_PREF."sales_order_details.qty_sent > 0 AND
80                                    ".TB_PREF."bom.component='$stockid' AND
81                                    ".TB_PREF."stock_master.stock_id=".TB_PREF."bom.parent AND
82                                    ".TB_PREF."stock_master.mb_flag='A'";
83
84     $TransResult = db_query($sql,"No transactions were returned");
85         if (db_num_rows($TransResult) == 1)
86         {
87                 $DemandRow = db_fetch_row($TransResult);
88                 $DemandQty = $DemandRow[0];
89         }
90         else
91                 $DemandQty = 0.0;
92
93     return $DemandQty;
94 }
95
96 function getSuppQty($stockid, $location)
97 {
98         $sql = "SELECT SUM(".TB_PREF."purch_order_details.quantity_ordered - ".TB_PREF."purch_order_details.quantity_received) AS QtyOnOrder
99                                 FROM ".TB_PREF."purch_order_details,
100                                         ".TB_PREF."purch_orders
101                                 WHERE ".TB_PREF."purch_order_details.order_no = ".TB_PREF."purch_orders.order_no
102                                 AND ".TB_PREF."purch_order_details.item_code = '$stockid'";
103         if ($location != "")                    
104                 $sql .= " AND ".TB_PREF."purch_orders.into_stock_location= '$location'";
105
106     $TransResult = db_query($sql,"No transactions were returned");
107         $DemandRow = db_fetch($TransResult);
108         return $DemandRow['QtyOnOrder'];
109 }
110
111 function getPeriods($stockid, $location)
112 {
113         $date5 = date('Y-m-d');
114         $date4 = date('Y-m-d',mktime(0,0,0,date('m'),1,date('Y')));
115         $date3 = date('Y-m-d',mktime(0,0,0,date('m')-1,1,date('Y')));
116         $date2 = date('Y-m-d',mktime(0,0,0,date('m')-2,1,date('Y')));
117         $date1 = date('Y-m-d',mktime(0,0,0,date('m')-3,1,date('Y')));
118         $date0 = date('Y-m-d',mktime(0,0,0,date('m')-4,1,date('Y')));
119
120         $sql = "SELECT SUM(CASE WHEN tran_date >= '$date0' AND tran_date < '$date1' THEN -qty ELSE 0 END) AS prd0,
121                                 SUM(CASE WHEN tran_date >= '$date1' AND tran_date < '$date2' THEN -qty ELSE 0 END) AS prd1,
122                                 SUM(CASE WHEN tran_date >= '$date2' AND tran_date < '$date3' THEN -qty ELSE 0 END) AS prd2,
123                                 SUM(CASE WHEN tran_date >= '$date3' AND tran_date < '$date4' THEN -qty ELSE 0 END) AS prd3,
124                                 SUM(CASE WHEN tran_date >= '$date4' AND tran_date <= '$date5' THEN -qty ELSE 0 END) AS prd4
125                         FROM ".TB_PREF."stock_moves
126                         WHERE stock_id='$stockid'
127                         AND loc_code ='$location'
128                         AND (type=13 OR type=11)
129                         AND visible=1";
130
131     $TransResult = db_query($sql,"No transactions were returned");
132         return db_fetch($TransResult);
133 }
134
135 //----------------------------------------------------------------------------------------------------
136
137 function print_inventory_planning()
138 {
139     global $path_to_root;
140
141     include_once($path_to_root . "reporting/includes/pdf_report.inc");
142
143     $category = $_POST['PARAM_0'];
144     $location = $_POST['PARAM_1'];
145     $comments = $_POST['PARAM_2'];
146
147         if ($category == reserved_words::get_all_numeric())
148                 $category = 0;
149         if ($category == 0)
150                 $cat = _('All');
151         else
152                 $cat = get_category_name($category);
153
154         if ($location == reserved_words::get_all())
155                 $location = 'all';
156         if ($location == 'all')
157                 $loc = _('All');
158         else
159                 $loc = $location;
160
161         $cols = array(0, 50, 150, 180, 210, 240, 270, 300, 330, 390, 435, 480, 525);
162
163         $per0 = strftime('%b',mktime(0,0,0,date('m'),1,date('Y')));
164         $per1 = strftime('%b',mktime(0,0,0,date('m')-1,1,date('Y')));
165         $per2 = strftime('%b',mktime(0,0,0,date('m')-2,1,date('Y')));
166         $per3 = strftime('%b',mktime(0,0,0,date('m')-3,1,date('Y')));
167         $per4 = strftime('%b',mktime(0,0,0,date('m')-4,1,date('Y')));
168
169         $headers = array(_('Category'), '', $per4, $per3, $per2, $per1, $per0, '3*M',
170                 _('QOH'), _('Cust Ord'), _('Supp Ord'), _('Sugg Ord'));
171
172         $aligns = array('left', 'left', 'right', 'right', 'right', 'right', 'right', 'right',
173                 'right', 'right', 'right', 'right');
174
175     $params =   array(  0 => $comments,
176                                     1 => array('text' => _('Category'), 'from' => $cat, 'to' => ''),
177                                     2 => array('text' => _('Location'), 'from' => $loc, 'to' => ''));
178
179     $rep = new FrontReport(_('Inventory Planning Report'), "InventoryPlanning.pdf", user_pagesize());
180
181     $rep->Font();
182     $rep->Info($params, $cols, $headers, $aligns);
183     $rep->Header();
184
185         $res = getTransactions($category, $location);
186         $catt = '';
187         while ($trans=db_fetch($res))
188         {
189                 if ($catt != $trans['cat_description'])
190                 {
191                         if ($catt != '')
192                         {
193                                 $rep->Line($rep->row - 2);
194                                 $rep->NewLine(2, 3);
195                         }
196                         $rep->TextCol(0, 1, $trans['category_id']);
197                         $rep->TextCol(1, 2, $trans['cat_description']);
198                         $catt = $trans['cat_description'];
199                         $rep->NewLine();
200                 }
201                 if ($location == 'all')
202                         $loc_code = "";
203                 else
204                         $loc_code = $trans['loc_code'];
205                 $custqty = getCustQty($trans['stock_id'], $loc_code);
206                 $custqty += getCustAsmQty($trans['stock_id'], $loc_code);
207                 $suppqty = getSuppQty($trans['stock_id'], $loc_code);
208                 $period = getPeriods($trans['stock_id'], $trans['loc_code']);
209                 $rep->NewLine();
210                 $dec = get_qty_dec($trans['stock_id']);
211                 $rep->TextCol(0, 1, $trans['stock_id']);
212                 $rep->TextCol(1, 2, $trans['description']);
213                 $rep->TextCol(2, 3, number_format2($period['prd0'], $dec));
214                 $rep->TextCol(3, 4, number_format2($period['prd1'], $dec));
215                 $rep->TextCol(4, 5, number_format2($period['prd2'], $dec));
216                 $rep->TextCol(5, 6, number_format2($period['prd3'], $dec));
217                 $rep->TextCol(6, 7, number_format2($period['prd4'], $dec));
218
219                 $MaxMthSales = Max($period['prd0'], $period['prd1'], $period['prd2'], $period['prd3']);
220                 $IdealStockHolding = $MaxMthSales * 3;
221                 $rep->TextCol(7, 8, number_format2($IdealStockHolding, $dec));
222
223                 $rep->TextCol(8, 9, number_format2($trans['qty_on_hand'], $dec));
224                 $rep->TextCol(9, 10, number_format2($custqty, $dec));
225                 $rep->TextCol(10, 11, number_format2($suppqty, $dec));
226
227                 $SuggestedTopUpOrder = $IdealStockHolding - $trans['qty_on_hand'] + $custqty - $suppqty;
228                 if ($SuggestedTopUpOrder < 0.0)
229                         $SuggestedTopUpOrder = 0.0;
230                 $rep->TextCol(11, 12, number_format2($SuggestedTopUpOrder, $dec));
231         }
232         $rep->Line($rep->row - 4);
233     $rep->End();
234 }
235
236 ?>