December 31, 2007 at 4:35 am
Experts,
TableName - MastBCP
Code NewCode FlatAcct
MSC MSC001 4000700DIVD+1|4000710DIVD-1
MSC MSC002 5000700DIVD+1|5000710DIVD-1
MSC MSC003 6000700 -1|6000710DIVD-1|6000720DIVD+1
Above one is the master table.
Below one is the transaction table.It receives data on daily basis.
TableName - AcctTrans
ProjectId Code AcctNbr SubAcctNbr SubAcctCode DrCrInd
200100 MSC 4000 700 DIVD Dr
200100 MSC 4000 710 DIVD Cr
200200 MSC 4000 700 DIVD Dr
200200 MSC 4000 710 DIVD Dr
200200 MSC 4000 720 DIVD Cr
200300 MSC 5000 700 DIVD Dr
200300 MSC 5000 710 DIVD Cr
200400 MSC 6000 700 Cr
200400 MSC 6000 710 Cr
200400 MSC 6000 720 DIVD Dr
Now i want to match the above rows with master table FlatAcct column.If it matches then i have to update NewCode column(I added a new column in AcctTrans table using Alter table statement) of AcctTrans table.
Say for example, if we take the rows of projectId 200100 it matches against MSC001(MastBCP table).But the format is entirely different in both the table.
Inputs are higly appreciable!
karthik
January 2, 2008 at 10:24 am
Ok I made some assumptions on the format of your accounts but here is at least one solution. Its worked well for me in the past but I would test it on your own data.
Create MastBCP
CREATE TABLE MastBCP (
code varchar(50),
newcode varchar(50),
flatacct varchar(50)
)
CREATE INDEX idx ON MASTBCP(FlatAcct)
INSERT INTO MastBCP VALUES ('MSC','MSC001','4000700DIVD+1|4000710DIVD-1')
INSERT INTO MastBCP VALUES ('MSC','MSC002','5000700DIVD+1|5000710DIVD-1')
INSERT INTO MastBCP VALUES ('MSC','MSC003','6000700 -1|6000710DIVD-1|6000720DIVD+1')
CREATE AcctTrans
CREATE TABLE AcctTrans
(ProjectId varchar(50),
Code varchar(50),
AcctNbr varchar(50),
SubAcctNbr varchar(50),
SubAcctCode varchar(50),
DrCrInd varchar(50) )
CREATE INDEX idx2 ON AcctTrans(AcctNbr, SubAcctNbr, SubAcctCode)
INSERT INTO AcctTrans VALUES ('200100','MSC','4000','700','DIVD','Dr')
INSERT INTO AcctTrans VALUES ('200100','MSC','4000','710','DIVD','Cr')
INSERT INTO AcctTrans VALUES ('200200','MSC','4000','700','DIVD','Dr')
INSERT INTO AcctTrans VALUES ('200200','MSC','4000','710','DIVD','Dr')
INSERT INTO AcctTrans VALUES ('200200','MSC','4000','720','DIVD','Cr')
INSERT INTO AcctTrans VALUES ('200300','MSC','5000','700','DIVD','Dr')
INSERT INTO AcctTrans VALUES ('200300','MSC','5000','710','DIVD','Cr')
INSERT INTO AcctTrans VALUES ('200400','MSC','6000','700',' ','Cr')
INSERT INTO AcctTrans VALUES ('200400','MSC','6000','710',' ','Cr')
INSERT INTO AcctTrans VALUES ('200400','MSC','6000','720','DIVD','Dr')
Actual Query
SELECT *
FROM MastBCP
FULL JOIN AcctTrans AT ON
'|'+MastBCP.FlatAcct+'|' LIKE '%|'+AT.AcctNbr+AT.SubAcctNbr+AT.SubAcctCode+'[+-]1|%'
Kenneth FisherI was once offered a wizards hat but it got in the way of my dunce cap.--------------------------------------------------------------------------------For better, quicker answers on T-SQL questions, click on the following... http://www.sqlservercentral.com/articles/Best+Practices/61537/[/url]For better answers on performance questions, click on the following... http://www.sqlservercentral.com/articles/SQLServerCentral/66909/[/url]Link to my Blog Post --> www.SQLStudies.com[/url]
January 3, 2008 at 12:09 am
Inputs are higly appreciable!
Ok... then study the article at the following URL before you post like this again...
http://www.sqlservercentral.com/articles/Best+Practices/61537/
... then, do what it says 😉
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 3 posts - 1 through 2 (of 2 total)
You must be logged in to reply to this topic. Login to reply