前回のC#版を中止してから即席で作った。C#のときはMySQLだったが、今回はmdbファイルとした。使うのが1~2名であっても複数箇所で開く場合、データは別ファイルの方がいいだろうと判断。
今回は使う場面を想像できたので、あまりしっかり対策していないが、使う人が書式や関数を変更してしまっても大丈夫なように、起動時にしっかり設定し直す処理をいれれば、エクセルVBAでもDBのクライアントとしてかなり使えそう。
UserForm1
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 |
Function form_query() On Error GoTo try Set cn = CreateObject("ADODB.Connection") Set rs = CreateObject("ADODB.Recordset") cn.Open "Provider=Microsoft.Jet.OLEDB.4.0;Data Source=" & Sheets("設定").Range("B3").Value & ";" rs.Open "select ID,customer,model,serial,quantity,notes from orders where serial = '" & UserForm1.TextBox1.Text & "';", cn Do Until rs.EOF UserForm1.TextBox8.Text = rs(0) UserForm1.TextBox2.Text = rs(1) UserForm1.TextBox3.Text = rs(2) UserForm1.TextBox1.Text = rs(3) UserForm1.TextBox7.Text = rs(4) UserForm1.TextBox4.Text = rs(5) rs.movenext Loop If UserForm1.TextBox8.Text <> "" Then UserForm1.TextBox5.Text = "1" UserForm1.TextBox6.Text = UserForm1.TextBox7.Text End If If rs.state = 1 Then rs.Close Set rs = Nothing If cn.state = 1 Then cn.Close Set cn = Nothing form_query = True Exit Function try: If rs.state = 1 Then rs.Close Set rs = Nothing If cn.state = 1 Then cn.Close Set cn = Nothing MsgBox Err.Description form_query = False End Function Private Sub CommandButton1_Click() If UserForm1.TextBox1.Text = "" Then MsgBox "工番を入力してください。" Exit Sub End If If db_chk = False Then Exit Sub form_clear form_query End Sub Sub form_clear() UserForm1.TextBox8.Text = "" UserForm1.TextBox2.Text = "" UserForm1.TextBox3.Text = "" UserForm1.TextBox7.Text = "" UserForm1.TextBox4.Text = "" UserForm1.TextBox5.Text = "" UserForm1.TextBox6.Text = "" End Sub Function db_chk() On Error GoTo try Set cn = CreateObject("ADODB.Connection") cn.Open "Provider=Microsoft.Jet.OLEDB.4.0;Data Source=" & Sheets("設定").Range("B3").Value & ";" If cn.state = 1 Then cn.Close Set cn = Nothing db_chk = True Exit Function try: If cn.state = 1 Then cn.Close Set cn = Nothing MsgBox "DBに接続できません。" db_chk = False End Function Function qty_parse() On Error GoTo try If UserForm1.TextBox5.Text = "" Or UserForm1.TextBox6.Text = "" Then MsgBox "対象枝を入力してください。" qty_parse = False Exit Function End If qty = CInt(UserForm1.TextBox7.Text) suffix_s = CInt(UserForm1.TextBox5.Text) suffix_e = CInt(UserForm1.TextBox6.Text) If suffix_s = 0 Or suffix_e = 0 Then MsgBox "対象枝は1以上の数字を指定する必要があります。" qty_parse = False Exit Function End If If suffix_e > qty Or suffix_s > suffix_e Then MsgBox "対象枝の指定範囲に問題があります。" qty_parse = False Exit Function End If qty_parse = True Exit Function try: MsgBox "対象枝が数字ではありません。" qty_parse = False End Function Private Sub CommandButton2_Click() Call MainWrite("1", "スタート", "作") End Sub Private Sub CommandButton3_Click() Call MainWrite("1", "スタート", "修") End Sub Private Sub CommandButton4_Click() Call MainWrite("3", "ストップ", "") End Sub Private Sub CommandButton5_Click() Call MainWrite("4", "完了", "") WorkTimeAdd End Sub Sub MainWrite(mark, state, typ) If ActiveSheet.Name <> "作業登録" Then MsgBox "作業登録で実施してください。" Exit Sub End If If UserForm1.TextBox8.Text = "" Then MsgBox "対象のIDが見つかりません。" Exit Sub End If If qty_parse = False Then Exit Sub Set w = Sheets("作業登録") serial = UserForm1.TextBox1.Text For suffix = CInt(UserForm1.TextBox5.Text) To CInt(UserForm1.TextBox6.Text) f = False For r = 2 To w.UsedRange.Rows.Count If serial = w.Cells(r, 1).Text And suffix = w.Cells(r, 2) Then f = True Call WriteCol(r, serial, suffix, mark, state, typ) End If Next r If f = False Then Call WriteCol(r, serial, suffix, mark, state, typ) End If Next suffix End Sub Sub WriteCol(r, serial, suffix, mark, state, typ) Set w = Sheets("作業登録") If w.Cells(r, 3).Value = "完了" Then MsgBox serial & "-" & suffix & "は既に完了しています。" Exit Sub End If Select Case mark Case "1" '作業スタート If w.Cells(r, 3).Value = "スタート" Then MsgBox serial & "-" & suffix & "は既にスタートしています。" Exit Sub End If If w.Cells(r, 3).Value = "" Or w.Cells(r, 3).Value = "ストップ" Then c = 8 End If Case "2" '修正スタート If w.Cells(r, 3).Value = "スタート" Then MsgBox serial & "-" & suffix & "は既にスタートしています。" Exit Sub End If If w.Cells(r, 3).Value = "" Or w.Cells(r, 3).Value = "ストップ" Then c = 8 End If Case "3" 'ストップ If w.Cells(r, 3).Value = "スタート" Then c = 9 End If If w.Cells(r, 3).Value = "" Or w.Cells(r, 3).Value = "ストップ" Then MsgBox serial & "-" & suffix & "はスタートしていません。" Exit Sub End If Case "4" '指定工番の完了 If w.Cells(r, 3).Value = "スタート" Then MsgBox serial & "-" & suffix & "はスタートしているため完了できません。" Exit Sub End If If w.Cells(r, 3).Value = "ストップ" Or w.Cells(r, 3).Value = "" Then w.Cells(r, 1).Value = serial w.Cells(r, 2).Value = suffix w.Cells(r, 3).Value = "完了" w.Cells(r, 3).Interior.ColorIndex = 0 Exit Sub End If End Select Do While True If w.Cells(r, c).Value = "" Then w.Cells(r, 1).Value = serial w.Cells(r, 2).Value = suffix w.Cells(r, 3).Value = state If (mark = 1 Or mark = 2) Then 'スタート w.Cells(r, 3).Interior.Color = RGB(255, 0, 0) w.Cells(r, 6).Value = "" w.Cells(r, c - 1).Value = typ End If If (mark = 3) Then 'ストップ w.Cells(r, 3).Interior.Color = RGB(255, 255, 0) w.Cells(r, 6).Value = c - 2 End If w.Cells(r, c).Value = Format(Now(), "yyyy/mm/dd hh:mm:00") Exit Do End If c = c + 3 Loop End Sub Private Sub CommandButton6_Click() UserForm1.TextBox1.Text = "" form_clear End Sub |
Module1
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 |
Sub auto_open() SetStyle If (StrConv(Sheets("設定").Range("B5").Value, 10) = "on") Then Sheets("作業登録").Activate UserForm1.Show End If On Error Resume Next Application.CommandBars("cell").Controls("フォーム表示").Delete Application.CommandBars("cell").Controls("フォーム表示").Delete With Application.CommandBars("cell").Controls.Add .Caption = "フォーム表示" .OnAction = "FormShow" End With End Sub Sub auto_close() On Error Resume Next Application.CommandBars("cell").Controls("フォーム表示").Delete Application.CommandBars("cell").Controls("フォーム表示").Delete End Sub Sub FormShow() Sheets("作業登録").Activate UserForm1.Show End Sub Sub SetStyle() Sheets("登録者").Cells(3, 2).NumberFormatLocal = "@" Sheets("登録者").Cells(5, 2).NumberFormatLocal = "@" Sheets("登録者").Cells(7, 2).NumberFormatLocal = "@" Sheets("登録者").Cells(11, 2).NumberFormatLocal = "@" Sheets("作業登録").Cells.NumberFormatLocal = "" Sheets("作業登録").Columns("A").NumberFormatLocal = "@" For c = 7 To 100 Step 3 Sheets("作業登録").Cells(1, c).Value = "種" Sheets("作業登録").Cells(1, c + 1).Value = "スタート" Sheets("作業登録").Cells(1, c + 2).Value = "ストップ" Sheets("作業登録").Columns(c).NumberFormatLocal = "" Sheets("作業登録").Columns(c + 1).NumberFormatLocal = "mm/dd hh:mm" Sheets("作業登録").Columns(c + 2).NumberFormatLocal = "mm/dd hh:mm" Sheets("作業登録").Columns(c).ColumnWidth = "2.5" Sheets("作業登録").Columns(c + 1).ColumnWidth = "12" Sheets("作業登録").Columns(c + 2).ColumnWidth = "12" Next c End Sub Sub WorkTimeAdd() Set w = Sheets("作業登録") For r = 2 To w.UsedRange.Rows.Count w.Cells(r, 4) = "" w.Cells(r, 5) = "" If w.Cells(r, 3).Text = "完了" And w.Cells(r, 6).Text <> "" Then n = 0 f = 0 For c = 7 To w.Cells(r, 6).Text Step 3 Select Case w.Cells(r, c).Text Case "作" n = n + WorkTime(w.Cells(r, c + 1).Text, w.Cells(r, c + 2).Text) Case "修" f = f + WorkTime(w.Cells(r, c + 1).Text, w.Cells(r, c + 2).Text) End Select Next c w.Cells(r, 4) = Int(n / 60) & "." & Format(n Mod 60, "00") & " H" w.Cells(r, 5) = Int(f / 60) & "." & Format(f Mod 60, "00") & " H" End If Next r w.Activate End Sub Function WorkTime(date_s, date_e) On Error GoTo try date_s = CDate(date_s) date_e = CDate(date_e) ts = 0 Do While date_s < date_e ts = ts + 1 If date_s >= CDate(Year(date_s) & "/" & Month(date_s) & "/" & Day(date_s) & " 10:00:00") And _ date_s < CDate(Year(date_s) & "/" & Month(date_s) & "/" & Day(date_s) & " 10:15:00") Then ts = ts - 1 End If If date_s >= CDate(Year(date_s) & "/" & Month(date_s) & "/" & Day(date_s) & " 12:00:00") And _ date_s < CDate(Year(date_s) & "/" & Month(date_s) & "/" & Day(date_s) & " 12:50:00") Then ts = ts - 1 End If If date_s >= CDate(Year(date_s) & "/" & Month(date_s) & "/" & Day(date_s) & " 15:00:00") And _ date_s < CDate(Year(date_s) & "/" & Month(date_s) & "/" & Day(date_s) & " 15:15:00") Then ts = ts - 1 End If If date_s >= CDate(Year(date_s) & "/" & Month(date_s) & "/" & Day(date_s) & " 17:20:00") And _ date_s < CDate(Year(date_s) & "/" & Month(date_s) & "/" & Day(date_s) & " 17:30:00") Then ts = ts - 1 End If date_s = DateAdd("n", 1, date_s) Loop WorkTime = ts Exit Function try: WorkTime = 0 End Function |
Sheet1(登録者)
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 |
Function BuildQuery(mark) q_i = Sheets("登録者").Range("B21").Value q_c = Sheets("登録者").Range("B3").Value q_m = Sheets("登録者").Range("B5").Value q_s = Sheets("登録者").Range("B7").Value q_q = Sheets("登録者").Range("B9").Value q_n = Sheets("登録者").Range("B11").Value q_i = StrConv(q_i, vbNarrow) q_s = StrConv(q_s, vbNarrow) q_q = StrConv(q_q, vbNarrow) q_i = Replace(q_i, "'", "’") q_c = Replace(q_c, "'", "’") q_m = Replace(q_m, "'", "’") q_s = Replace(q_s, "'", "’") q_q = Replace(q_q, "'", "’") q_n = Replace(q_n, "'", "’") q_i = Replace(q_i, """", "’") q_c = Replace(q_c, """", "’") q_m = Replace(q_m, """", "’") q_s = Replace(q_s, """", "’") q_q = Replace(q_q, """", "’") q_n = Replace(q_n, """", "’") If mark = "s1" Then q = "select ID,customer,model,serial,quantity,notes from orders where visible = 'true'" If mark = "s2" Then q = "select ID,customer,model,serial,quantity,notes from orders where visible = 'false'" If mark = "i" Then q = "insert into orders (customer,model,serial,quantity,notes,visible) values ('" & q_c & "','" & q_m & "','" & q_s & "'," & q_q & ",'" & q_n & "','true');" If mark = "u" Then q = "update orders set customer = '" & q_c & "', model = '" & q_m & "', serial = '" & q_s & "', quantity = " & q_q & ", notes = '" & q_n & "' where ID = " & q_i & ";" If mark = "d" Then q = "delete from orders where ID = " & q_i & ";" If mark = "h" Then q = "update orders set visible = 'false' where ID = " & q_i & ";" BuildQuery = q: Debug.Print q End Function Private Sub CommandButton6_Click() If db_chk = False Then Exit Sub grid_clear If grid_load("s1") = False Then Exit Sub form_clear End Sub Private Sub CommandButton5_Click() If db_chk = False Then Exit Sub grid_clear If grid_load("s2") = False Then Exit Sub form_clear End Sub Private Sub CommandButton1_Click() If db_chk = False Then Exit Sub If form_chk = False Then Exit Sub If qty_parse = False Then Exit Sub If form_query("i") = False Then Exit Sub grid_clear If grid_load("s1") = False Then Exit Sub form_clear End Sub Private Sub CommandButton2_Click() If db_chk = False Then Exit Sub If id_chk = False Then Exit Sub If form_chk = False Then Exit Sub If qty_parse = False Then Exit Sub If form_query("u") = False Then Exit Sub grid_clear If grid_load("s1") = False Then Exit Sub form_clear End Sub Private Sub CommandButton3_Click() If db_chk = False Then Exit Sub If id_chk = False Then Exit Sub yn = MsgBox("削除しますか?", vbYesNo) If yn = vbNo Then Exit Sub If form_query("d") = False Then Exit Sub grid_clear If grid_load("s1") = False Then Exit Sub form_clear End Sub Private Sub CommandButton4_Click() If db_chk = False Then Exit Sub If id_chk = False Then Exit Sub If form_query("h") = False Then Exit Sub grid_clear If grid_load("s1") = False Then Exit Sub form_clear End Sub Function id_chk() On Error GoTo try If Sheets("登録者").Range("B21").Value = "" Then GoTo try v = CLng(Sheets("登録者").Range("B21").Value) id_chk = True Exit Function try: MsgBox "IDが正しくありません。" id_chk = False End Function Function form_chk() If Sheets("登録者").Range("B3").Value = "" Then GoTo try If Sheets("登録者").Range("B5").Value = "" Then GoTo try If Sheets("登録者").Range("B7").Value = "" Then GoTo try If Sheets("登録者").Range("B9").Value = "" Then GoTo try form_chk = True Exit Function try: MsgBox "入力が不足しています。" form_chk = False End Function Sub grid_clear() Sheets("登録者").Range("G4:L1000").Delete End Sub Sub form_clear() Sheets("登録者").Range("B3").Value = "" Sheets("登録者").Range("B5").Value = "" Sheets("登録者").Range("B7").Value = "" Sheets("登録者").Range("B9").Value = "" Sheets("登録者").Range("B11").Value = "" Sheets("登録者").Range("B21").Value = "" End Sub Function qty_parse() On Error GoTo try qty = CLng(Sheets("登録者").Range("B9").Value) If qty = 0 Then GoTo try qty_parse = True Exit Function try: MsgBox "数量が正しくありません。" qty_parse = False End Function Function form_query(mark) On Error GoTo try Set cn = CreateObject("ADODB.Connection") cn.Open "Provider=Microsoft.Jet.OLEDB.4.0;Data Source=" & Sheets("設定").Range("B3").Value & ";" cn.Execute BuildQuery(mark) If cn.state = 1 Then cn.Close Set cn = Nothing form_query = True Exit Function try: If cn.state = 1 Then cn.Close Set cn = Nothing MsgBox Err.Description form_query = False End Function Function grid_load(mark) On Error GoTo try Set cn = CreateObject("ADODB.Connection") Set rs = CreateObject("ADODB.Recordset") cn.Open "Provider=Microsoft.Jet.OLEDB.4.0;Data Source=" & Sheets("設定").Range("B3").Value & ";" rs.Open BuildQuery(mark), cn r = 4 Do Until rs.EOF Sheets("登録者").Cells(r, 7).Value = rs(0) Sheets("登録者").Cells(r, 8).Value = rs(1) Sheets("登録者").Cells(r, 9).Value = rs(2) Sheets("登録者").Cells(r, 10).Value = rs(3) Sheets("登録者").Cells(r, 11).Value = rs(4) Sheets("登録者").Cells(r, 12).Value = rs(5) Sheets("登録者").Range("G" & r & ":L" & r & "").Borders.LineStyle = True r = r + 1 rs.movenext Loop If rs.state = 1 Then rs.Close Set rs = Nothing If cn.state = 1 Then cn.Close Set cn = Nothing grid_load = True Exit Function try: If rs.state = 1 Then rs.Close Set rs = Nothing If cn.state = 1 Then cn.Close Set cn = Nothing grid_load = False End Function Function db_chk() On Error GoTo try Set cn = CreateObject("ADODB.Connection") cn.Open "Provider=Microsoft.Jet.OLEDB.4.0;Data Source=" & Sheets("設定").Range("B3").Value & ";" If cn.state = 1 Then cn.Close Set cn = Nothing db_chk = True Exit Function try: If cn.state = 1 Then cn.Close Set cn = Nothing MsgBox "DBに接続できません。" db_chk = False End Function Private Sub Worksheet_SelectionChange(ByVal Target As Range) If Target.Row >= 4 And Target.Column = 7 And Target.Text <> "" Then ActiveSheet.Cells(3, 2).Value = ActiveSheet.Cells(Target.Row, 8).Value ActiveSheet.Cells(5, 2).Value = ActiveSheet.Cells(Target.Row, 9).Value ActiveSheet.Cells(7, 2).Value = ActiveSheet.Cells(Target.Row, 10).Value ActiveSheet.Cells(9, 2).Value = ActiveSheet.Cells(Target.Row, 11).Value ActiveSheet.Cells(11, 2).Value = ActiveSheet.Cells(Target.Row, 12).Value ActiveSheet.Cells(21, 2).Value = ActiveSheet.Cells(Target.Row, 7).Value ElseIf Target.Row >= 4 And Target.Column = 7 And Target.Text = "" Then ActiveSheet.Cells(3, 2).Value = "" ActiveSheet.Cells(5, 2).Value = "" ActiveSheet.Cells(7, 2).Value = "" ActiveSheet.Cells(9, 2).Value = "" ActiveSheet.Cells(11, 2).Value = "" ActiveSheet.Cells(21, 2).Value = "" End If End Sub |
Sheet3(作業登録)
1 2 3 4 5 6 7 8 |
Private Sub Worksheet_SelectionChange(ByVal Target As Range) If UserForm1.Visible And UserForm1.TextBox8.Text = "" And _ Target.Row >= 2 And Target.Column = 1 And Target.Text <> "" Then UserForm1.TextBox1.Text = Target.Text End If End Sub |