From fahooper at gmail.com Mon Apr 9 16:10:01 2018 From: fahooper at gmail.com (Fred Hooper) Date: Mon, 9 Apr 2018 17:10:01 -0400 Subject: [AccessD] SQL Server back end conversion Message-ID: Hi All, I've written a couple of times in the past about converting my brother-in-law's software program from an Access back end to a SQL Server back end. I'd like to summarize the situation and my immediate plans in hope that someone will see something I've missed. The speed issues are apparent from two test cases (in seconds): Time to open two forms: #1 #2 Access back end: 0.55 2.13 SQL Server table links only: 0.96 13.88 SQL Server views linked too: 9.50 0.54 SQL Server w/ADO recordset: 0.55 0.19 These results are on a fast computer with everything on that computer. The times are 5-20 times longer on their network -- which has about 20 people using the program. We've updated and replaced network components and the server, but found only small improvements. The back end mdb is just 140Mb. It's the 5-20X time multiplier that's the problem; which probably results from the fact that all heavily-used forms are fed by complex queries, having many tables with outer joins. I've tried a SQL Server table-links-only version on their network and it was pathetic, far slower than Access. The recordset-fed-forms version is my only real hope, absent a "Why didn't you try X?" response to this email. My theory is that the reduction of network load by server query execution and results-only recordsets will make their performance almost as fast as on my PC. Here's what I've done so far: (1) Improved the network (2) JIT subforms, particularly on the large, heavily-used forms (3) Replaced complex embedded SQL with queries (4) Tweaked queries so they're not grouping entire tables (5) Tried to find a commercial substitute for their program; there isn't one even close The program was written by someone as their first big project, but was generally well done. My only two real complaints are zero defaults for foreign keys and no referential integrity (RI). I can't move forward with recordsets without RI, as they won't be editable. So that's where I'm going next. TIA, Fred From jimdettman at verizon.net Mon Apr 9 16:30:53 2018 From: jimdettman at verizon.net (Jim Dettman) Date: Mon, 9 Apr 2018 17:30:53 -0400 Subject: [AccessD] SQL Server back end conversion In-Reply-To: References: Message-ID: <002a01d3d04a$0a0ba910$1e22fb30$@verizon.net> << It's the 5-20X time multiplier that's the problem; which probably results from the fact that all heavily-used forms are fed by complex queries, having many tables with outer joins>> One thing to be aware of, if the query has: 1. VBA expressions. 2. JET specific SQL. 3. Joins to local tables. Then JET will do the processing rather than handing it off to SQL. That means a lot of data over the wire and depending on the query, JET may actually issue one SQL statement per row in your result set. I forget what the rules are for that off-hand, but it typically happens on deletes. In general though, most apps do OK with a conversion to SQL with just linked tables, but there are a few that end up slower. In order to harness the power of SQL, you need to send processing server side. That's done by using: 1. Views 2. Pass-through queries 3. Stored Procedures The other thing is that if you have not already done so, you should add a Time Stamp field to every table that JET will work with. It's really not a time stamp field as one would think. What it does is turn on row versioning for SQL, and JET will latch onto that field for building recordsets. Add the time stamp fields if you don't have them, relink, and see if you get a performance boost on your tests. Jim. -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Fred Hooper Sent: Monday, April 9, 2018 5:10 PM To: Access Developers discussion and problem solving Subject: [AccessD] SQL Server back end conversion Hi All, I've written a couple of times in the past about converting my brother-in-law's software program from an Access back end to a SQL Server back end. I'd like to summarize the situation and my immediate plans in hope that someone will see something I've missed. The speed issues are apparent from two test cases (in seconds): Time to open two forms: #1 #2 Access back end: 0.55 2.13 SQL Server table links only: 0.96 13.88 SQL Server views linked too: 9.50 0.54 SQL Server w/ADO recordset: 0.55 0.19 These results are on a fast computer with everything on that computer. The times are 5-20 times longer on their network -- which has about 20 people using the program. We've updated and replaced network components and the server, but found only small improvements. The back end mdb is just 140Mb. It's the 5-20X time multiplier that's the problem; which probably results from the fact that all heavily-used forms are fed by complex queries, having many tables with outer joins. I've tried a SQL Server table-links-only version on their network and it was pathetic, far slower than Access. The recordset-fed-forms version is my only real hope, absent a "Why didn't you try X?" response to this email. My theory is that the reduction of network load by server query execution and results-only recordsets will make their performance almost as fast as on my PC. Here's what I've done so far: (1) Improved the network (2) JIT subforms, particularly on the large, heavily-used forms (3) Replaced complex embedded SQL with queries (4) Tweaked queries so they're not grouping entire tables (5) Tried to find a commercial substitute for their program; there isn't one even close The program was written by someone as their first big project, but was generally well done. My only two real complaints are zero defaults for foreign keys and no referential integrity (RI). I can't move forward with recordsets without RI, as they won't be editable. So that's where I'm going next. TIA, Fred -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From stuart at lexacorp.com.pg Mon Apr 9 19:59:34 2018 From: stuart at lexacorp.com.pg (Stuart McLachlan) Date: Tue, 10 Apr 2018 10:59:34 +1000 Subject: [AccessD] SQL Server back end conversion In-Reply-To: <002a01d3d04a$0a0ba910$1e22fb30$@verizon.net> References: , <002a01d3d04a$0a0ba910$1e22fb30$@verizon.net> Message-ID: <5ACC0C76.27874.6D26B21C@stuart.lexacorp.com.pg> I second Jim's comments. First thing I'd do is convert those form record source "complex queries" to views. On 9 Apr 2018 at 17:30, Jim Dettman wrote: > << It's the 5-20X time multiplier that's the problem; which probably > results from the fact that all heavily-used forms are fed by complex > queries, having many tables with outer joins>> > > One thing to be aware of, if the query has: > > 1. VBA expressions. > 2. JET specific SQL. > 3. Joins to local tables. > > Then JET will do the processing rather than handing it off to SQL. > That > means a lot of data over the wire and depending on the query, JET may > actually issue one SQL statement per row in your result set. I > forget what the rules are for that off-hand, but it typically happens > on deletes. > > In general though, most apps do OK with a conversion to SQL with just > linked tables, but there are a few that end up slower. > > In order to harness the power of SQL, you need to send processing > server > side. That's done by using: > > 1. Views > 2. Pass-through queries > 3. Stored Procedures > > The other thing is that if you have not already done so, you should > add a Time Stamp field to every table that JET will work with. It's > really not a time stamp field as one would think. What it does is > turn on row versioning for SQL, and JET will latch onto that field for > building recordsets. > > Add the time stamp fields if you don't have them, relink, and see if > you > get a performance boost on your tests. > > Jim. > > > > -----Original Message----- > From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf > Of Fred Hooper Sent: Monday, April 9, 2018 5:10 PM To: Access > Developers discussion and problem solving Subject: [AccessD] SQL > Server back end conversion > > Hi All, > > I've written a couple of times in the past about converting my > brother-in-law's software program from an Access back end to a SQL > Server back end. I'd like to summarize the situation and my immediate > plans in hope that someone will see something I've missed. > > The speed issues are apparent from two test cases (in seconds): > Time to open two forms: #1 #2 > Access back end: 0.55 2.13 > SQL Server table links only: 0.96 13.88 SQL > Server views linked too: 9.50 0.54 SQL Server > w/ADO recordset: 0.55 0.19 > > These results are on a fast computer with everything on that computer. > The times are 5-20 times longer on their network -- which has about 20 > people using the program. We've updated and replaced network > components and the server, but found only small improvements. The back > end mdb is just 140Mb. > > It's the 5-20X time multiplier that's the problem; which probably > results from the fact that all heavily-used forms are fed by complex > queries, having many tables with outer joins. I've tried a SQL Server > table-links-only version on their network and it was pathetic, far > slower than Access. The recordset-fed-forms version is my only real > hope, absent a "Why didn't you try X?" response to this email. My > theory is that the reduction of network load by server query execution > and results-only recordsets will make their performance almost as fast > as on my PC. > > Here's what I've done so far: > (1) Improved the network > (2) JIT subforms, particularly on the large, heavily-used forms > (3) Replaced complex embedded SQL with queries > (4) Tweaked queries so they're not grouping entire tables > (5) Tried to find a commercial substitute for their program; there > isn't one even close > > The program was written by someone as their first big project, but was > generally well done. My only two real complaints are zero defaults for > foreign keys and no referential integrity (RI). I can't move forward > with recordsets without RI, as they won't be editable. So that's where > I'm going next. > > TIA, Fred > -- > AccessD mailing list > AccessD at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/accessd > Website: http://www.databaseadvisors.com > > -- > AccessD mailing list > AccessD at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/accessd > Website: http://www.databaseadvisors.com > From fuller.artful at gmail.com Tue Apr 10 03:27:50 2018 From: fuller.artful at gmail.com (Arthur Fuller) Date: Tue, 10 Apr 2018 04:27:50 -0400 Subject: [AccessD] SQL Server back end conversion In-Reply-To: <5ACC0C76.27874.6D26B21C@stuart.lexacorp.com.pg> References: <002a01d3d04a$0a0ba910$1e22fb30$@verizon.net> <5ACC0C76.27874.6D26B21C@stuart.lexacorp.com.pg> Message-ID: I second Stuart's advice. The thing about complex queries is that, with linked tables, all the data is sent to the Access client, which then applies filters and sorts to deliver the desired data. With Views, on the other hand, the database itself does all the heavy lifting, then sends the results to the client. On Mon, Apr 9, 2018 at 8:59 PM, Stuart McLachlan wrote: > I second Jim's comments. > > First thing I'd do is convert those form record source "complex queries" > to views. > > On 9 Apr 2018 at 17:30, Jim Dettman wrote: > > > << It's the 5-20X time multiplier that's the problem; which probably > > results from the fact that all heavily-used forms are fed by complex > > queries, having many tables with outer joins>> > > > > One thing to be aware of, if the query has: > > > > 1. VBA expressions. > > 2. JET specific SQL. > > 3. Joins to local tables. > > > > Then JET will do the processing rather than handing it off to SQL. > > That > > means a lot of data over the wire and depending on the query, JET may > > actually issue one SQL statement per row in your result set. I > > forget what the rules are for that off-hand, but it typically happens > > on deletes. > > > > In general though, most apps do OK with a conversion to SQL with just > > linked tables, but there are a few that end up slower. > > > > In order to harness the power of SQL, you need to send processing > > server > > side. That's done by using: > > > > 1. Views > > 2. Pass-through queries > > 3. Stored Procedures > > > > The other thing is that if you have not already done so, you should > > add a Time Stamp field to every table that JET will work with. It's > > really not a time stamp field as one would think. What it does is > > turn on row versioning for SQL, and JET will latch onto that field for > > building recordsets. > > > > Add the time stamp fields if you don't have them, relink, and see if > > you > > get a performance boost on your tests. > > > > Jim. > > > > > > > > -----Original Message----- > > From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf > > Of Fred Hooper Sent: Monday, April 9, 2018 5:10 PM To: Access > > Developers discussion and problem solving Subject: [AccessD] SQL > > Server back end conversion > > > > Hi All, > > > > I've written a couple of times in the past about converting my > > brother-in-law's software program from an Access back end to a SQL > > Server back end. I'd like to summarize the situation and my immediate > > plans in hope that someone will see something I've missed. > > > > The speed issues are apparent from two test cases (in seconds): > > Time to open two forms: #1 #2 > > Access back end: 0.55 2.13 > > SQL Server table links only: 0.96 13.88 SQL > > Server views linked too: 9.50 0.54 SQL Server > > w/ADO recordset: 0.55 0.19 > > > > These results are on a fast computer with everything on that computer. > > The times are 5-20 times longer on their network -- which has about 20 > > people using the program. We've updated and replaced network > > components and the server, but found only small improvements. The back > > end mdb is just 140Mb. > > > > It's the 5-20X time multiplier that's the problem; which probably > > results from the fact that all heavily-used forms are fed by complex > > queries, having many tables with outer joins. I've tried a SQL Server > > table-links-only version on their network and it was pathetic, far > > slower than Access. The recordset-fed-forms version is my only real > > hope, absent a "Why didn't you try X?" response to this email. My > > theory is that the reduction of network load by server query execution > > and results-only recordsets will make their performance almost as fast > > as on my PC. > > > > Here's what I've done so far: > > (1) Improved the network > > (2) JIT subforms, particularly on the large, heavily-used forms > > (3) Replaced complex embedded SQL with queries > > (4) Tweaked queries so they're not grouping entire tables > > (5) Tried to find a commercial substitute for their program; there > > isn't one even close > > > > The program was written by someone as their first big project, but was > > generally well done. My only two real complaints are zero defaults for > > foreign keys and no referential integrity (RI). I can't move forward > > with recordsets without RI, as they won't be editable. So that's where > > I'm going next. > > > > TIA, Fred > > -- > > AccessD mailing list > > AccessD at databaseadvisors.com > > http://databaseadvisors.com/mailman/listinfo/accessd > > Website: http://www.databaseadvisors.com > > > > -- > > AccessD mailing list > > AccessD at databaseadvisors.com > > http://databaseadvisors.com/mailman/listinfo/accessd > > Website: http://www.databaseadvisors.com > > > > > -- > AccessD mailing list > AccessD at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/accessd > Website: http://www.databaseadvisors.com > -- Arthur From jwcolby at gmail.com Tue Apr 10 08:17:41 2018 From: jwcolby at gmail.com (John Colby) Date: Tue, 10 Apr 2018 09:17:41 -0400 Subject: [AccessD] SQL Server back end conversion In-Reply-To: References: Message-ID: <48d50c5d-8752-8b77-5587-8640b2a618d7@Gmail.com> Fred, I did a year contract for IBM in research triangle park.? During that time I was tasked with completely rewriting an access database that no one understood and which only kinda sorta worked.? I had to analyze a ton of queries which were more complex than most anything I had ever encountered.? Statistical stuff. The queries were based on a dozen tables.? The queries were layered, i.e. a set of data pulled into Access, manipulated, stored in temp tables, then those results used to pull more data, manipulated, stored, used for more data etc. It was a mess but it was based on a process by a skilled person who understood the data but not databases. I ended up pulling all of that crap out of access.? I built stored procedures which did pretty much the exact same thing but back in the SQL Server.? The result was a LONG and COMPLEX stored procedure that returned a data set from that stored procedure. The times dropped from dozens of minutes to a dozen seconds.? The ENTIRE thing was SQL Server based TSQL sitting out in SQL Server and executed by a query in Access that just told SQL Server to return some results. Users won't wait for dozens of minutes for results from Access, and worse, because Access is single threaded, the user interface freezes.? They will wonder if the computer is hung.? They will reset their computer.? Things get ugly. On 4/9/2018 5:10 PM, Fred Hooper wrote: > Hi All, > > I've written a couple of times in the past about converting my > brother-in-law's software program from an Access back end to a SQL > Server back end. I'd like to summarize the situation and my immediate > plans in hope that someone will see something I've missed. > > The speed issues are apparent from two test cases (in seconds): > Time to open two forms:???????????????????? #1??????????????? #2 > Access back end:???????????????????????????????? 0.55 2.13 > SQL Server table links only:?????????????? 0.96?????????? 13.88 > SQL Server views linked too:???????????? 9.50???????????? 0.54 > SQL Server w/ADO recordset:?????????? 0.55???????????? 0.19 > > These results are on a fast computer with everything on that computer. > The times are 5-20 times longer on their network -- which has about 20 > people using the program. We've updated and replaced network > components and the server, but found only small improvements. The back > end mdb is just 140Mb. > > It's the 5-20X time multiplier that's the problem; which probably > results from the fact that all heavily-used forms are fed by complex > queries, having many tables with outer joins. I've tried a SQL Server > table-links-only version on their network and it was pathetic, far > slower than Access. The recordset-fed-forms version is my only real > hope, absent a "Why didn't you try X?" response to this email. My > theory is that the reduction of network load by server query execution > and results-only recordsets will make their performance almost as fast > as on my PC. > > Here's what I've done so far: > (1) Improved the network > (2) JIT subforms, particularly on the large, heavily-used forms > (3) Replaced complex embedded SQL with queries > (4) Tweaked queries so they're not grouping entire tables > (5) Tried to find a commercial substitute for their program; there > isn't one even close > > The program was written by someone as their first big project, but was > generally well done. My only two real complaints are zero defaults for > foreign keys and no referential integrity (RI). I can't move forward > with recordsets without RI, as they won't be editable. So that's where > I'm going next. > > TIA, Fred -- John W. Colby From newsgrps at dalyn.co.nz Wed Apr 11 16:24:27 2018 From: newsgrps at dalyn.co.nz (David Emerson) Date: Thu, 12 Apr 2018 09:24:27 +1200 Subject: [AccessD] Form Totals and SQL Recordsets Message-ID: <004101d3d1db$78c425c0$6a4c7140$@dalyn.co.nz> Hi Listers, I have an accdb which uses recordsets based on SQL stored procedures to populate forms. One form is set to "Continuous Forms" which has columns of numbers. In the form footer under each column are fields for column totals. The control source for the total fields look like this: =Sum(Nz([SLOPSOpeningBalance],0)). SLOPSOpeningBalance is the field name. txtSLOPSOpeningBalance is the control name for the records. txtSLOPSOpeningBalanceSum is the name of the form footer control. The form footer control shows #Error. The main records all show correct values and there are no nulls. I am converting this database from an adp which worked fine (but the records came from the Record Source property) I haven't found a solution on the web for this. The closest solutions I have come up with is to write code to populate the totals, or to put a subform in the Form Footer which populates the fields based on a stored procedure which returns the totals. Has anyone come across this before? Regards David Emerson Dalyn Software Ltd Wellington, New Zealand From garykjos at gmail.com Wed Apr 11 18:08:19 2018 From: garykjos at gmail.com (Gary Kjos) Date: Wed, 11 Apr 2018 18:08:19 -0500 Subject: [AccessD] Form Totals and SQL Recordsets In-Reply-To: <004101d3d1db$78c425c0$6a4c7140$@dalyn.co.nz> References: <004101d3d1db$78c425c0$6a4c7140$@dalyn.co.nz> Message-ID: Typical no information error code. I would try to simplify what the control is supposed to be displaying... Perhaps by a saved query or maybe even a stored aggregate table just to take some other things like naming conventions and dots verses bangs or Exclamation or whatever BS has changed between Access versions. On Wed, Apr 11, 2018 at 4:24 PM, David Emerson wrote: > Hi Listers, > > I have an accdb which uses recordsets based on SQL stored procedures to > populate forms. > > One form is set to "Continuous Forms" which has columns of numbers. In the > form footer under each column are fields for column totals. > > The control source for the total fields look like this: > =Sum(Nz([SLOPSOpeningBalance],0)). > > SLOPSOpeningBalance is the field name. txtSLOPSOpeningBalance is the > control name for the records. txtSLOPSOpeningBalanceSum is the name of the > form footer control. > > The form footer control shows #Error. The main records all show correct > values and there are no nulls. I am converting this database from an adp > which worked fine (but the records came from the Record Source property) > > I haven't found a solution on the web for this. The closest solutions I > have come up with is to write code to populate the totals, or to put a > subform in the Form Footer which populates the fields based on a stored > procedure which returns the totals. > > Has anyone come across this before? > > Regards > > David Emerson > Dalyn Software Ltd > Wellington, New Zealand > > > > > -- > AccessD mailing list > AccessD at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/accessd > Website: http://www.databaseadvisors.com -- Gary Kjos garykjos at gmail.com From RockySmolin at bchacc.com Wed Apr 11 19:37:33 2018 From: RockySmolin at bchacc.com (RockySmolin at bchacc.com) Date: Wed, 11 Apr 2018 17:37:33 -0700 Subject: [AccessD] Form Totals and SQL Recordsets Message-ID: <20180411173733.86c3debdd1c3983866efe200e2feb95f.6ccc5836aa.wbe@email25.godaddy.com> I have always done something horrible in my bound forms but fortunately have never gotten bit by it ? I name the control the same as the control source. I know it?s a sin I should atone for and someday I will. Meanwhile try that and see if it solves the problem. i got into this bad habit because sometimes es you need to reference 5e control name and sometimes the record source. R -------- Original Message -------- Subject: [AccessD] Form Totals and SQL Recordsets From: "David Emerson" Date: Wed, April 11, 2018 2:24 pm To: "'Access Developers discussion and problem solving'" Hi Listers, I have an accdb which uses recordsets based on SQL stored procedures to populate forms. One form is set to "Continuous Forms" which has columns of numbers. In the form footer under each column are fields for column totals. The control source for the total fields look like this: =Sum(Nz([SLOPSOpeningBalance],0)). SLOPSOpeningBalance is the field name. txtSLOPSOpeningBalance is the control name for the records. txtSLOPSOpeningBalanceSum is the name of the form footer control. The form footer control shows #Error. The main records all show correct values and there are no nulls. I am converting this database from an adp which worked fine (but the records came from the Record Source property) I haven't found a solution on the web for this. The closest solutions I have come up with is to write code to populate the totals, or to put a subform in the Form Footer which populates the fields based on a stored procedure which returns the totals. Has anyone come across this before? Regards David Emerson Dalyn Software Ltd Wellington, New Zealand -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From newsgrps at dalyn.co.nz Wed Apr 11 21:59:03 2018 From: newsgrps at dalyn.co.nz (David Emerson) Date: Thu, 12 Apr 2018 14:59:03 +1200 Subject: [AccessD] Form Totals and SQL Recordsets In-Reply-To: <20180411173733.86c3debdd1c3983866efe200e2feb95f.6ccc5836aa.wbe@email25.godaddy.com> References: <20180411173733.86c3debdd1c3983866efe200e2feb95f.6ccc5836aa.wbe@email25.godaddy.com> Message-ID: <001201d3d20a$37200e70$a5602b50$@dalyn.co.nz> Hi Rocky, Have tried that already but no joy. Regards David -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of RockySmolin at bchacc.com Sent: Thursday, 12 April 2018 12:38 p.m. To: Access Developers discussion and problem solving Subject: Re: [AccessD] Form Totals and SQL Recordsets I have always done something horrible in my bound forms but fortunately have never gotten bit by it ? I name the control the same as the control source. I know it?s a sin I should atone for and someday I will. Meanwhile try that and see if it solves the problem. i got into this bad habit because sometimes es you need to reference 5e control name and sometimes the record source. R -------- Original Message -------- Subject: [AccessD] Form Totals and SQL Recordsets From: "David Emerson" Date: Wed, April 11, 2018 2:24 pm To: "'Access Developers discussion and problem solving'" Hi Listers, I have an accdb which uses recordsets based on SQL stored procedures to populate forms. One form is set to "Continuous Forms" which has columns of numbers. In the form footer under each column are fields for column totals. The control source for the total fields look like this: =Sum(Nz([SLOPSOpeningBalance],0)). SLOPSOpeningBalance is the field name. txtSLOPSOpeningBalance is the control name for the records. txtSLOPSOpeningBalanceSum is the name of the form footer control. The form footer control shows #Error. The main records all show correct values and there are no nulls. I am converting this database from an adp which worked fine (but the records came from the Record Source property) I haven't found a solution on the web for this. The closest solutions I have come up with is to write code to populate the totals, or to put a subform in the Form Footer which populates the fields based on a stored procedure which returns the totals. Has anyone come across this before? Regards David Emerson Dalyn Software Ltd Wellington, New Zealand -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From newsgrps at dalyn.co.nz Wed Apr 11 22:01:36 2018 From: newsgrps at dalyn.co.nz (David Emerson) Date: Thu, 12 Apr 2018 15:01:36 +1200 Subject: [AccessD] Form Totals and SQL Recordsets In-Reply-To: References: <004101d3d1db$78c425c0$6a4c7140$@dalyn.co.nz> Message-ID: <001301d3d20a$91ff7420$b5fe5c60$@dalyn.co.nz> Thanks for the reply Gary, Sounds like what I am ending up doing (putting a subform in the Form Footer which populates the fields based on a stored procedure which returns the totals.) Regards David -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Gary Kjos Sent: Thursday, 12 April 2018 11:08 a.m. To: Access Developers discussion and problem solving Subject: Re: [AccessD] Form Totals and SQL Recordsets Typical no information error code. I would try to simplify what the control is supposed to be displaying... Perhaps by a saved query or maybe even a stored aggregate table just to take some other things like naming conventions and dots verses bangs or Exclamation or whatever BS has changed between Access versions. On Wed, Apr 11, 2018 at 4:24 PM, David Emerson wrote: > Hi Listers, > > I have an accdb which uses recordsets based on SQL stored procedures to > populate forms. > > One form is set to "Continuous Forms" which has columns of numbers. In the > form footer under each column are fields for column totals. > > The control source for the total fields look like this: > =Sum(Nz([SLOPSOpeningBalance],0)). > > SLOPSOpeningBalance is the field name. txtSLOPSOpeningBalance is the > control name for the records. txtSLOPSOpeningBalanceSum is the name of the > form footer control. > > The form footer control shows #Error. The main records all show correct > values and there are no nulls. I am converting this database from an adp > which worked fine (but the records came from the Record Source property) > > I haven't found a solution on the web for this. The closest solutions I > have come up with is to write code to populate the totals, or to put a > subform in the Form Footer which populates the fields based on a stored > procedure which returns the totals. > > Has anyone come across this before? > > Regards > > David Emerson > Dalyn Software Ltd > Wellington, New Zealand > > > > > -- > AccessD mailing list > AccessD at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/accessd > Website: http://www.databaseadvisors.com -- Gary Kjos garykjos at gmail.com -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From RockySmolin at bchacc.com Wed Apr 11 22:23:43 2018 From: RockySmolin at bchacc.com (RockySmolin at bchacc.com) Date: Wed, 11 Apr 2018 20:23:43 -0700 Subject: [AccessD] Form Totals and SQL Recordsets Message-ID: <20180411202343.86c3debdd1c3983866efe200e2feb95f.099def1661.wbe@email25.godaddy.com> Well this wouldn?t solve a he problem but work around it - replace the sum with a query that does the same as thing? -------- Original Message -------- Subject: Re: [AccessD] Form Totals and SQL Recordsets From: "David Emerson" Date: Wed, April 11, 2018 7:59 pm To: "'Access Developers discussion and problem solving'" Hi Rocky, Have tried that already but no joy. Regards David -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of RockySmolin at bchacc.com Sent: Thursday, 12 April 2018 12:38 p.m. To: Access Developers discussion and problem solving Subject: Re: [AccessD] Form Totals and SQL Recordsets I have always done something horrible in my bound forms but fortunately have never gotten bit by it ? I name the control the same as the control source. I know it?s a sin I should atone for and someday I will. Meanwhile try that and see if it solves the problem. i got into this bad habit because sometimes es you need to reference 5e control name and sometimes the record source. R -------- Original Message -------- Subject: [AccessD] Form Totals and SQL Recordsets From: "David Emerson" Date: Wed, April 11, 2018 2:24 pm To: "'Access Developers discussion and problem solving'" Hi Listers, I have an accdb which uses recordsets based on SQL stored procedures to populate forms. One form is set to "Continuous Forms" which has columns of numbers. In the form footer under each column are fields for column totals. The control source for the total fields look like this: =Sum(Nz([SLOPSOpeningBalance],0)). SLOPSOpeningBalance is the field name. txtSLOPSOpeningBalance is the control name for the records. txtSLOPSOpeningBalanceSum is the name of the form footer control. The form footer control shows #Error. The main records all show correct values and there are no nulls. I am converting this database from an adp which worked fine (but the records came from the Record Source property) I haven't found a solution on the web for this. The closest solutions I have come up with is to write code to populate the totals, or to put a subform in the Form Footer which populates the fields based on a stored procedure which returns the totals. Has anyone come across this before? Regards David Emerson Dalyn Software Ltd Wellington, New Zealand -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From newsgrps at dalyn.co.nz Wed Apr 11 22:43:45 2018 From: newsgrps at dalyn.co.nz (David Emerson) Date: Thu, 12 Apr 2018 15:43:45 +1200 Subject: [AccessD] Form Totals and SQL Recordsets In-Reply-To: <20180411202343.86c3debdd1c3983866efe200e2feb95f.099def1661.wbe@email25.godaddy.com> References: <20180411202343.86c3debdd1c3983866efe200e2feb95f.099def1661.wbe@email25.godaddy.com> Message-ID: <002001d3d210$75a2ce70$60e86b50$@dalyn.co.nz> Yep - that's what I ended up with. -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of RockySmolin at bchacc.com Sent: Thursday, 12 April 2018 3:24 p.m. To: Access Developers discussion and problem solving Subject: Re: [AccessD] Form Totals and SQL Recordsets Well this wouldn?t solve a he problem but work around it - replace the sum with a query that does the same as thing? -------- Original Message -------- Subject: Re: [AccessD] Form Totals and SQL Recordsets From: "David Emerson" Date: Wed, April 11, 2018 7:59 pm To: "'Access Developers discussion and problem solving'" Hi Rocky, Have tried that already but no joy. Regards David -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of RockySmolin at bchacc.com Sent: Thursday, 12 April 2018 12:38 p.m. To: Access Developers discussion and problem solving Subject: Re: [AccessD] Form Totals and SQL Recordsets I have always done something horrible in my bound forms but fortunately have never gotten bit by it ? I name the control the same as the control source. I know it?s a sin I should atone for and someday I will. Meanwhile try that and see if it solves the problem. i got into this bad habit because sometimes es you need to reference 5e control name and sometimes the record source. R -------- Original Message -------- Subject: [AccessD] Form Totals and SQL Recordsets From: "David Emerson" Date: Wed, April 11, 2018 2:24 pm To: "'Access Developers discussion and problem solving'" Hi Listers, I have an accdb which uses recordsets based on SQL stored procedures to populate forms. One form is set to "Continuous Forms" which has columns of numbers. In the form footer under each column are fields for column totals. The control source for the total fields look like this: =Sum(Nz([SLOPSOpeningBalance],0)). SLOPSOpeningBalance is the field name. txtSLOPSOpeningBalance is the control name for the records. txtSLOPSOpeningBalanceSum is the name of the form footer control. The form footer control shows #Error. The main records all show correct values and there are no nulls. I am converting this database from an adp which worked fine (but the records came from the Record Source property) I haven't found a solution on the web for this. The closest solutions I have come up with is to write code to populate the totals, or to put a subform in the Form Footer which populates the fields based on a stored procedure which returns the totals. Has anyone come across this before? Regards David Emerson Dalyn Software Ltd Wellington, New Zealand -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From gustav at cactus.dk Thu Apr 12 03:05:44 2018 From: gustav at cactus.dk (Gustav Brock) Date: Thu, 12 Apr 2018 08:05:44 +0000 Subject: [AccessD] Microsoft Office Support - animated GIFs Message-ID: Hi all Microsoft is currently busy with improving the support and help pages, focusing on those with a poor feedback. Recently, I worked with Jeff Conrad to improve a topic I recall - in my early Access days - to be difficult to get hold on, due to the total lack of visual help: Union queries. The old article was lengthy and with much text, and for many - from the feedback to read - simply uncomprehensive. So, I brought in the collapsible view used widely by Microsoft and some animated GIFs to make it more appealing. While animated GIFs is a quick method to visualise things, they aren't easy to edit, and they are not that user friendly - you cannot stop the animation, and it isn't easy to start over, and - in general - users are more familiar with videos. Thus, Jeff decided to remake them as videos. Only the first has been replaced, so the second GIF is still on-line: Use a union query to combine multiple queries into a single result https://support.office.com/en-us/article/Use-a-union-query-to-combine-multiple-queries-into-a-single-result-1F772EC0-CC73-474D-AB10-AD0A75541C6E What do you think of this format? I'm not asking for "likes" (= This page was helpful). Rather, you should not, as you are not in the target group. /gustav From gustav at cactus.dk Thu Apr 12 04:11:46 2018 From: gustav at cactus.dk (Gustav Brock) Date: Thu, 12 Apr 2018 09:11:46 +0000 Subject: [AccessD] Microsoft Office Support - animated GIFs In-Reply-To: References: Message-ID: Hi all Microsoft is currently busy with improving the support and help pages, focusing on those with a poor feedback. Recently, I worked with Jeff Conrad to improve a topic I recall - in my early Access days - to be difficult to get hold on, due to the total lack of visual help: Union queries. The old article was lengthy and with much text, and for many - from the feedback to read - simply uncomprehensive. So, I brought in the collapsible view used widely by Microsoft and some animated GIFs to make it more appealing. While animated GIFs is a quick method to visualise things, they aren't easy to edit, and they are not that user friendly - you cannot stop the animation, and it isn't easy to start over, and - in general - users are more familiar with videos. Thus, Jeff decided to remake them as videos. Only the first has been replaced, so the second GIF is still on-line: Use a union query to combine multiple queries into a single result https://support.office.com/en-us/article/Use-a-union-query-to-combine-multiple-queries-into-a-single-result-1F772EC0-CC73-474D-AB10-AD0A75541C6E What do you think of this format? I'm not asking for "likes" (= This page was helpful). Rather, you should not, as you are not in the target group. /gustav From gustav at cactus.dk Thu Apr 12 05:09:29 2018 From: gustav at cactus.dk (Gustav Brock) Date: Thu, 12 Apr 2018 10:09:29 +0000 Subject: [AccessD] Rounding. The collection. Message-ID: Hi all Recently, I've supplemented this with rounding of a sum and rounding with the power of two: Round elements of a sum to match a total https://www.experts-exchange.com/articles/31683/Round-elements-of-a-sum-to-match-a-total.html Round by the power of two https://www.experts-exchange.com/articles/31859/Round-by-the-power-of-two.html Both operates with Decimal for extreme precision for "normal" numbers and with Double for very large or small numbers. /gustav -----Oprindelig meddelelse----- Fra: AccessD [mailto:accessd-bounces at databaseadvisors.com] P? vegne af Gustav Brock Sendt: 31. august 2015 22:33 Til: Access Developers discussion and problem solving Emne: [AccessD] Rounding. The collection. Hi all After many years I've managed to collect and polish the rounding functions I have for VBA and posted these at Experts Exchange: "Rounding values up, down, by 4/5, or to significant figures" http://rdsrc.us/4phszx The challenge is to handle both the very large and very small numbers of Double, floating point errors, and the large values and large count of decimals for Decimal - as well as symmetrical/asymmetrical rounding up/down of positive/negative values. /gustav From jimdettman at verizon.net Thu Apr 12 06:23:40 2018 From: jimdettman at verizon.net (Jim Dettman) Date: Thu, 12 Apr 2018 07:23:40 -0400 Subject: [AccessD] Microsoft Office Support - animated GIFs In-Reply-To: References: Message-ID: <005101d3d250$b5a2ac30$20e80490$@verizon.net> Gustav, Video is far better. As you said, the animated GIFs are hard to work with in a learning situation, mainly in that you cannot pause them. The GIF in the article you pointed to was too fast for me to follow. Jim. -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Gustav Brock Sent: Thursday, April 12, 2018 5:12 AM To: Access Developers discussion and problem solving Subject: [AccessD] Microsoft Office Support - animated GIFs Hi all Microsoft is currently busy with improving the support and help pages, focusing on those with a poor feedback. Recently, I worked with Jeff Conrad to improve a topic I recall - in my early Access days - to be difficult to get hold on, due to the total lack of visual help: Union queries. The old article was lengthy and with much text, and for many - from the feedback to read - simply uncomprehensive. So, I brought in the collapsible view used widely by Microsoft and some animated GIFs to make it more appealing. While animated GIFs is a quick method to visualise things, they aren't easy to edit, and they are not that user friendly - you cannot stop the animation, and it isn't easy to start over, and - in general - users are more familiar with videos. Thus, Jeff decided to remake them as videos. Only the first has been replaced, so the second GIF is still on-line: Use a union query to combine multiple queries into a single result https://support.office.com/en-us/article/Use-a-union-query-to-combine-multip le-queries-into-a-single-result-1F772EC0-CC73-474D-AB10-AD0A75541C6E What do you think of this format? I'm not asking for "likes" (= This page was helpful). Rather, you should not, as you are not in the target group. /gustav -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From gustav at cactus.dk Thu Apr 12 06:47:09 2018 From: gustav at cactus.dk (Gustav Brock) Date: Thu, 12 Apr 2018 11:47:09 +0000 Subject: [AccessD] Microsoft Office Support - animated GIFs Message-ID: Hi Jim Yes, speed is difficult. If too slow, some will quickly run out of patience. The trick with the arrows in the video, that directs to the next action, is a great help. The original GIF ran at nearly the same speed as the video if the arrows were excluded. /gustav -----Oprindelig meddelelse----- Fra: AccessD [mailto:accessd-bounces at databaseadvisors.com] P? vegne af Jim Dettman Sendt: 12. april 2018 13:24 Til: 'Access Developers discussion and problem solving' Emne: Re: [AccessD] Microsoft Office Support - animated GIFs Gustav, Video is far better. As you said, the animated GIFs are hard to work with in a learning situation, mainly in that you cannot pause them. The GIF in the article you pointed to was too fast for me to follow. Jim. -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Gustav Brock Sent: Thursday, April 12, 2018 5:12 AM To: Access Developers discussion and problem solving Subject: [AccessD] Microsoft Office Support - animated GIFs Hi all Microsoft is currently busy with improving the support and help pages, focusing on those with a poor feedback. Recently, I worked with Jeff Conrad to improve a topic I recall - in my early Access days - to be difficult to get hold on, due to the total lack of visual help: Union queries. The old article was lengthy and with much text, and for many - from the feedback to read - simply uncomprehensive. So, I brought in the collapsible view used widely by Microsoft and some animated GIFs to make it more appealing. While animated GIFs is a quick method to visualise things, they aren't easy to edit, and they are not that user friendly - you cannot stop the animation, and it isn't easy to start over, and - in general - users are more familiar with videos. Thus, Jeff decided to remake them as videos. Only the first has been replaced, so the second GIF is still on-line: Use a union query to combine multiple queries into a single result https://support.office.com/en-us/article/Use-a-union-query-to-combine-multip le-queries-into-a-single-result-1F772EC0-CC73-474D-AB10-AD0A75541C6E What do you think of this format? I'm not asking for "likes" (= This page was helpful). Rather, you should not, as you are not in the target group. /gustav From RockySmolin at bchacc.com Thu Apr 12 07:50:28 2018 From: RockySmolin at bchacc.com (RockySmolin at bchacc.com) Date: Thu, 12 Apr 2018 05:50:28 -0700 Subject: [AccessD] Microsoft Office Support - animated GIFs Message-ID: <20180412055028.86c3debdd1c3983866efe200e2feb95f.504151f559.wbe@email25.godaddy.com> You can always hit the pause button to see what?s going on better. But wouldn?t a series of pictures showing the progression as it is in the video of the steps especially separating the sequel, wouldn?t that be easier to digest? R -------- Original Message -------- Subject: Re: [AccessD] Microsoft Office Support - animated GIFs From: Gustav Brock Date: Thu, April 12, 2018 4:47 am To: Access Developers discussion and problem solving Hi Jim Yes, speed is difficult. If too slow, some will quickly run out of patience. The trick with the arrows in the video, that directs to the next action, is a great help. The original GIF ran at nearly the same speed as the video if the arrows were excluded. /gustav -----Oprindelig meddelelse----- Fra: AccessD [mailto:accessd-bounces at databaseadvisors.com] P? vegne af Jim Dettman Sendt: 12. april 2018 13:24 Til: 'Access Developers discussion and problem solving' Emne: Re: [AccessD] Microsoft Office Support - animated GIFs Gustav, Video is far better. As you said, the animated GIFs are hard to work with in a learning situation, mainly in that you cannot pause them. The GIF in the article you pointed to was too fast for me to follow. Jim. -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Gustav Brock Sent: Thursday, April 12, 2018 5:12 AM To: Access Developers discussion and problem solving Subject: [AccessD] Microsoft Office Support - animated GIFs Hi all Microsoft is currently busy with improving the support and help pages, focusing on those with a poor feedback. Recently, I worked with Jeff Conrad to improve a topic I recall - in my early Access days - to be difficult to get hold on, due to the total lack of visual help: Union queries. The old article was lengthy and with much text, and for many - from the feedback to read - simply uncomprehensive. So, I brought in the collapsible view used widely by Microsoft and some animated GIFs to make it more appealing. While animated GIFs is a quick method to visualise things, they aren't easy to edit, and they are not that user friendly - you cannot stop the animation, and it isn't easy to start over, and - in general - users are more familiar with videos. Thus, Jeff decided to remake them as videos. Only the first has been replaced, so the second GIF is still on-line: Use a union query to combine multiple queries into a single result https://support.office.com/en-us/article/Use-a-union-query-to-combine-multip le-queries-into-a-single-result-1F772EC0-CC73-474D-AB10-AD0A75541C6E What do you think of this format? I'm not asking for "likes" (= This page was helpful). Rather, you should not, as you are not in the target group. /gustav -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From bensonforums at gmail.com Thu Apr 12 08:26:52 2018 From: bensonforums at gmail.com (Bill Benson) Date: Thu, 12 Apr 2018 09:26:52 -0400 Subject: [AccessD] Microsoft Office Support - animated GIFs In-Reply-To: References: Message-ID: Format a union query? Every time I format a query, my carriage returns are sucked out again by Access next time I view the queries in SQL view, and everything tuns together again. On Thu, Apr 12, 2018 at 4:05 AM, Gustav Brock wrote: > Hi all > > Microsoft is currently busy with improving the support and help pages, > focusing on those with a poor feedback. > Recently, I worked with Jeff Conrad to improve a topic I recall - in my > early Access days - to be difficult to get hold on, due to the total lack > of visual help: Union queries. > > The old article was lengthy and with much text, and for many - from the > feedback to read - simply uncomprehensive. > So, I brought in the collapsible view used widely by Microsoft and some > animated GIFs to make it more appealing. > > While animated GIFs is a quick method to visualise things, they aren't > easy to edit, and they are not that user friendly - you cannot stop the > animation, and it isn't easy to start over, and - in general - users are > more familiar with videos. > Thus, Jeff decided to remake them as videos. Only the first has been > replaced, so the second GIF is still on-line: > > Use a union query to combine multiple queries into a single result > https://support.office.com/en-us/article/Use-a-union-query- > to-combine-multiple-queries-into-a-single-result-1F772EC0- > CC73-474D-AB10-AD0A75541C6E > > What do you think of this format? > > I'm not asking for "likes" (= This page was helpful). Rather, you should > not, as you are not in the target group. > > /gustav > -- > AccessD mailing list > AccessD at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/accessd > Website: http://www.databaseadvisors.com > From gustav at cactus.dk Thu Apr 12 08:33:17 2018 From: gustav at cactus.dk (Gustav Brock) Date: Thu, 12 Apr 2018 13:33:17 +0000 Subject: [AccessD] Microsoft Office Support - animated GIFs Message-ID: Hi Rocky I don't think so. It quickly becomes a lot of pictures, and you constantly need to compare each picture with the one before to find out the action taken. /gustav -----Oprindelig meddelelse----- Fra: AccessD [mailto:accessd-bounces at databaseadvisors.com] P? vegne af RockySmolin at bchacc.com Sendt: 12. april 2018 14:50 Til: Access Developers discussion and problem solving Emne: Re: [AccessD] Microsoft Office Support - animated GIFs You can always hit the pause button to see what?s going on better. But wouldn?t a series of pictures showing the progression as it is in the video of the steps especially separating the sequel, wouldn?t that be easier to digest? R -------- Original Message -------- Subject: Re: [AccessD] Microsoft Office Support - animated GIFs From: Gustav Brock Date: Thu, April 12, 2018 4:47 am To: Access Developers discussion and problem solving Hi Jim Yes, speed is difficult. If too slow, some will quickly run out of patience. The trick with the arrows in the video, that directs to the next action, is a great help. The original GIF ran at nearly the same speed as the video if the arrows were excluded. /gustav -----Oprindelig meddelelse----- Fra: AccessD [mailto:accessd-bounces at databaseadvisors.com] P? vegne af Jim Dettman Sendt: 12. april 2018 13:24 Til: 'Access Developers discussion and problem solving' Emne: Re: [AccessD] Microsoft Office Support - animated GIFs Gustav, Video is far better. As you said, the animated GIFs are hard to work with in a learning situation, mainly in that you cannot pause them. The GIF in the article you pointed to was too fast for me to follow. Jim. -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Gustav Brock Sent: Thursday, April 12, 2018 5:12 AM To: Access Developers discussion and problem solving Subject: [AccessD] Microsoft Office Support - animated GIFs Hi all Microsoft is currently busy with improving the support and help pages, focusing on those with a poor feedback. Recently, I worked with Jeff Conrad to improve a topic I recall - in my early Access days - to be difficult to get hold on, due to the total lack of visual help: Union queries. The old article was lengthy and with much text, and for many - from the feedback to read - simply uncomprehensive. So, I brought in the collapsible view used widely by Microsoft and some animated GIFs to make it more appealing. While animated GIFs is a quick method to visualise things, they aren't easy to edit, and they are not that user friendly - you cannot stop the animation, and it isn't easy to start over, and - in general - users are more familiar with videos. Thus, Jeff decided to remake them as videos. Only the first has been replaced, so the second GIF is still on-line: Use a union query to combine multiple queries into a single result https://support.office.com/en-us/article/Use-a-union-query-to-combine-multip le-queries-into-a-single-result-1F772EC0-CC73-474D-AB10-AD0A75541C6E What do you think of this format? I'm not asking for "likes" (= This page was helpful). Rather, you should not, as you are not in the target group. /gustav From gustav at cactus.dk Thu Apr 12 08:36:14 2018 From: gustav at cactus.dk (Gustav Brock) Date: Thu, 12 Apr 2018 13:36:14 +0000 Subject: [AccessD] Microsoft Office Support - animated GIFs Message-ID: Hi Bill It's not that bad with union queries as you have no GUI designer to switch to. The formatting in the video and the GIF is to make the parts stand out more clearly. /gustav -----Oprindelig meddelelse----- Fra: AccessD [mailto:accessd-bounces at databaseadvisors.com] P? vegne af Bill Benson Sendt: 12. april 2018 15:27 Til: Access Developers discussion and problem solving Emne: Re: [AccessD] Microsoft Office Support - animated GIFs Format a union query? Every time I format a query, my carriage returns are sucked out again by Access next time I view the queries in SQL view, and everything tuns together again. On Thu, Apr 12, 2018 at 4:05 AM, Gustav Brock wrote: > Hi all > > Microsoft is currently busy with improving the support and help pages, > focusing on those with a poor feedback. > Recently, I worked with Jeff Conrad to improve a topic I recall - in > my early Access days - to be difficult to get hold on, due to the > total lack of visual help: Union queries. > > The old article was lengthy and with much text, and for many - from > the feedback to read - simply uncomprehensive. > So, I brought in the collapsible view used widely by Microsoft and > some animated GIFs to make it more appealing. > > While animated GIFs is a quick method to visualise things, they aren't > easy to edit, and they are not that user friendly - you cannot stop > the animation, and it isn't easy to start over, and - in general - > users are more familiar with videos. > Thus, Jeff decided to remake them as videos. Only the first has been > replaced, so the second GIF is still on-line: > > Use a union query to combine multiple queries into a single result > https://support.office.com/en-us/article/Use-a-union-query- > to-combine-multiple-queries-into-a-single-result-1F772EC0- > CC73-474D-AB10-AD0A75541C6E > > What do you think of this format? > > I'm not asking for "likes" (= This page was helpful). Rather, you > should not, as you are not in the target group. > > /gustav From accessd at shaw.ca Thu Apr 12 10:54:16 2018 From: accessd at shaw.ca (Jim Lawrence) Date: Thu, 12 Apr 2018 09:54:16 -0600 (MDT) Subject: [AccessD] Microsoft Office Support - animated GIFs In-Reply-To: References: Message-ID: <1606171590.479617298.1523548456304.JavaMail.zimbra@shaw.ca> That is really cool. :-) Jim ----- Original Message ----- From: "Gustav Brock" To: "Access Developers discussion and problem solving" , accessmvp at googlegroups.com Sent: Thursday, April 12, 2018 1:05:44 AM Subject: [AccessD] Microsoft Office Support - animated GIFs Hi all Microsoft is currently busy with improving the support and help pages, focusing on those with a poor feedback. Recently, I worked with Jeff Conrad to improve a topic I recall - in my early Access days - to be difficult to get hold on, due to the total lack of visual help: Union queries. The old article was lengthy and with much text, and for many - from the feedback to read - simply uncomprehensive. So, I brought in the collapsible view used widely by Microsoft and some animated GIFs to make it more appealing. While animated GIFs is a quick method to visualise things, they aren't easy to edit, and they are not that user friendly - you cannot stop the animation, and it isn't easy to start over, and - in general - users are more familiar with videos. Thus, Jeff decided to remake them as videos. Only the first has been replaced, so the second GIF is still on-line: Use a union query to combine multiple queries into a single result https://support.office.com/en-us/article/Use-a-union-query-to-combine-multiple-queries-into-a-single-result-1F772EC0-CC73-474D-AB10-AD0A75541C6E What do you think of this format? I'm not asking for "likes" (= This page was helpful). Rather, you should not, as you are not in the target group. /gustav -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From accessd at shaw.ca Thu Apr 12 22:23:50 2018 From: accessd at shaw.ca (Jim Lawrence) Date: Thu, 12 Apr 2018 21:23:50 -0600 (MDT) Subject: [AccessD] Rounding. The collection. In-Reply-To: References: Message-ID: <748207039.481418751.1523589830424.JavaMail.zimbra@shaw.ca> You never fail to amaze me. :-) Jim ----- Original Message ----- From: "Gustav Brock" To: "Access Developers discussion and problem solving" Sent: Thursday, April 12, 2018 3:09:29 AM Subject: Re: [AccessD] Rounding. The collection. Hi all Recently, I've supplemented this with rounding of a sum and rounding with the power of two: Round elements of a sum to match a total https://www.experts-exchange.com/articles/31683/Round-elements-of-a-sum-to-match-a-total.html Round by the power of two https://www.experts-exchange.com/articles/31859/Round-by-the-power-of-two.html Both operates with Decimal for extreme precision for "normal" numbers and with Double for very large or small numbers. /gustav -----Oprindelig meddelelse----- Fra: AccessD [mailto:accessd-bounces at databaseadvisors.com] P? vegne af Gustav Brock Sendt: 31. august 2015 22:33 Til: Access Developers discussion and problem solving Emne: [AccessD] Rounding. The collection. Hi all After many years I've managed to collect and polish the rounding functions I have for VBA and posted these at Experts Exchange: "Rounding values up, down, by 4/5, or to significant figures" http://rdsrc.us/4phszx The challenge is to handle both the very large and very small numbers of Double, floating point errors, and the large values and large count of decimals for Decimal - as well as symmetrical/asymmetrical rounding up/down of positive/negative values. /gustav -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From accessd at shaw.ca Fri Apr 13 00:28:22 2018 From: accessd at shaw.ca (Jim Lawrence) Date: Thu, 12 Apr 2018 23:28:22 -0600 (MDT) Subject: [AccessD] Jeremy Corbyn In-Reply-To: <748207039.481418751.1523589830424.JavaMail.zimbra@shaw.ca> References: <748207039.481418751.1523589830424.JavaMail.zimbra@shaw.ca> Message-ID: <1187192070.481676071.1523597302833.JavaMail.zimbra@shaw.ca> Jeremy Corbyn, of the UK labour party, similar to the Democrats but left like Bernie Sanders, has just said that Theresa May, of the Tory party, after her rant about the guilt of the Russians, is putting the cart ahead of horse...first procedures must be followed, evidence must be produced, for everyone to see and then both side must make a legal determination. It seems to me that that position is very statesman like. But the establishment press went berserk, accusing him of being a Putin-puppet and a criminal and then the Tories have piled on. (You know the usual sort of crap we read on the OT.) Enter a real announcer, you know the type, one with strength of character. It so refreshing after watching the smarmy, placid and cowardly announcers, we call our news anchors, on our own networks. No wonder no one listens to main-stream news anymore. The following should be required viewing for every western news announcer. https://www.youtube.com/watch?v=P5keoT4PvPs Jim From gustav at cactus.dk Mon Apr 16 10:35:38 2018 From: gustav at cactus.dk (Gustav Brock) Date: Mon, 16 Apr 2018 15:35:38 +0000 Subject: [AccessD] Microsoft Office Support - animated GIFs Message-ID: Thank you all for the very useful feedback! I have assembled the essence of all the topics touched in your feedback and passed it anonymized to Jeff - and already got the answer, why animated GIFs aren't that great: Accessibility. So, that is why you only meet very few of these at the Microsoft support pages. I can add, that the second animated GIF now has been replaced with a neat video. This video also has sound - for the simple reason that various tests with pages using videos with sound gives a measurable better user response than pages with dumb videos. Nothing is random. /gustav Fra: mailto:accessmvp at googlegroups.com [mailto:accessmvp at googlegroups.com] P? vegne af Gustav Brock Sendt: 12. april 2018 10:06 Til: Access Developers discussion and problem solving Emne: [AccessMVP] Microsoft Office Support - animated GIFs Hi all Microsoft is currently busy with improving the support and help pages, focusing on those with a poor feedback. Recently, I worked with Jeff Conrad to improve a topic I recall - in my early Access days - ?to be difficult to get hold on, due to the total lack of visual help: Union queries. The old article was lengthy and with much text, and for many - from the feedback to read - simply uncomprehensive. So, I brought in the collapsible view used widely by Microsoft and some animated GIFs to make it more appealing. While animated GIFs is a quick method to visualise things, they aren't easy to edit, and they are not that user friendly - you cannot stop the animation, and it isn't easy to start over, and - in general - users are more familiar with videos. Thus, Jeff decided to remake them as videos. Only the first has been replaced, so the second GIF is still on-line: ??? Use a union query to combine multiple queries into a single result ??? https://support.office.com/en-us/article/Use-a-union-query-to-combine-multiple-queries-into-a-single-result-1F772EC0-CC73-474D-AB10-AD0A75541C6E What do you think of this format? I'm not asking for "likes" (= This page was helpful). Rather, you should not, as you are not in the target group. /gustav From newsgrps at dalyn.co.nz Sun Apr 22 23:18:02 2018 From: newsgrps at dalyn.co.nz (David Emerson) Date: Mon, 23 Apr 2018 16:18:02 +1200 Subject: [AccessD] Connection Strings for SQL2012R2 Message-ID: <00ba01d3daba$127b2970$37717c50$@dalyn.co.nz> Hi Listers, I have an Access accdb which connects to an SQL database. Currently I connect to an sql database in SQL2008 which runs fine. The connection strings are: Set gADODBConnection = New ADODB.Connection gADODBConnection.ConnectionString = "Provider=sqloledb;Data Source=SWLGWCLUT12;Initial Catalog=StockData5;Integrated Security=SSPI;" Dim strTempQueryName As String, qdefTemp As DAO.QueryDef strTempQueryName = "qryTempQuery1" Set qdefTemp = CurrentDb.CreateQueryDef(strTempQueryName) qdefTemp.ReturnsRecords = True qdefTemp.ODBCTimeout = 300 qdefTemp.Connect = "ODBC;DRIVER=SQL Server;SERVER=SWLGWCLUT12;DATABASE=StockData5;Trusted_Connection=Yes" I am trying to set up the database on an RDS server (being 2012 R2) but according to the IT people the problem is that we cannot install the x86 SQL driver that access needs as this seems to be unsupported. We have tried bypassing this initial issue by creating a DSN using the "ODBC Driver 11 for SQL Server" and using this code for the global connection: gADODBConnection.ConnectionString = "DSN=StocksData5;Trusted_Connection=yes;" This seems to work but when we try to attach tables we get an error message: Error 3027: Cannot Update. Database or object is read-only. Public Function AttachDSNLessTable(stLocalTableName As String, stRemoteTableName As String, stServer As String, stDatabase As String, Optional stUsername As String, Optional stPassword As String, Optional stKeyfield As String) '//Name : AttachDSNLessTable '//Purpose : Create a linked table to SQL Server without using a DSN '//Parameters '// stLocalTableName: Name of the table that you are creating in the current database '// stRemoteTableName: Name of the table that you are linking to on the SQL Server database '// stServer: Name of the SQL Server that you are linking to '// stDatabase: Name of the SQL Server database that you are linking to '// stUsername: Name of the SQL Server user who can connect to SQL Server, leave blank to use a Trusted Connection '// stPassword: SQL Server user password '// stKeyfield: Name of field if stRemoteTableName is a view. This is used to set up an index so data can be edited On Error GoTo Err_AttachDSNLessTable Dim td As TableDef Dim stConnect As String For Each td In CurrentDb.TableDefs If td.Name = stLocalTableName Then CurrentDb.TableDefs.Delete stLocalTableName End If Next If Len(stUsername) = 0 Then '//Use trusted authentication if stUsername is not supplied. stConnect = "ODBC;DRIVER=SQL Server;SERVER=" & stServer & ";DATABASE=" & stDatabase & ";Trusted_Connection=Yes" Else '//WARNING: This will save the username and the password with the linked table information. stConnect = "ODBC;DRIVER=SQL Server;SERVER=" & stServer & ";DATABASE=" & stDatabase & ";UID=" & stUsername & ";PWD=" & stPassword End If Set td = CurrentDb.CreateTableDef(stLocalTableName, dbAttachSavePWD, stRemoteTableName, stConnect) CurrentDb.TableDefs.Append td If Len(stKeyfield) > 0 Then CurrentDb.Execute "CREATE UNIQUE INDEX 'PrimaryKey' ON " & stLocalTableName & " (" & stKeyfield & ") WITH PRIMARY" End If Does anyone know what connection string I can use? Regards David Emerson Dalyn Software Ltd Wellington, New Zealand From wrwehler at gmail.com Mon Apr 23 09:08:30 2018 From: wrwehler at gmail.com (Ryan W) Date: Mon, 23 Apr 2018 09:08:30 -0500 Subject: [AccessD] Suppress error message dialog Message-ID: I've got some tricky users that were getting around some of my validation process on a datasheet... I had set the combo boxes to limit to list on objects that were 'active' in inventory. They got around this by pasting in records from a previous piece of work.. which doesn't go trigger the combobox validation. In this instance I decided to use an "INSTEAD OF INSERT" trigger on my SQL Back end... The problem now becomes they get an error message that I raise in the trigger, but then they get a dialog box that says: "Do you want to suppress further error messages telling you why records can't be pasted". The default option is "yes". here. They need to answer "no" to see more messages, but ideally I'd like to completely suppress this box from coming up and have it spew every "paste error" at them. Does anyone have any ideas how I might do that without changing the validation code to the front end? From df.waters at outlook.com Mon Apr 23 09:44:47 2018 From: df.waters at outlook.com (Dan Waters) Date: Mon, 23 Apr 2018 14:44:47 +0000 Subject: [AccessD] Suppress error message dialog In-Reply-To: References: Message-ID: Hi Ryan, I wouldn't see this is as primarily a technology issue for you to solve. It sounds like they have a different belief in what their process is than you are aware of. I'd get together with a few of the experienced users to find out what's going on? It might be that they know that they can use a non-active object on your form because it will soon be active? Just a guess... If what they are doing turns out to be OK then perhaps you could add a 'Clone' button next to the previous records so they don't need to copy/paste. If you and your users are working in the same company then you should raise this issue with your management and theirs. This is not to give them grief, but just so that everyone knows that this issue is happening. You can describe the consequences of taking these actions and then they can decide if they want to continue on this way or if they want to 'obey' your validation warnings. Put the problem on their back instead of yours. If you are working for a client it's about the same thing - but you'll need to be more formal by writing up a document of what's happening and what the consequences are. Let your contact person know that you are going to send this to him or her so they can decide how to proceed. For the technical solution it seems like you are presenting a form in table view which allows them so paste in a record (I've just never done that). You could change the form to form view with all individual fields which then have all the correct validation code. More work for them but then they probably can't get around the validation. Good Luck! Dan -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Ryan W Sent: April 23, 2018 09:08 To: Access Developers discussion and problem solving Subject: [AccessD] Suppress error message dialog I've got some tricky users that were getting around some of my validation process on a datasheet... I had set the combo boxes to limit to list on objects that were 'active' in inventory. They got around this by pasting in records from a previous piece of work.. which doesn't go trigger the combobox validation. In this instance I decided to use an "INSTEAD OF INSERT" trigger on my SQL Back end... The problem now becomes they get an error message that I raise in the trigger, but then they get a dialog box that says: "Do you want to suppress further error messages telling you why records can't be pasted". The default option is "yes". here. They need to answer "no" to see more messages, but ideally I'd like to completely suppress this box from coming up and have it spew every "paste error" at them. Does anyone have any ideas how I might do that without changing the validation code to the front end? -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From wrwehler at gmail.com Mon Apr 23 09:56:50 2018 From: wrwehler at gmail.com (Ryan W) Date: Mon, 23 Apr 2018 09:56:50 -0500 Subject: [AccessD] Suppress error message dialog In-Reply-To: References: Message-ID: Management is involved. The sort of problems that this would have caused if it wasn't caught would have been monumental next time we go through an audit. I didn't know that the users were doing the ole copy/paste method on these records until it was brought to my attention. I decided to write this logic into a trigger instead of the front end because we have some older (Win XP) machines that run an older version of the front end/Access than most of the other workstations in the office (Most of us are on Office 2013). So rather than manage/maintain two sets of form code I figured I'd write it in to the back end as a trigger. The objects they are pasting are consumables, so when they are marked consumed they are no longer able to be selected via the combo box dropdown... but as I said pasting the record in circumvents that. I'd have to use an AfterInsert action to back the 'bad records' back out. I'll see how this trigger works out. On Mon, Apr 23, 2018 at 9:44 AM, Dan Waters wrote: > Hi Ryan, > > I wouldn't see this is as primarily a technology issue for you to solve. > It sounds like they have a different belief in what their process is than > you are aware of. I'd get together with a few of the experienced users to > find out what's going on? > > It might be that they know that they can use a non-active object on your > form because it will soon be active? Just a guess... If what they are > doing turns out to be OK then perhaps you could add a 'Clone' button next > to the previous records so they don't need to copy/paste. > > If you and your users are working in the same company then you should > raise this issue with your management and theirs. This is not to give them > grief, but just so that everyone knows that this issue is happening. You > can describe the consequences of taking these actions and then they can > decide if they want to continue on this way or if they want to 'obey' your > validation warnings. Put the problem on their back instead of yours. > > If you are working for a client it's about the same thing - but you'll > need to be more formal by writing up a document of what's happening and > what the consequences are. Let your contact person know that you are going > to send this to him or her so they can decide how to proceed. > > For the technical solution it seems like you are presenting a form in > table view which allows them so paste in a record (I've just never done > that). You could change the form to form view with all individual fields > which then have all the correct validation code. More work for them but > then they probably can't get around the validation. > > Good Luck! > Dan > > -----Original Message----- > From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of > Ryan W > Sent: April 23, 2018 09:08 > To: Access Developers discussion and problem solving > Subject: [AccessD] Suppress error message dialog > > I've got some tricky users that were getting around some of my validation > process on a datasheet... I had set the combo boxes to limit to list on > objects that were 'active' in inventory. > > They got around this by pasting in records from a previous piece of work.. > which doesn't go trigger the combobox validation. > > In this instance I decided to use an "INSTEAD OF INSERT" trigger on my SQL > Back end... > > The problem now becomes they get an error message that I raise in the > trigger, but then they get a dialog box that says: > > "Do you want to suppress further error messages telling you why records > can't be pasted". > > The default option is "yes". here. They need to answer "no" to see more > messages, but ideally I'd like to completely suppress this box from coming > up and have it spew every "paste error" at them. > > Does anyone have any ideas how I might do that without changing the > validation code to the front end? > -- > AccessD mailing list > AccessD at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/accessd > Website: http://www.databaseadvisors.com > > -- > AccessD mailing list > AccessD at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/accessd > Website: http://www.databaseadvisors.com > From df.waters at outlook.com Mon Apr 23 11:03:01 2018 From: df.waters at outlook.com (Dan Waters) Date: Mon, 23 Apr 2018 16:03:01 +0000 Subject: [AccessD] Suppress error message dialog In-Reply-To: References: Message-ID: I've never used triggers in SQL tables. Please follow up! Thanks! Dan -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Ryan W Sent: April 23, 2018 09:57 To: Access Developers discussion and problem solving Subject: Re: [AccessD] Suppress error message dialog Management is involved. The sort of problems that this would have caused if it wasn't caught would have been monumental next time we go through an audit. I didn't know that the users were doing the ole copy/paste method on these records until it was brought to my attention. I decided to write this logic into a trigger instead of the front end because we have some older (Win XP) machines that run an older version of the front end/Access than most of the other workstations in the office (Most of us are on Office 2013). So rather than manage/maintain two sets of form code I figured I'd write it in to the back end as a trigger. The objects they are pasting are consumables, so when they are marked consumed they are no longer able to be selected via the combo box dropdown... but as I said pasting the record in circumvents that. I'd have to use an AfterInsert action to back the 'bad records' back out. I'll see how this trigger works out. On Mon, Apr 23, 2018 at 9:44 AM, Dan Waters wrote: > Hi Ryan, > > I wouldn't see this is as primarily a technology issue for you to solve. > It sounds like they have a different belief in what their process is than > you are aware of. I'd get together with a few of the experienced users to > find out what's going on? > > It might be that they know that they can use a non-active object on your > form because it will soon be active? Just a guess... If what they are > doing turns out to be OK then perhaps you could add a 'Clone' button next > to the previous records so they don't need to copy/paste. > > If you and your users are working in the same company then you should > raise this issue with your management and theirs. This is not to give them > grief, but just so that everyone knows that this issue is happening. You > can describe the consequences of taking these actions and then they can > decide if they want to continue on this way or if they want to 'obey' your > validation warnings. Put the problem on their back instead of yours. > > If you are working for a client it's about the same thing - but you'll > need to be more formal by writing up a document of what's happening and > what the consequences are. Let your contact person know that you are going > to send this to him or her so they can decide how to proceed. > > For the technical solution it seems like you are presenting a form in > table view which allows them so paste in a record (I've just never done > that). You could change the form to form view with all individual fields > which then have all the correct validation code. More work for them but > then they probably can't get around the validation. > > Good Luck! > Dan > > -----Original Message----- > From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of > Ryan W > Sent: April 23, 2018 09:08 > To: Access Developers discussion and problem solving > Subject: [AccessD] Suppress error message dialog > > I've got some tricky users that were getting around some of my validation > process on a datasheet... I had set the combo boxes to limit to list on > objects that were 'active' in inventory. > > They got around this by pasting in records from a previous piece of work.. > which doesn't go trigger the combobox validation. > > In this instance I decided to use an "INSTEAD OF INSERT" trigger on my SQL > Back end... > > The problem now becomes they get an error message that I raise in the > trigger, but then they get a dialog box that says: > > "Do you want to suppress further error messages telling you why records > can't be pasted". > > The default option is "yes". here. They need to answer "no" to see more > messages, but ideally I'd like to completely suppress this box from coming > up and have it spew every "paste error" at them. > > Does anyone have any ideas how I might do that without changing the > validation code to the front end? > -- > AccessD mailing list > AccessD at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/accessd > Website: http://www.databaseadvisors.com > > -- > AccessD mailing list > AccessD at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/accessd > Website: http://www.databaseadvisors.com > -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From fuller.artful at gmail.com Mon Apr 23 11:40:31 2018 From: fuller.artful at gmail.com (Arthur Fuller) Date: Mon, 23 Apr 2018 12:40:31 -0400 Subject: [AccessD] Suppress error message dialog In-Reply-To: References: Message-ID: I think Triggers are your best bet, shy of a managerial mandate forbidding cut-and-paste. But as written above, there may exist sound reasons for getting around the "now available" rule, such as "Will be available by the time this order is processed." Just one example. It seems to me that a discussion involving management, users who regularly do this, and yourself. The Users Who Regularly Do This (TURDT :) should be first to explain their behaviour. Management should be second to the plate, having heard TURDT's reasoning. Finally, you step up, having heard their respective perspectives, and either figuring out how to satisfy both camps, or to explain why both cannot be satisfied within the limits of Excel. OTOH, perhaps both camps can be satisfied, insofar as their rules are sufficiently and effectively explained, in detail, and with known exceptions thoroughly described. It's also true that unknown exceptions cannot be described prior to their occurrence; but that ought not stop us from thoroughly describing the known exceptions, and unveiling the reasoning behind their existence. This, I am woefully too aware, is the most difficult aspect of application-development. In this light, I shall relate a tale from my thankfully distant past, involving an insurance company. Various reports were required, about 87% of which reported accurate data while the remaining 13% contained a few inaccurate result-rows. I slaved over my logic and algorithms for about 6 weeks, of meetings with the stakeholders and various persons higher up the food chain, when someone at a meeting, in early December of that year, casually mentioned that the InsCo operated on 360-day years, in essence forgiving the Holiday Season. Meanwhile I had gone so far as to factor in leap years and consequent calculations, and hence, depending upon the life-span of any given pension fund, my calcs and theirs might differ. Nobody thought to mention this accounting fiction until the project was six weeks late, and only then mentioned in passing, as if this humble programmer ought to have known the shenanigans this insurance company was pulling. That contract cost me a bundle -- well not compared to what Trump considers a bundle, but in my local league, six weeks of work wasted results in a bundle. To escape this IMHO lack of specification, the principal stakeholder dismissed me with a simple, "This is standard practice in our line of work. If you'd done your research, you'd have known that. This is on you." Lacking the funds to pay a lawyer, I succumed and took the economic scar as a badge of honour, much like German swordsmen wore their scars. The difference is that scars from a sword imply honour, while scars on your resum? follow you forever, and do not get you laid by a woman who likes scarred women -- which means most women. But now I'm echoing too much reading of Raymond Chandler, Dash Hammett and James McCain, so best I stop, and return to the novel upon I'm currently at work, whose conscious intention is to emulate those great crime writers, and to that esteemed list I would add the late Philip Kerr, whose Bernie Gunther novels are inimitable. Arthur On Mon, Apr 23, 2018 at 12:03 PM, Dan Waters wrote: > I've never used triggers in SQL tables. Please follow up! > > Thanks! > Dan > > -----Original Message----- > From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of > Ryan W > Sent: April 23, 2018 09:57 > To: Access Developers discussion and problem solving > Subject: Re: [AccessD] Suppress error message dialog > > Management is involved. The sort of problems that this would have caused > if it wasn't caught would have been monumental next time we go through an > audit. > > I didn't know that the users were doing the ole copy/paste method on these > records until it was brought to my attention. > > I decided to write this logic into a trigger instead of the front end > because we have some older (Win XP) machines that run an older version of > the front end/Access than most of the other workstations in the office > (Most of us are on Office 2013). So rather than manage/maintain two sets > of form code I figured I'd write it in to the back end as a trigger. > > The objects they are pasting are consumables, so when they are marked > consumed they are no longer able to be selected via the combo box > dropdown... but as I said pasting the record in circumvents that. I'd have > to use an AfterInsert action to back the 'bad records' back out. > > I'll see how this trigger works out. > > > > On Mon, Apr 23, 2018 at 9:44 AM, Dan Waters wrote: > > > Hi Ryan, > > > > I wouldn't see this is as primarily a technology issue for you to solve. > > It sounds like they have a different belief in what their process is than > > you are aware of. I'd get together with a few of the experienced users > to > > find out what's going on? > > > > It might be that they know that they can use a non-active object on your > > form because it will soon be active? Just a guess... If what they are > > doing turns out to be OK then perhaps you could add a 'Clone' button next > > to the previous records so they don't need to copy/paste. > > > > If you and your users are working in the same company then you should > > raise this issue with your management and theirs. This is not to give > them > > grief, but just so that everyone knows that this issue is happening. You > > can describe the consequences of taking these actions and then they can > > decide if they want to continue on this way or if they want to 'obey' > your > > validation warnings. Put the problem on their back instead of yours. > > > > If you are working for a client it's about the same thing - but you'll > > need to be more formal by writing up a document of what's happening and > > what the consequences are. Let your contact person know that you are > going > > to send this to him or her so they can decide how to proceed. > > > > For the technical solution it seems like you are presenting a form in > > table view which allows them so paste in a record (I've just never done > > that). You could change the form to form view with all individual fields > > which then have all the correct validation code. More work for them but > > then they probably can't get around the validation. > > > > Good Luck! > > Dan > > > > -----Original Message----- > > From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of > > Ryan W > > Sent: April 23, 2018 09:08 > > To: Access Developers discussion and problem solving > > Subject: [AccessD] Suppress error message dialog > > > > I've got some tricky users that were getting around some of my validation > > process on a datasheet... I had set the combo boxes to limit to list on > > objects that were 'active' in inventory. > > > > They got around this by pasting in records from a previous piece of > work.. > > which doesn't go trigger the combobox validation. > > > > In this instance I decided to use an "INSTEAD OF INSERT" trigger on my > SQL > > Back end... > > > > The problem now becomes they get an error message that I raise in the > > trigger, but then they get a dialog box that says: > > > > "Do you want to suppress further error messages telling you why records > > can't be pasted". > > > > The default option is "yes". here. They need to answer "no" to see more > > messages, but ideally I'd like to completely suppress this box from > coming > > up and have it spew every "paste error" at them. > > > > Does anyone have any ideas how I might do that without changing the > > validation code to the front end? > > -- > > AccessD mailing list > > AccessD at databaseadvisors.com > > http://databaseadvisors.com/mailman/listinfo/accessd > > Website: http://www.databaseadvisors.com > > > > -- > > AccessD mailing list > > AccessD at databaseadvisors.com > > http://databaseadvisors.com/mailman/listinfo/accessd > > Website: http://www.databaseadvisors.com > > > -- > AccessD mailing list > AccessD at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/accessd > Website: http://www.databaseadvisors.com > > -- > AccessD mailing list > AccessD at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/accessd > Website: http://www.databaseadvisors.com > -- Arthur From wrwehler at gmail.com Mon Apr 23 12:32:27 2018 From: wrwehler at gmail.com (Ryan W) Date: Mon, 23 Apr 2018 12:32:27 -0500 Subject: [AccessD] Suppress error message dialog In-Reply-To: References: Message-ID: Arthur, The TURDTs who are doing this is nearly everyone. It's being done to save time. They aren't "future availability" dependencies though. They're dependencies we sometimes (or maybe all the time?) make in house, mark as "opened" so that they can be used in the work and then marked Consumed when they're done (they may last a day, or several days). The copy and paste is laziness to avoid having to hand enter each of the codes into the datasheet along with some other items that get stored (units used, etc). Leave it to the users to find ways to use what you've programmed in unintended ways, that's for sure. On Mon, Apr 23, 2018 at 11:40 AM, Arthur Fuller wrote: > I think Triggers are your best bet, shy of a managerial mandate forbidding > cut-and-paste. But as written above, there may exist sound reasons for > getting around the "now available" rule, such as "Will be available by the > time this order is processed." Just one example. > > It seems to me that a discussion involving management, users who regularly > do this, and yourself. The Users Who Regularly Do This (TURDT :) should be > first to explain their behaviour. Management should be second to the plate, > having heard TURDT's reasoning. Finally, you step up, having heard their > respective perspectives, and either figuring out how to satisfy both camps, > or to explain why both cannot be satisfied within the limits of Excel. > OTOH, perhaps both camps can be satisfied, insofar as their rules are > sufficiently and effectively explained, in detail, and with known > exceptions thoroughly described. > > It's also true that unknown exceptions cannot be described prior to their > occurrence; but that ought not stop us from thoroughly describing the known > exceptions, and unveiling the reasoning behind their existence. > > This, I am woefully too aware, is the most difficult aspect of > application-development. In this light, I shall relate a tale from my > thankfully distant past, involving an insurance company. Various reports > were required, about 87% of which reported accurate data while the > remaining 13% contained a few inaccurate result-rows. I slaved over my > logic and algorithms for about 6 weeks, of meetings with the stakeholders > and various persons higher up the food chain, when someone at a meeting, in > early December of that year, casually mentioned that the InsCo operated on > 360-day years, in essence forgiving the Holiday Season. Meanwhile I had > gone so far as to factor in leap years and consequent calculations, and > hence, depending upon the life-span of any given pension fund, my calcs and > theirs might differ. Nobody thought to mention this accounting fiction > until the project was six weeks late, and only then mentioned in passing, > as if this humble programmer ought to have known the shenanigans this > insurance company was pulling. That contract cost me a bundle -- well not > compared to what Trump considers a bundle, but in my local league, six > weeks of work wasted results in a bundle. To escape this IMHO lack of > specification, the principal stakeholder dismissed me with a simple, "This > is standard practice in our line of work. If you'd done your research, > you'd have known that. This is on you." > > Lacking the funds to pay a lawyer, I succumed and took the economic scar as > a badge of honour, much like German swordsmen wore their scars. The > difference is that scars from a sword imply honour, while scars on your > resum? follow you forever, and do not get you laid by a woman who likes > scarred women -- which means most women. But now I'm echoing too much > reading of Raymond Chandler, Dash Hammett and James McCain, so best I stop, > and return to the novel upon I'm currently at work, whose conscious > intention is to emulate those great crime writers, and to that esteemed > list I would add the late Philip Kerr, whose Bernie Gunther novels are > inimitable. > > Arthur > From jackandpat.d at gmail.com Mon Apr 23 14:06:25 2018 From: jackandpat.d at gmail.com (jack drawbridge) Date: Mon, 23 Apr 2018 15:06:25 -0400 Subject: [AccessD] Suppress error message dialog In-Reply-To: References: Message-ID: Ryan, Along the line of thought Arthur posed, and I don't mean to be contrary, I have learned that sometimes requirements are not necessarily what has been documented and designed/developed against. Users, and familiarity with the business and sometimes changing business processes, get reflected in how systems are being used/abused. What may seem to be an abuse of the approved design, may also be considered a change in process or a possible optimization of an established process. I have seen lots of reporting applications where the reports were spooled, printed and delivered--until one day someone questioned the process. All we need are the exceptions. Or, we put this pile of reports here and no one has collected them for a month??? Just saying --the requirement and the implementation -- may not be a static as the original requirement and plan. Just saying --it may be appropriate to analyze what's really happening. Good luck. Virus-free. www.avast.com <#DAB4FAD8-2DD7-40BB-A1B8-4E2AA1F9FDF2> On Mon, Apr 23, 2018 at 1:32 PM, Ryan W wrote: > Arthur, > The TURDTs who are doing this is nearly everyone. It's being done to save > time. They aren't "future availability" dependencies though. They're > dependencies we sometimes (or maybe all the time?) make in house, mark as > "opened" so that they can be used in the work and then marked Consumed when > they're done (they may last a day, or several days). The copy and paste is > laziness to avoid having to hand enter each of the codes into the datasheet > along with some other items that get stored (units used, etc). > > Leave it to the users to find ways to use what you've programmed in > unintended ways, that's for sure. > > > On Mon, Apr 23, 2018 at 11:40 AM, Arthur Fuller > wrote: > > > I think Triggers are your best bet, shy of a managerial mandate > forbidding > > cut-and-paste. But as written above, there may exist sound reasons for > > getting around the "now available" rule, such as "Will be available by > the > > time this order is processed." Just one example. > > > > It seems to me that a discussion involving management, users who > regularly > > do this, and yourself. The Users Who Regularly Do This (TURDT :) should > be > > first to explain their behaviour. Management should be second to the > plate, > > having heard TURDT's reasoning. Finally, you step up, having heard their > > respective perspectives, and either figuring out how to satisfy both > camps, > > or to explain why both cannot be satisfied within the limits of Excel. > > OTOH, perhaps both camps can be satisfied, insofar as their rules are > > sufficiently and effectively explained, in detail, and with known > > exceptions thoroughly described. > > > > It's also true that unknown exceptions cannot be described prior to their > > occurrence; but that ought not stop us from thoroughly describing the > known > > exceptions, and unveiling the reasoning behind their existence. > > > > This, I am woefully too aware, is the most difficult aspect of > > application-development. In this light, I shall relate a tale from my > > thankfully distant past, involving an insurance company. Various reports > > were required, about 87% of which reported accurate data while the > > remaining 13% contained a few inaccurate result-rows. I slaved over my > > logic and algorithms for about 6 weeks, of meetings with the stakeholders > > and various persons higher up the food chain, when someone at a meeting, > in > > early December of that year, casually mentioned that the InsCo operated > on > > 360-day years, in essence forgiving the Holiday Season. Meanwhile I had > > gone so far as to factor in leap years and consequent calculations, and > > hence, depending upon the life-span of any given pension fund, my calcs > and > > theirs might differ. Nobody thought to mention this accounting fiction > > until the project was six weeks late, and only then mentioned in passing, > > as if this humble programmer ought to have known the shenanigans this > > insurance company was pulling. That contract cost me a bundle -- well not > > compared to what Trump considers a bundle, but in my local league, six > > weeks of work wasted results in a bundle. To escape this IMHO lack of > > specification, the principal stakeholder dismissed me with a simple, > "This > > is standard practice in our line of work. If you'd done your research, > > you'd have known that. This is on you." > > > > Lacking the funds to pay a lawyer, I succumed and took the economic scar > as > > a badge of honour, much like German swordsmen wore their scars. The > > difference is that scars from a sword imply honour, while scars on your > > resum? follow you forever, and do not get you laid by a woman who likes > > scarred women -- which means most women. But now I'm echoing too much > > reading of Raymond Chandler, Dash Hammett and James McCain, so best I > stop, > > and return to the novel upon I'm currently at work, whose conscious > > intention is to emulate those great crime writers, and to that esteemed > > list I would add the late Philip Kerr, whose Bernie Gunther novels are > > inimitable. > > > > Arthur > > > -- > AccessD mailing list > AccessD at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/accessd > Website: http://www.databaseadvisors.com > From newsgrps at dalyn.co.nz Mon Apr 23 22:23:07 2018 From: newsgrps at dalyn.co.nz (David Emerson) Date: Tue, 24 Apr 2018 15:23:07 +1200 Subject: [AccessD] Connection Strings for SQL2012R2 In-Reply-To: <00ba01d3daba$127b2970$37717c50$@dalyn.co.nz> References: <00ba01d3daba$127b2970$37717c50$@dalyn.co.nz> Message-ID: <001801d3db7b$909ee870$b1dcb950$@dalyn.co.nz> Tracked the problem - it was permissions on the folder and database that caused the read only error. -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of David Emerson Sent: Monday, 23 April 2018 4:18 p.m. To: 'Access Developers discussion and problem solving' Subject: [AccessD] Connection Strings for SQL2012R2 Hi Listers, I have an Access accdb which connects to an SQL database. Currently I connect to an sql database in SQL2008 which runs fine. The connection strings are: Set gADODBConnection = New ADODB.Connection gADODBConnection.ConnectionString = "Provider=sqloledb;Data Source=SWLGWCLUT12;Initial Catalog=StockData5;Integrated Security=SSPI;" Dim strTempQueryName As String, qdefTemp As DAO.QueryDef strTempQueryName = "qryTempQuery1" Set qdefTemp = CurrentDb.CreateQueryDef(strTempQueryName) qdefTemp.ReturnsRecords = True qdefTemp.ODBCTimeout = 300 qdefTemp.Connect = "ODBC;DRIVER=SQL Server;SERVER=SWLGWCLUT12;DATABASE=StockData5;Trusted_Connection=Yes" I am trying to set up the database on an RDS server (being 2012 R2) but according to the IT people the problem is that we cannot install the x86 SQL driver that access needs as this seems to be unsupported. We have tried bypassing this initial issue by creating a DSN using the "ODBC Driver 11 for SQL Server" and using this code for the global connection: gADODBConnection.ConnectionString = "DSN=StocksData5;Trusted_Connection=yes;" This seems to work but when we try to attach tables we get an error message: Error 3027: Cannot Update. Database or object is read-only. Public Function AttachDSNLessTable(stLocalTableName As String, stRemoteTableName As String, stServer As String, stDatabase As String, Optional stUsername As String, Optional stPassword As String, Optional stKeyfield As String) '//Name : AttachDSNLessTable '//Purpose : Create a linked table to SQL Server without using a DSN '//Parameters '// stLocalTableName: Name of the table that you are creating in the current database '// stRemoteTableName: Name of the table that you are linking to on the SQL Server database '// stServer: Name of the SQL Server that you are linking to '// stDatabase: Name of the SQL Server database that you are linking to '// stUsername: Name of the SQL Server user who can connect to SQL Server, leave blank to use a Trusted Connection '// stPassword: SQL Server user password '// stKeyfield: Name of field if stRemoteTableName is a view. This is used to set up an index so data can be edited On Error GoTo Err_AttachDSNLessTable Dim td As TableDef Dim stConnect As String For Each td In CurrentDb.TableDefs If td.Name = stLocalTableName Then CurrentDb.TableDefs.Delete stLocalTableName End If Next If Len(stUsername) = 0 Then '//Use trusted authentication if stUsername is not supplied. stConnect = "ODBC;DRIVER=SQL Server;SERVER=" & stServer & ";DATABASE=" & stDatabase & ";Trusted_Connection=Yes" Else '//WARNING: This will save the username and the password with the linked table information. stConnect = "ODBC;DRIVER=SQL Server;SERVER=" & stServer & ";DATABASE=" & stDatabase & ";UID=" & stUsername & ";PWD=" & stPassword End If Set td = CurrentDb.CreateTableDef(stLocalTableName, dbAttachSavePWD, stRemoteTableName, stConnect) CurrentDb.TableDefs.Append td If Len(stKeyfield) > 0 Then CurrentDb.Execute "CREATE UNIQUE INDEX 'PrimaryKey' ON " & stLocalTableName & " (" & stKeyfield & ") WITH PRIMARY" End If Does anyone know what connection string I can use? Regards David Emerson Dalyn Software Ltd Wellington, New Zealand -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From accesspro at gmail.com Fri Apr 27 10:20:30 2018 From: accesspro at gmail.com (Bob Heygood) Date: Fri, 27 Apr 2018 08:20:30 -0700 Subject: [AccessD] Payroll Message-ID: <0a3101d3de3b$47d9a900$d78cfb00$@gmail.com> Hello to the list, I am beginning design of a db to track payroll. The clients biz is such that even though I suggested a "canned" solution, they need a custom. But in order not to recreate the wheel I am looking for a template or a table relationship to jump start me. They use a two week pay period. Ideally they would choose an employee (already have a table), then a pay period (already have a table listing dates for two years) and then enter hours in 14 text boxes or maybe a list box ??? Tia Bob From jimdettman at verizon.net Fri Apr 27 11:41:06 2018 From: jimdettman at verizon.net (Jim Dettman) Date: Fri, 27 Apr 2018 12:41:06 -0400 Subject: [AccessD] Payroll In-Reply-To: <0a3101d3de3b$47d9a900$d78cfb00$@gmail.com> References: <0a3101d3de3b$47d9a900$d78cfb00$@gmail.com> Message-ID: <000301d3de46$8a471e70$9ed55b50$@verizon.net> Bob, They should really re-think about buying a canned package. Not sure the size or why they need for custom, but payroll systems in today's time can get fairly complex, and you need to keep up with all the laws. If you're talking about time card entry, and not the backend processing of the actual paycheck, that's something else. I could see that then. Jim. -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Bob Heygood Sent: Friday, April 27, 2018 11:20 AM To: 'Access Developers discussion and problem solving' Subject: [AccessD] Payroll Hello to the list, I am beginning design of a db to track payroll. The clients biz is such that even though I suggested a "canned" solution, they need a custom. But in order not to recreate the wheel I am looking for a template or a table relationship to jump start me. They use a two week pay period. Ideally they would choose an employee (already have a table), then a pay period (already have a table listing dates for two years) and then enter hours in 14 text boxes or maybe a list box ??? Tia Bob -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From jamesbutton at blueyonder.co.uk Fri Apr 27 12:35:56 2018 From: jamesbutton at blueyonder.co.uk (James Button) Date: Fri, 27 Apr 2018 18:35:56 +0100 Subject: [AccessD] Payroll In-Reply-To: <0a3101d3de3b$47d9a900$d78cfb00$@gmail.com> References: <0a3101d3de3b$47d9a900$d78cfb00$@gmail.com> Message-ID: Deadly assumption(s) Workers will only work 1 shift in a calendar day Workers shift will be entirely within a calendar day Pay will be at the standard rate(s) for all hours in a shift Bonuses will be subject to tax Benefits in kind - car, fuel, or taxi's, meals , healthcare - various categories and provision processes Benefits in kind - non taxable such as hydration drinks, uniforms and safety equipment Newly introduced local, or state taxes I would consider the input of hours being a daily thing with all employees (and contractors?, and agents?, and professional persons?) hours being entered by rote working down the employee list - That list being ordered by category, location and maybe grading so 1 person deals with input for management at a site and 1 person (maybe the same one) deals with the general pay-scale workers. Allow for - paid or not, hours holiday Sick leave, compassionate/extraordinary Education/courses Legally required Contractual Pay in lieu of hours Hours owed/carried forward Meetings required to attend - performance, disciplinary, associated with the employment All should be considered as entries for that person's 'employment' in a period - day The input should be appropriate for easy verification that there is no fraudulent input and submission to courts if required /ordered There maybe a legal decision that pay is (or is not) required for the time spent in such activities. Then - for the actual payment - as in assembly of time for which payment is due, That becomes the weekly, or other timing process Not forgetting the possibility of changes to the qualification and 'cash' related to any and all the above at any time in the payment period. Your payroll period is unlikely to match the legislative periods. Also maybe worth having an 'acceptable' max for each person (or job classification) for the payment period and for the quarter, and annually There should also be a very well managed process for implementing changes on specific dates (and times) with the effects being applied from specific dates & times - Local or other Consider employees abroad on behalf of the organisation Payroll is a real pain in the head (and elsewhere) and that is without getting retrospective adjustments from insurers, government departments, and the courts As well as evaluations by inspectors who cannot do basic arithmetic, speak the language properly. Or even punctuate letters so their orders and requirements are clear. So - no template - but asuggestion that you keep at least 7 separate structures - the business, the employee their contractual usability, qualifications and benefits, the activities they do, the payments due, the payments made, the payroll & benefits declarations to the government, and the associated business costings. OK - they will all link into 1 actual composite, but keeping them separate makes their management - with modifications, general data input and reporting easier to manage as an IT facility. JimB -----Original Message----- From: AccessD On Behalf Of Bob Heygood Sent: Friday, April 27, 2018 4:21 PM To: 'Access Developers discussion and problem solving' Subject: [AccessD] Payroll Hello to the list, I am beginning design of a db to track payroll. The clients biz is such that even though I suggested a "canned" solution, they need a custom. But in order not to recreate the wheel I am looking for a template or a table relationship to jump start me. They use a two week pay period. Ideally they would choose an employee (already have a table), then a pay period (already have a table listing dates for two years) and then enter hours in 14 text boxes or maybe a list box ??? Tia Bob From accesspro at gmail.com Sun Apr 29 16:25:04 2018 From: accesspro at gmail.com (Bob Heygood) Date: Sun, 29 Apr 2018 14:25:04 -0700 Subject: [AccessD] Payroll In-Reply-To: References: <0a3101d3de3b$47d9a900$d78cfb00$@gmail.com> Message-ID: <005b01d3e000$8a8b4080$9fa1c180$@gmail.com> Thanks for the responses. I should have been a bit more clear. I am only tracking the hours worked per day per payperiod. I will easily via a button dump into Excel for submission to the payroll processer. Like ADT. Bout settled on : tblEmployees tblJobs tblTimeCard containing.. EmpID, JobID, Payperiod, Monday1Hours, Tuesday1Hours.......... Monday1Hours15, Tuesday1Hours15,........ Monday1Hours2, Tuesday 1Hours2, ......... then for the second week: Monday2Hours, Tuesday2Hours...... Monday2Hours15, Tuesday2Hours15...... Monday2Hours2, Tuesday2Hours2 this allows for time, time and a half and double time. Also, makes for easy and familiar entry. tblEmployees contains pay rate info, so a little multiplication will give me totals for the resulting sheet/query. Tia Bob -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of James Button via AccessD Sent: Friday, April 27, 2018 10:36 AM To: 'Access Developers discussion and problem solving' Cc: James Button Subject: Re: [AccessD] Payroll Deadly assumption(s) Workers will only work 1 shift in a calendar day Workers shift will be entirely within a calendar day Pay will be at the standard rate(s) for all hours in a shift Bonuses will be subject to tax Benefits in kind - car, fuel, or taxi's, meals , healthcare - various categories and provision processes Benefits in kind - non taxable such as hydration drinks, uniforms and safety equipment Newly introduced local, or state taxes I would consider the input of hours being a daily thing with all employees (and contractors?, and agents?, and professional persons?) hours being entered by rote working down the employee list - That list being ordered by category, location and maybe grading so 1 person deals with input for management at a site and 1 person (maybe the same one) deals with the general pay-scale workers. Allow for - paid or not, hours holiday Sick leave, compassionate/extraordinary Education/courses Legally required Contractual Pay in lieu of hours Hours owed/carried forward Meetings required to attend - performance, disciplinary, associated with the employment All should be considered as entries for that person's 'employment' in a period - day The input should be appropriate for easy verification that there is no fraudulent input and submission to courts if required /ordered There maybe a legal decision that pay is (or is not) required for the time spent in such activities. Then - for the actual payment - as in assembly of time for which payment is due, That becomes the weekly, or other timing process Not forgetting the possibility of changes to the qualification and 'cash' related to any and all the above at any time in the payment period. Your payroll period is unlikely to match the legislative periods. Also maybe worth having an 'acceptable' max for each person (or job classification) for the payment period and for the quarter, and annually There should also be a very well managed process for implementing changes on specific dates (and times) with the effects being applied from specific dates & times - Local or other Consider employees abroad on behalf of the organisation Payroll is a real pain in the head (and elsewhere) and that is without getting retrospective adjustments from insurers, government departments, and the courts As well as evaluations by inspectors who cannot do basic arithmetic, speak the language properly. Or even punctuate letters so their orders and requirements are clear. So - no template - but asuggestion that you keep at least 7 separate structures - the business, the employee their contractual usability, qualifications and benefits, the activities they do, the payments due, the payments made, the payroll & benefits declarations to the government, and the associated business costings. OK - they will all link into 1 actual composite, but keeping them separate makes their management - with modifications, general data input and reporting easier to manage as an IT facility. JimB -----Original Message----- From: AccessD On Behalf Of Bob Heygood Sent: Friday, April 27, 2018 4:21 PM To: 'Access Developers discussion and problem solving' Subject: [AccessD] Payroll Hello to the list, I am beginning design of a db to track payroll. The clients biz is such that even though I suggested a "canned" solution, they need a custom. But in order not to recreate the wheel I am looking for a template or a table relationship to jump start me. They use a two week pay period. Ideally they would choose an employee (already have a table), then a pay period (already have a table listing dates for two years) and then enter hours in 14 text boxes or maybe a list box ??? Tia Bob -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From rockysmolin at bchacc.com Sun Apr 29 18:35:53 2018 From: rockysmolin at bchacc.com (Rocky Smolin) Date: Sun, 29 Apr 2018 16:35:53 -0700 Subject: [AccessD] Payroll In-Reply-To: <005b01d3e000$8a8b4080$9fa1c180$@gmail.com> References: <0a3101d3de3b$47d9a900$d78cfb00$@gmail.com> <005b01d3e000$8a8b4080$9fa1c180$@gmail.com> Message-ID: <000e01d3e012$d09d01a0$71d704e0$@bchacc.com> Bob: I think your timecard capture table should have one record for each day with FK of Empl ID: fldTimeCardID Autonumber fldEmplID Number (FK) fldDateWorked Date fldHours Number(Double) fldMultiplier Number (for straight time(1), time and 1/2(1.5), double time(2) Obviously an Employee table. And then a work period Start Date, End Date But for rate of pay since the rate changes you should have a RateofPay table: fldRateOfPayID Autonumber EmplID Number (FK) fldRateStarDate Date fldRateEndDate Date fldBaseRate Number (Double) It's a little more complicated that way but that way you could reconstruct their pay for any period in the past. But if all you want is hours without anything else then you don't need the pay rate data. But then why not just dump the timecards into a spreadsheet? What is Access doing for you? If you want to discuss, call me. Or come over and in short order we could design the back end to just what you want. R 760-683-5777 -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Bob Heygood Sent: Sunday, April 29, 2018 2:25 PM To: 'Access Developers discussion and problem solving' Subject: Re: [AccessD] Payroll Thanks for the responses. I should have been a bit more clear. I am only tracking the hours worked per day per payperiod. I will easily via a button dump into Excel for submission to the payroll processer. Like ADT. Bout settled on : tblEmployees tblJobs tblTimeCard containing.. EmpID, JobID, Payperiod, Monday1Hours, Tuesday1Hours.......... Monday1Hours15, Tuesday1Hours15,........ Monday1Hours2, Tuesday 1Hours2, ......... then for the second week: Monday2Hours, Tuesday2Hours...... Monday2Hours15, Tuesday2Hours15...... Monday2Hours2, Tuesday2Hours2 this allows for time, time and a half and double time. Also, makes for easy and familiar entry. tblEmployees contains pay rate info, so a little multiplication will give me totals for the resulting sheet/query. Tia Bob -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of James Button via AccessD Sent: Friday, April 27, 2018 10:36 AM To: 'Access Developers discussion and problem solving' Cc: James Button Subject: Re: [AccessD] Payroll Deadly assumption(s) Workers will only work 1 shift in a calendar day Workers shift will be entirely within a calendar day Pay will be at the standard rate(s) for all hours in a shift Bonuses will be subject to tax Benefits in kind - car, fuel, or taxi's, meals , healthcare - various categories and provision processes Benefits in kind - non taxable such as hydration drinks, uniforms and safety equipment Newly introduced local, or state taxes I would consider the input of hours being a daily thing with all employees (and contractors?, and agents?, and professional persons?) hours being entered by rote working down the employee list - That list being ordered by category, location and maybe grading so 1 person deals with input for management at a site and 1 person (maybe the same one) deals with the general pay-scale workers. Allow for - paid or not, hours holiday Sick leave, compassionate/extraordinary Education/courses Legally required Contractual Pay in lieu of hours Hours owed/carried forward Meetings required to attend - performance, disciplinary, associated with the employment All should be considered as entries for that person's 'employment' in a period - day The input should be appropriate for easy verification that there is no fraudulent input and submission to courts if required /ordered There maybe a legal decision that pay is (or is not) required for the time spent in such activities. Then - for the actual payment - as in assembly of time for which payment is due, That becomes the weekly, or other timing process Not forgetting the possibility of changes to the qualification and 'cash' related to any and all the above at any time in the payment period. Your payroll period is unlikely to match the legislative periods. Also maybe worth having an 'acceptable' max for each person (or job classification) for the payment period and for the quarter, and annually There should also be a very well managed process for implementing changes on specific dates (and times) with the effects being applied from specific dates & times - Local or other Consider employees abroad on behalf of the organisation Payroll is a real pain in the head (and elsewhere) and that is without getting retrospective adjustments from insurers, government departments, and the courts As well as evaluations by inspectors who cannot do basic arithmetic, speak the language properly. Or even punctuate letters so their orders and requirements are clear. So - no template - but asuggestion that you keep at least 7 separate structures - the business, the employee their contractual usability, qualifications and benefits, the activities they do, the payments due, the payments made, the payroll & benefits declarations to the government, and the associated business costings. OK - they will all link into 1 actual composite, but keeping them separate makes their management - with modifications, general data input and reporting easier to manage as an IT facility. JimB -----Original Message----- From: AccessD On Behalf Of Bob Heygood Sent: Friday, April 27, 2018 4:21 PM To: 'Access Developers discussion and problem solving' Subject: [AccessD] Payroll Hello to the list, I am beginning design of a db to track payroll. The clients biz is such that even though I suggested a "canned" solution, they need a custom. But in order not to recreate the wheel I am looking for a template or a table relationship to jump start me. They use a two week pay period. Ideally they would choose an employee (already have a table), then a pay period (already have a table listing dates for two years) and then enter hours in 14 text boxes or maybe a list box ??? Tia Bob -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From jimdettman at verizon.net Mon Apr 30 06:26:31 2018 From: jimdettman at verizon.net (Jim Dettman) Date: Mon, 30 Apr 2018 07:26:31 -0400 Subject: [AccessD] Payroll In-Reply-To: <005b01d3e000$8a8b4080$9fa1c180$@gmail.com> References: <0a3101d3de3b$47d9a900$d78cfb00$@gmail.com> <005b01d3e000$8a8b4080$9fa1c180$@gmail.com> Message-ID: <002f01d3e076$17b9c650$472d52f0$@verizon.net> Bob, << tblTimeCard containing.. EmpID, JobID, Payperiod, Monday1Hours, Tuesday1Hours.......... Monday1Hours15, Tuesday1Hours15,........>> You really don't want this. You've broken a normalization rule and it really leaves you with an inflexible design if changes are wanted in the future. Keep in mind that the table design does not imply the UI. You can use whatever setup you want for the entry of the time cards and then generate the records as needed. Something along these lines would be better: tblTimeCards - One record per pay period. TimeCardID - AN - PK EmpID - Long - FK tblEmployees JobID - Long WorkDate - D/T TimeIn - Decimal(4) TimeOut - Decimal(4) ElapsedTime - Decimal(4) BasePay - Currency RegHrs - Decimal(4) OTHTHrs - Decimal(4) OTDTHrs - Decimal(4) RegPay - Currency OTHTHrs - Currency OTDTHrs - Currency PayCode - Text(4) PayCodeComment - Text(32) EnteredBy EnteredOn PostedPR - Date/Time Where you have one entry for each clock on/off. Many systems try to do one record per time clock "punch", but it becomes a very complex task to marry up a start time with an end time. With this setup you can tell easily if someone missed a clock in or out, and it's much easier to process. In regards to the work date and then a start/stop, some will do it as a date/time in and date/time out. I've found it easier to handle the times separately and store them as text as this allows systems where you want 10ths of an hour in one, and actual minutes in another. Ie. 1030 can be 10th hour 30 minutes, or 10th hour and .3 hours (18 minute). This is also why ET (Elapsed Time) is stored in the record above rather than simply end - start. If you need on-job time spans > 24 hours, you would need to add a EndWorkDate. You also mentioned a job ID; is this an incentivized system? If so, you'll need quite a few more fields (SKU, Machine, Operation, NoPeople, Qty, Base Rate, STDAllowed, STDUsed, EarnedHrs, Normalization Factor, Normalized Earned Hours, Percent of STD, etc.) and also take into account shift differentials. The other thing you'll notice here is some fields are stored (i.e. RegPay). While that flies in the face of what you'd normally do, there are a few reasons for that: 1. Once calculated, it's easy to sum up those fields to feed to a payroll system. 2. Doing so allows an employee's base pay to change at any time. 3. The rules for deciding what is Reg vs OT can change at any time. 4. You can always look back and derive how an employees pay was calculated. PayCode is so you can tag entries for things like vacation time, sick pay, training, family leave, etc. I can fill in more details if needed. HTH, Jim. -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Bob Heygood Sent: Sunday, April 29, 2018 5:25 PM To: 'Access Developers discussion and problem solving' Subject: Re: [AccessD] Payroll Thanks for the responses. I should have been a bit more clear. I am only tracking the hours worked per day per payperiod. I will easily via a button dump into Excel for submission to the payroll processer. Like ADT. Bout settled on : tblEmployees tblJobs tblTimeCard containing.. EmpID, JobID, Payperiod, Monday1Hours, Tuesday1Hours.......... Monday1Hours15, Tuesday1Hours15,........ Monday1Hours2, Tuesday 1Hours2, ......... then for the second week: Monday2Hours, Tuesday2Hours...... Monday2Hours15, Tuesday2Hours15...... Monday2Hours2, Tuesday2Hours2 this allows for time, time and a half and double time. Also, makes for easy and familiar entry. tblEmployees contains pay rate info, so a little multiplication will give me totals for the resulting sheet/query. Tia Bob -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of James Button via AccessD Sent: Friday, April 27, 2018 10:36 AM To: 'Access Developers discussion and problem solving' Cc: James Button Subject: Re: [AccessD] Payroll Deadly assumption(s) Workers will only work 1 shift in a calendar day Workers shift will be entirely within a calendar day Pay will be at the standard rate(s) for all hours in a shift Bonuses will be subject to tax Benefits in kind - car, fuel, or taxi's, meals , healthcare - various categories and provision processes Benefits in kind - non taxable such as hydration drinks, uniforms and safety equipment Newly introduced local, or state taxes I would consider the input of hours being a daily thing with all employees (and contractors?, and agents?, and professional persons?) hours being entered by rote working down the employee list - That list being ordered by category, location and maybe grading so 1 person deals with input for management at a site and 1 person (maybe the same one) deals with the general pay-scale workers. Allow for - paid or not, hours holiday Sick leave, compassionate/extraordinary Education/courses Legally required Contractual Pay in lieu of hours Hours owed/carried forward Meetings required to attend - performance, disciplinary, associated with the employment All should be considered as entries for that person's 'employment' in a period - day The input should be appropriate for easy verification that there is no fraudulent input and submission to courts if required /ordered There maybe a legal decision that pay is (or is not) required for the time spent in such activities. Then - for the actual payment - as in assembly of time for which payment is due, That becomes the weekly, or other timing process Not forgetting the possibility of changes to the qualification and 'cash' related to any and all the above at any time in the payment period. Your payroll period is unlikely to match the legislative periods. Also maybe worth having an 'acceptable' max for each person (or job classification) for the payment period and for the quarter, and annually There should also be a very well managed process for implementing changes on specific dates (and times) with the effects being applied from specific dates & times - Local or other Consider employees abroad on behalf of the organisation Payroll is a real pain in the head (and elsewhere) and that is without getting retrospective adjustments from insurers, government departments, and the courts As well as evaluations by inspectors who cannot do basic arithmetic, speak the language properly. Or even punctuate letters so their orders and requirements are clear. So - no template - but asuggestion that you keep at least 7 separate structures - the business, the employee their contractual usability, qualifications and benefits, the activities they do, the payments due, the payments made, the payroll & benefits declarations to the government, and the associated business costings. OK - they will all link into 1 actual composite, but keeping them separate makes their management - with modifications, general data input and reporting easier to manage as an IT facility. JimB -----Original Message----- From: AccessD On Behalf Of Bob Heygood Sent: Friday, April 27, 2018 4:21 PM To: 'Access Developers discussion and problem solving' Subject: [AccessD] Payroll Hello to the list, I am beginning design of a db to track payroll. The clients biz is such that even though I suggested a "canned" solution, they need a custom. But in order not to recreate the wheel I am looking for a template or a table relationship to jump start me. They use a two week pay period. Ideally they would choose an employee (already have a table), then a pay period (already have a table listing dates for two years) and then enter hours in 14 text boxes or maybe a list box ??? Tia Bob -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From accesspro at gmail.com Mon Apr 30 13:30:50 2018 From: accesspro at gmail.com (Bob Heygood) Date: Mon, 30 Apr 2018 11:30:50 -0700 Subject: [AccessD] Payroll In-Reply-To: References: <0a3101d3de3b$47d9a900$d78cfb00$@gmail.com> <005b01d3e000$8a8b4080$9fa1c180$@gmail.com> Message-ID: <00fb01d3e0b1$5e365a90$1aa30fb0$@gmail.com> Rocky & Jim, Yes I knew intuitively that I was breaking some normalization rules. Just started to let the UI interface drive the schema. For data entry the user insists on being able to "tab" through a whole pay period (2 weeks) for each employee and job. So, how do I use a table with only one record per day? UNBOUND, I guess. And then via code stuff into a "proper" table........ I have done so before but a lot work. Really don't need any other fields. Thanks for responding, Bob -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Rocky Smolin Sent: Sunday, April 29, 2018 4:36 PM To: 'Access Developers discussion and problem solving' Subject: Re: [AccessD] Payroll Bob: I think your timecard capture table should have one record for each day with FK of Empl ID: fldTimeCardID Autonumber fldEmplID Number (FK) fldDateWorked Date fldHours Number(Double) fldMultiplier Number (for straight time(1), time and 1/2(1.5), double time(2) Obviously an Employee table. And then a work period Start Date, End Date But for rate of pay since the rate changes you should have a RateofPay table: fldRateOfPayID Autonumber EmplID Number (FK) fldRateStarDate Date fldRateEndDate Date fldBaseRate Number (Double) It's a little more complicated that way but that way you could reconstruct their pay for any period in the past. But if all you want is hours without anything else then you don't need the pay rate data. But then why not just dump the timecards into a spreadsheet? What is Access doing for you? If you want to discuss, call me. Or come over and in short order we could design the back end to just what you want. R 760-683-5777 -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Bob Heygood Sent: Sunday, April 29, 2018 2:25 PM To: 'Access Developers discussion and problem solving' Subject: Re: [AccessD] Payroll Thanks for the responses. I should have been a bit more clear. I am only tracking the hours worked per day per payperiod. I will easily via a button dump into Excel for submission to the payroll processer. Like ADT. Bout settled on : tblEmployees tblJobs tblTimeCard containing.. EmpID, JobID, Payperiod, Monday1Hours, Tuesday1Hours.......... Monday1Hours15, Tuesday1Hours15,........ Monday1Hours2, Tuesday 1Hours2, ......... then for the second week: Monday2Hours, Tuesday2Hours...... Monday2Hours15, Tuesday2Hours15...... Monday2Hours2, Tuesday2Hours2 this allows for time, time and a half and double time. Also, makes for easy and familiar entry. tblEmployees contains pay rate info, so a little multiplication will give me totals for the resulting sheet/query. Tia Bob -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of James Button via AccessD Sent: Friday, April 27, 2018 10:36 AM To: 'Access Developers discussion and problem solving' Cc: James Button Subject: Re: [AccessD] Payroll Deadly assumption(s) Workers will only work 1 shift in a calendar day Workers shift will be entirely within a calendar day Pay will be at the standard rate(s) for all hours in a shift Bonuses will be subject to tax Benefits in kind - car, fuel, or taxi's, meals , healthcare - various categories and provision processes Benefits in kind - non taxable such as hydration drinks, uniforms and safety equipment Newly introduced local, or state taxes I would consider the input of hours being a daily thing with all employees (and contractors?, and agents?, and professional persons?) hours being entered by rote working down the employee list - That list being ordered by category, location and maybe grading so 1 person deals with input for management at a site and 1 person (maybe the same one) deals with the general pay-scale workers. Allow for - paid or not, hours holiday Sick leave, compassionate/extraordinary Education/courses Legally required Contractual Pay in lieu of hours Hours owed/carried forward Meetings required to attend - performance, disciplinary, associated with the employment All should be considered as entries for that person's 'employment' in a period - day The input should be appropriate for easy verification that there is no fraudulent input and submission to courts if required /ordered There maybe a legal decision that pay is (or is not) required for the time spent in such activities. Then - for the actual payment - as in assembly of time for which payment is due, That becomes the weekly, or other timing process Not forgetting the possibility of changes to the qualification and 'cash' related to any and all the above at any time in the payment period. Your payroll period is unlikely to match the legislative periods. Also maybe worth having an 'acceptable' max for each person (or job classification) for the payment period and for the quarter, and annually There should also be a very well managed process for implementing changes on specific dates (and times) with the effects being applied from specific dates & times - Local or other Consider employees abroad on behalf of the organisation Payroll is a real pain in the head (and elsewhere) and that is without getting retrospective adjustments from insurers, government departments, and the courts As well as evaluations by inspectors who cannot do basic arithmetic, speak the language properly. Or even punctuate letters so their orders and requirements are clear. So - no template - but asuggestion that you keep at least 7 separate structures - the business, the employee their contractual usability, qualifications and benefits, the activities they do, the payments due, the payments made, the payroll & benefits declarations to the government, and the associated business costings. OK - they will all link into 1 actual composite, but keeping them separate makes their management - with modifications, general data input and reporting easier to manage as an IT facility. JimB -----Original Message----- From: AccessD On Behalf Of Bob Heygood Sent: Friday, April 27, 2018 4:21 PM To: 'Access Developers discussion and problem solving' Subject: [AccessD] Payroll Hello to the list, I am beginning design of a db to track payroll. The clients biz is such that even though I suggested a "canned" solution, they need a custom. But in order not to recreate the wheel I am looking for a template or a table relationship to jump start me. They use a two week pay period. Ideally they would choose an employee (already have a table), then a pay period (already have a table listing dates for two years) and then enter hours in 14 text boxes or maybe a list box ??? Tia Bob -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From jimdettman at verizon.net Mon Apr 30 13:49:20 2018 From: jimdettman at verizon.net (Jim Dettman) Date: Mon, 30 Apr 2018 14:49:20 -0400 Subject: [AccessD] Payroll In-Reply-To: <00fb01d3e0b1$5e365a90$1aa30fb0$@gmail.com> References: <0a3101d3de3b$47d9a900$d78cfb00$@gmail.com> <005b01d3e000$8a8b4080$9fa1c180$@gmail.com> <00fb01d3e0b1$5e365a90$1aa30fb0$@gmail.com> Message-ID: <03df01d3e0b3$f3b2b760$db182620$@verizon.net> << So, how do I use a table with only one record per day? UNBOUND, I guess. And then via code stuff into a "proper" table........>> That's one way certainly, but there's nothing stopping you from having one record per day. So you could give them a sub form pre-populated with two weeks' worth of blank time cards. Or you could even give them one time card record per two week period. Then there are UI features that you could supply to speed up data entry, such as "Auto Fill" (the two week period), "Copy last rec", so they could rapidly enter new time cards. Without a lot more info it would hard to say what would work best, but I would not drive the schema based on what they ask for in the UI. Just shooting yourself in the foot because changes will come sooner or later and no one likes to hear "it's a total re-write" Jim. -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Bob Heygood Sent: Monday, April 30, 2018 2:31 PM To: 'Access Developers discussion and problem solving' Subject: Re: [AccessD] Payroll Rocky & Jim, Yes I knew intuitively that I was breaking some normalization rules. Just started to let the UI interface drive the schema. For data entry the user insists on being able to "tab" through a whole pay period (2 weeks) for each employee and job. So, how do I use a table with only one record per day? UNBOUND, I guess. And then via code stuff into a "proper" table........ I have done so before but a lot work. Really don't need any other fields. Thanks for responding, Bob -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Rocky Smolin Sent: Sunday, April 29, 2018 4:36 PM To: 'Access Developers discussion and problem solving' Subject: Re: [AccessD] Payroll Bob: I think your timecard capture table should have one record for each day with FK of Empl ID: fldTimeCardID Autonumber fldEmplID Number (FK) fldDateWorked Date fldHours Number(Double) fldMultiplier Number (for straight time(1), time and 1/2(1.5), double time(2) Obviously an Employee table. And then a work period Start Date, End Date But for rate of pay since the rate changes you should have a RateofPay table: fldRateOfPayID Autonumber EmplID Number (FK) fldRateStarDate Date fldRateEndDate Date fldBaseRate Number (Double) It's a little more complicated that way but that way you could reconstruct their pay for any period in the past. But if all you want is hours without anything else then you don't need the pay rate data. But then why not just dump the timecards into a spreadsheet? What is Access doing for you? If you want to discuss, call me. Or come over and in short order we could design the back end to just what you want. R 760-683-5777 -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Bob Heygood Sent: Sunday, April 29, 2018 2:25 PM To: 'Access Developers discussion and problem solving' Subject: Re: [AccessD] Payroll Thanks for the responses. I should have been a bit more clear. I am only tracking the hours worked per day per payperiod. I will easily via a button dump into Excel for submission to the payroll processer. Like ADT. Bout settled on : tblEmployees tblJobs tblTimeCard containing.. EmpID, JobID, Payperiod, Monday1Hours, Tuesday1Hours.......... Monday1Hours15, Tuesday1Hours15,........ Monday1Hours2, Tuesday 1Hours2, ......... then for the second week: Monday2Hours, Tuesday2Hours...... Monday2Hours15, Tuesday2Hours15...... Monday2Hours2, Tuesday2Hours2 this allows for time, time and a half and double time. Also, makes for easy and familiar entry. tblEmployees contains pay rate info, so a little multiplication will give me totals for the resulting sheet/query. Tia Bob -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of James Button via AccessD Sent: Friday, April 27, 2018 10:36 AM To: 'Access Developers discussion and problem solving' Cc: James Button Subject: Re: [AccessD] Payroll Deadly assumption(s) Workers will only work 1 shift in a calendar day Workers shift will be entirely within a calendar day Pay will be at the standard rate(s) for all hours in a shift Bonuses will be subject to tax Benefits in kind - car, fuel, or taxi's, meals , healthcare - various categories and provision processes Benefits in kind - non taxable such as hydration drinks, uniforms and safety equipment Newly introduced local, or state taxes I would consider the input of hours being a daily thing with all employees (and contractors?, and agents?, and professional persons?) hours being entered by rote working down the employee list - That list being ordered by category, location and maybe grading so 1 person deals with input for management at a site and 1 person (maybe the same one) deals with the general pay-scale workers. Allow for - paid or not, hours holiday Sick leave, compassionate/extraordinary Education/courses Legally required Contractual Pay in lieu of hours Hours owed/carried forward Meetings required to attend - performance, disciplinary, associated with the employment All should be considered as entries for that person's 'employment' in a period - day The input should be appropriate for easy verification that there is no fraudulent input and submission to courts if required /ordered There maybe a legal decision that pay is (or is not) required for the time spent in such activities. Then - for the actual payment - as in assembly of time for which payment is due, That becomes the weekly, or other timing process Not forgetting the possibility of changes to the qualification and 'cash' related to any and all the above at any time in the payment period. Your payroll period is unlikely to match the legislative periods. Also maybe worth having an 'acceptable' max for each person (or job classification) for the payment period and for the quarter, and annually There should also be a very well managed process for implementing changes on specific dates (and times) with the effects being applied from specific dates & times - Local or other Consider employees abroad on behalf of the organisation Payroll is a real pain in the head (and elsewhere) and that is without getting retrospective adjustments from insurers, government departments, and the courts As well as evaluations by inspectors who cannot do basic arithmetic, speak the language properly. Or even punctuate letters so their orders and requirements are clear. So - no template - but asuggestion that you keep at least 7 separate structures - the business, the employee their contractual usability, qualifications and benefits, the activities they do, the payments due, the payments made, the payroll & benefits declarations to the government, and the associated business costings. OK - they will all link into 1 actual composite, but keeping them separate makes their management - with modifications, general data input and reporting easier to manage as an IT facility. JimB -----Original Message----- From: AccessD On Behalf Of Bob Heygood Sent: Friday, April 27, 2018 4:21 PM To: 'Access Developers discussion and problem solving' Subject: [AccessD] Payroll Hello to the list, I am beginning design of a db to track payroll. The clients biz is such that even though I suggested a "canned" solution, they need a custom. But in order not to recreate the wheel I am looking for a template or a table relationship to jump start me. They use a two week pay period. Ideally they would choose an employee (already have a table), then a pay period (already have a table listing dates for two years) and then enter hours in 14 text boxes or maybe a list box ??? Tia Bob -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From rockysmolin at bchacc.com Mon Apr 30 13:57:07 2018 From: rockysmolin at bchacc.com (Rocky Smolin) Date: Mon, 30 Apr 2018 11:57:07 -0700 Subject: [AccessD] Payroll In-Reply-To: <00fb01d3e0b1$5e365a90$1aa30fb0$@gmail.com> References: <0a3101d3de3b$47d9a900$d78cfb00$@gmail.com> <005b01d3e000$8a8b4080$9fa1c180$@gmail.com> <00fb01d3e0b1$5e365a90$1aa30fb0$@gmail.com> Message-ID: <004501d3e0b5$09ebd830$1dc38890$@bchacc.com> You make the data entry form bound to the hours table and let them enter a date range to display. If the date range exceeds that last date in the hours table for that employee, create the empty records and then display. They can then tab from one entry to the next. Instead of tabbing across they would be tabbing down. But same approach to tabbing. If you want to discuss further call me. Rocky Smolin Beach Access Software 760-683-5777 www.bchacc.com www.e-z-mrp.com Skype: rocky.smolin -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Bob Heygood Sent: Monday, April 30, 2018 11:31 AM To: 'Access Developers discussion and problem solving' Subject: Re: [AccessD] Payroll Rocky & Jim, Yes I knew intuitively that I was breaking some normalization rules. Just started to let the UI interface drive the schema. For data entry the user insists on being able to "tab" through a whole pay period (2 weeks) for each employee and job. So, how do I use a table with only one record per day? UNBOUND, I guess. And then via code stuff into a "proper" table........ I have done so before but a lot work. Really don't need any other fields. Thanks for responding, Bob -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Rocky Smolin Sent: Sunday, April 29, 2018 4:36 PM To: 'Access Developers discussion and problem solving' Subject: Re: [AccessD] Payroll Bob: I think your timecard capture table should have one record for each day with FK of Empl ID: fldTimeCardID Autonumber fldEmplID Number (FK) fldDateWorked Date fldHours Number(Double) fldMultiplier Number (for straight time(1), time and 1/2(1.5), double time(2) Obviously an Employee table. And then a work period Start Date, End Date But for rate of pay since the rate changes you should have a RateofPay table: fldRateOfPayID Autonumber EmplID Number (FK) fldRateStarDate Date fldRateEndDate Date fldBaseRate Number (Double) It's a little more complicated that way but that way you could reconstruct their pay for any period in the past. But if all you want is hours without anything else then you don't need the pay rate data. But then why not just dump the timecards into a spreadsheet? What is Access doing for you? If you want to discuss, call me. Or come over and in short order we could design the back end to just what you want. R 760-683-5777 -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Bob Heygood Sent: Sunday, April 29, 2018 2:25 PM To: 'Access Developers discussion and problem solving' Subject: Re: [AccessD] Payroll Thanks for the responses. I should have been a bit more clear. I am only tracking the hours worked per day per payperiod. I will easily via a button dump into Excel for submission to the payroll processer. Like ADT. Bout settled on : tblEmployees tblJobs tblTimeCard containing.. EmpID, JobID, Payperiod, Monday1Hours, Tuesday1Hours.......... Monday1Hours15, Tuesday1Hours15,........ Monday1Hours2, Tuesday 1Hours2, ......... then for the second week: Monday2Hours, Tuesday2Hours...... Monday2Hours15, Tuesday2Hours15...... Monday2Hours2, Tuesday2Hours2 this allows for time, time and a half and double time. Also, makes for easy and familiar entry. tblEmployees contains pay rate info, so a little multiplication will give me totals for the resulting sheet/query. Tia Bob -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of James Button via AccessD Sent: Friday, April 27, 2018 10:36 AM To: 'Access Developers discussion and problem solving' Cc: James Button Subject: Re: [AccessD] Payroll Deadly assumption(s) Workers will only work 1 shift in a calendar day Workers shift will be entirely within a calendar day Pay will be at the standard rate(s) for all hours in a shift Bonuses will be subject to tax Benefits in kind - car, fuel, or taxi's, meals , healthcare - various categories and provision processes Benefits in kind - non taxable such as hydration drinks, uniforms and safety equipment Newly introduced local, or state taxes I would consider the input of hours being a daily thing with all employees (and contractors?, and agents?, and professional persons?) hours being entered by rote working down the employee list - That list being ordered by category, location and maybe grading so 1 person deals with input for management at a site and 1 person (maybe the same one) deals with the general pay-scale workers. Allow for - paid or not, hours holiday Sick leave, compassionate/extraordinary Education/courses Legally required Contractual Pay in lieu of hours Hours owed/carried forward Meetings required to attend - performance, disciplinary, associated with the employment All should be considered as entries for that person's 'employment' in a period - day The input should be appropriate for easy verification that there is no fraudulent input and submission to courts if required /ordered There maybe a legal decision that pay is (or is not) required for the time spent in such activities. Then - for the actual payment - as in assembly of time for which payment is due, That becomes the weekly, or other timing process Not forgetting the possibility of changes to the qualification and 'cash' related to any and all the above at any time in the payment period. Your payroll period is unlikely to match the legislative periods. Also maybe worth having an 'acceptable' max for each person (or job classification) for the payment period and for the quarter, and annually There should also be a very well managed process for implementing changes on specific dates (and times) with the effects being applied from specific dates & times - Local or other Consider employees abroad on behalf of the organisation Payroll is a real pain in the head (and elsewhere) and that is without getting retrospective adjustments from insurers, government departments, and the courts As well as evaluations by inspectors who cannot do basic arithmetic, speak the language properly. Or even punctuate letters so their orders and requirements are clear. So - no template - but asuggestion that you keep at least 7 separate structures - the business, the employee their contractual usability, qualifications and benefits, the activities they do, the payments due, the payments made, the payroll & benefits declarations to the government, and the associated business costings. OK - they will all link into 1 actual composite, but keeping them separate makes their management - with modifications, general data input and reporting easier to manage as an IT facility. JimB -----Original Message----- From: AccessD On Behalf Of Bob Heygood Sent: Friday, April 27, 2018 4:21 PM To: 'Access Developers discussion and problem solving' Subject: [AccessD] Payroll Hello to the list, I am beginning design of a db to track payroll. The clients biz is such that even though I suggested a "canned" solution, they need a custom. But in order not to recreate the wheel I am looking for a template or a table relationship to jump start me. They use a two week pay period. Ideally they would choose an employee (already have a table), then a pay period (already have a table listing dates for two years) and then enter hours in 14 text boxes or maybe a list box ??? Tia Bob -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com -- AccessD mailing list AccessD at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/accessd Website: http://www.databaseadvisors.com From jamesbutton at blueyonder.co.uk Mon Apr 30 14:44:02 2018 From: jamesbutton at blueyonder.co.uk (James Button) Date: Mon, 30 Apr 2018 20:44:02 +0100 Subject: [AccessD] Payroll In-Reply-To: <004501d3e0b5$09ebd830$1dc38890$@bchacc.com> References: <0a3101d3de3b$47d9a900$d78cfb00$@gmail.com> <005b01d3e000$8a8b4080$9fa1c180$@gmail.com> <00fb01d3e0b1$5e365a90$1aa30fb0$@gmail.com> <004501d3e0b5$09ebd830$1dc38890$@bchacc.com> Message-ID: >From (painful) experience - Yes - you can do what the client (boss?) declares is to be done. Or You can do what will allow flexibility in the process Either way you should detail what the process is required to do, and what the design will not allow to be addressed. That document should be accepted by, and signed off by those responsible for the implementation of the process, those who will have to enter the data into the system, and those who will have to use the data from the system. Your job will then be to design a data structure and process to meet the requirements of all groups. So - considering what had been detailed No person is allowed to leave work and then return during the same day No person is allowed to continue working through midnight So - that is a total inability coded within the system for someone to go to the doctors, to hospital, to the police station, on an unpaid basis, and then return to complete their shift If you only have the 1 period enterable, then there is no possibility of enhanced payment for an extended day Definitely - you are going to need to have gotten (and secured) a set of signatures for the design of the user interface! The documentation will certainly be needed for UAT and may later maintenance processing (after you move on to a new environment). Normalisation is a good idea and should be applied within the data store Views are a means of presenting composite data to a facility/app/user report And while Normalisation need not be applied at all times, the data should ALWAYS be easy to present in a normalised manner for other processing. As in - yes UI should present payroll number, Earning period (which is not the payroll period) and the period worked It is also prudent to include other data such as the employees name, work location, supervisor/manager time recorder id, from other tables You will need to consider the process that will be needed to take the data from the presented single start and end time for each of 14 days into a normalised form for the payment calculator That follow on process will (I would expect) be processing a payment at a set rate for a single specification of the number of hours worked. JimB -----Original Message----- From: AccessD On Behalf Of Rocky Smolin Sent: Monday, April 30, 2018 7:57 PM To: 'Access Developers discussion and problem solving' Subject: Re: [AccessD] Payroll You make the data entry form bound to the hours table and let them enter a date range to display. If the date range exceeds that last date in the hours table for that employee, create the empty records and then display. They can then tab from one entry to the next. Instead of tabbing across they would be tabbing down. But same approach to tabbing. If you want to discuss further call me. Rocky Smolin Beach Access Software 760-683-5777 www.bchacc.com www.e-z-mrp.com Skype: rocky.smolin -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Bob Heygood Sent: Monday, April 30, 2018 11:31 AM To: 'Access Developers discussion and problem solving' Subject: Re: [AccessD] Payroll Rocky & Jim, Yes I knew intuitively that I was breaking some normalization rules. Just started to let the UI interface drive the schema. For data entry the user insists on being able to "tab" through a whole pay period (2 weeks) for each employee and job. So, how do I use a table with only one record per day? UNBOUND, I guess. And then via code stuff into a "proper" table........ I have done so before but a lot work. Really don't need any other fields. Thanks for responding, Bob -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Rocky Smolin Sent: Sunday, April 29, 2018 4:36 PM To: 'Access Developers discussion and problem solving' Subject: Re: [AccessD] Payroll Bob: I think your timecard capture table should have one record for each day with FK of Empl ID: fldTimeCardID Autonumber fldEmplID Number (FK) fldDateWorked Date fldHours Number(Double) fldMultiplier Number (for straight time(1), time and 1/2(1.5), double time(2) Obviously an Employee table. And then a work period Start Date, End Date But for rate of pay since the rate changes you should have a RateofPay table: fldRateOfPayID Autonumber EmplID Number (FK) fldRateStarDate Date fldRateEndDate Date fldBaseRate Number (Double) It's a little more complicated that way but that way you could reconstruct their pay for any period in the past. But if all you want is hours without anything else then you don't need the pay rate data. But then why not just dump the timecards into a spreadsheet? What is Access doing for you? If you want to discuss, call me. Or come over and in short order we could design the back end to just what you want. R 760-683-5777 -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of Bob Heygood Sent: Sunday, April 29, 2018 2:25 PM To: 'Access Developers discussion and problem solving' Subject: Re: [AccessD] Payroll Thanks for the responses. I should have been a bit more clear. I am only tracking the hours worked per day per payperiod. I will easily via a button dump into Excel for submission to the payroll processer. Like ADT. Bout settled on : tblEmployees tblJobs tblTimeCard containing.. EmpID, JobID, Payperiod, Monday1Hours, Tuesday1Hours.......... Monday1Hours15, Tuesday1Hours15,........ Monday1Hours2, Tuesday 1Hours2, ......... then for the second week: Monday2Hours, Tuesday2Hours...... Monday2Hours15, Tuesday2Hours15...... Monday2Hours2, Tuesday2Hours2 this allows for time, time and a half and double time. Also, makes for easy and familiar entry. tblEmployees contains pay rate info, so a little multiplication will give me totals for the resulting sheet/query. Tia Bob -----Original Message----- From: AccessD [mailto:accessd-bounces at databaseadvisors.com] On Behalf Of James Button via AccessD Sent: Friday, April 27, 2018 10:36 AM To: 'Access Developers discussion and problem solving' Cc: James Button Subject: Re: [AccessD] Payroll Deadly assumption(s) Workers will only work 1 shift in a calendar day Workers shift will be entirely within a calendar day Pay will be at the standard rate(s) for all hours in a shift Bonuses will be subject to tax Benefits in kind - car, fuel, or taxi's, meals , healthcare - various categories and provision processes Benefits in kind - non taxable such as hydration drinks, uniforms and safety equipment Newly introduced local, or state taxes I would consider the input of hours being a daily thing with all employees (and contractors?, and agents?, and professional persons?) hours being entered by rote working down the employee list - That list being ordered by category, location and maybe grading so 1 person deals with input for management at a site and 1 person (maybe the same one) deals with the general pay-scale workers. Allow for - paid or not, hours holiday Sick leave, compassionate/extraordinary Education/courses Legally required Contractual Pay in lieu of hours Hours owed/carried forward Meetings required to attend - performance, disciplinary, associated with the employment All should be considered as entries for that person's 'employment' in a period - day The input should be appropriate for easy verification that there is no fraudulent input and submission to courts if required /ordered There maybe a legal decision that pay is (or is not) required for the time spent in such activities. Then - for the actual payment - as in assembly of time for which payment is due, That becomes the weekly, or other timing process Not forgetting the possibility of changes to the qualification and 'cash' related to any and all the above at any time in the payment period. Your payroll period is unlikely to match the legislative periods. Also maybe worth having an 'acceptable' max for each person (or job classification) for the payment period and for the quarter, and annually There should also be a very well managed process for implementing changes on specific dates (and times) with the effects being applied from specific dates & times - Local or other Consider employees abroad on behalf of the organisation Payroll is a real pain in the head (and elsewhere) and that is without getting retrospective adjustments from insurers, government departments, and the courts As well as evaluations by inspectors who cannot do basic arithmetic, speak the language properly. Or even punctuate letters so their orders and requirements are clear. So - no template - but asuggestion that you keep at least 7 separate structures - the business, the employee their contractual usability, qualifications and benefits, the activities they do, the payments due, the payments made, the payroll & benefits declarations to the government, and the associated business costings. OK - they will all link into 1 actual composite, but keeping them separate makes their management - with modifications, general data input and reporting easier to manage as an IT facility. JimB -----Original Message----- From: AccessD On Behalf Of Bob Heygood Sent: Friday, April 27, 2018 4:21 PM To: 'Access Developers discussion and problem solving' Subject: [AccessD] Payroll Hello to the list, I am beginning design of a db to track payroll. The clients biz is such that even though I suggested a "canned" solution, they need a custom. But in order not to recreate the wheel I am looking for a template or a table relationship to jump start me. They use a two week pay period. Ideally they would choose an employee (already have a table), then a pay period (already have a table listing dates for two years) and then enter hours in 14 text boxes or maybe a list box ??? Tia Bob From stuart at lexacorp.com.pg Mon Apr 30 16:54:27 2018 From: stuart at lexacorp.com.pg (Stuart McLachlan) Date: Tue, 01 May 2018 07:54:27 +1000 Subject: [AccessD] Payroll In-Reply-To: <00fb01d3e0b1$5e365a90$1aa30fb0$@gmail.com> References: <0a3101d3de3b$47d9a900$d78cfb00$@gmail.com>, , <00fb01d3e0b1$5e365a90$1aa30fb0$@gmail.com> Message-ID: <5AE79093.3657.4BEA278B@stuart.lexacorp.com.pg> At times, there are valid reasons for NOT normalising or for re-thinking what you actual mean by nromalisation. This is one of them. Think in terms of a TYPE or Object called a "PayPeriod" rather than "Day" and D1Hours to D14Hours become separate attributes, not separate entities. :) I've built systems exactly like this in the past and in fact I'm doing another one right now. I doubt that there will ever be a fortnight with more or less days. :) If they decide to change to a different pay period, (weekly or monthly?) how you store daily attendance hours will be the least of your worries. On 30 Apr 2018 at 11:30, Bob Heygood wrote: > Rocky & Jim, > Yes I knew intuitively that I was breaking some normalization rules. > Just started to let the UI interface drive the schema. > > For data entry the user insists on being able to "tab" through a whole > pay period (2 weeks) for each employee and job. > > So, how do I use a table with only one record per day? > UNBOUND, I guess. And then via code stuff into a "proper" > table........ I have done so before but a lot work. > > Really don't need any other fields. > > Thanks for responding, > > Bob > > >