SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


INSERT multi-table foreign keys from XML


INSERT multi-table foreign keys from XML

Author
Message
Carlo Clausius
Carlo Clausius
Valued Member
Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)

Group: General Forum Members
Points: 61 Visits: 234
Hi

I trying to build a SP in which I'm inserting foreign key values into a table from XML as follows.
DECLARE @xmlInsertRecordString XML

SET @xmlInsertRecordString = '<AllForcast>
<SESA>SESA99999</SESA>
<EmployeeName>Alex Bea</EmployeeName>
<HiringStatus>Full Time</HiringStatus>
<EmployeeGroup>HW</EmployeeGroup>
<EmployeeSub-Group>HW</EmployeeSub-Group>
<City>Burnaby</City>
<ProjectStatus>Active</ProjectStatus>
<ProjectName>AB-1</ProjectName>
<ProjectCode>411</ProjectCode>
<ProjectManager>John Doe</ProjectManager>
<Notes></Notes>
<Date>Jan 1 2016</Date>
<Effort>1</Effort>
<RecordBy>SESA123456</RecordBy>
<RecordID>4</RecordID>
</AllForcast>'

INSERT INTO dbo.TBL_ALL_FORC_TEST (fk_sub_group, fk_employee, fk_project)
SELECT ID FROM dbo.TBL_EMPLOYEE_SUB_GROUP_LU WHERE [sub_group] = (SELECT a.a.value('.', 'VARCHAR(255)') AS GroupID FROM @xmlInsertRecordString.nodes('/AllForcast/EmployeeSub-Group') AS a(a))),
SELECT ID FROM dbo.TBL_MAIN_EMPLOYEE WHERE sesa_id = (SELECT a.a.value('.', 'VARCHAR(256)') AS EmplyID FROM @xmlInsertRecordString.nodes('/AllForcast/SESA') AS a(a)),
SELECT ID FROM dbo.TBL_MAIN_PROJECTS WHERE project_code = (SELECT a.a.value('.', 'VARCHAR(256)') AS ProjID FROM @xmlInsertRecordString.nodes('/AllForcast/ProjectCode') AS a(a))



I can get one insert in for a column this way but not multiples as exampled.

Thoughts?

Thanks
Evil Kraig F
Evil Kraig F
SSCrazy Eights
SSCrazy Eights (8.7K reputation)SSCrazy Eights (8.7K reputation)SSCrazy Eights (8.7K reputation)SSCrazy Eights (8.7K reputation)SSCrazy Eights (8.7K reputation)SSCrazy Eights (8.7K reputation)SSCrazy Eights (8.7K reputation)SSCrazy Eights (8.7K reputation)

Group: General Forum Members
Points: 8651 Visits: 7660
I'm not sure I'm clear on your objective. Are you simply trying to get your three columns into a single select into the same table, or have I horribly misunderstood what you're asking?


- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
Carlo Clausius
Carlo Clausius
Valued Member
Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)

Group: General Forum Members
Points: 61 Visits: 234
I'm not sure I'm clear on your objective. Are you simply trying to get your three columns into a single select into the same table, or have I horribly misunderstood what you're asking?


Yes. Right now I'm declaring three variables, assigning the value to the variables one by one, then doing the insert into the table using the three variables...tedious and I'm getting finger fatigue.Crazy
Evil Kraig F
Evil Kraig F
SSCrazy Eights
SSCrazy Eights (8.7K reputation)SSCrazy Eights (8.7K reputation)SSCrazy Eights (8.7K reputation)SSCrazy Eights (8.7K reputation)SSCrazy Eights (8.7K reputation)SSCrazy Eights (8.7K reputation)SSCrazy Eights (8.7K reputation)SSCrazy Eights (8.7K reputation)

Group: General Forum Members
Points: 8651 Visits: 7660
Try the following, then just join normally:


DECLARE @xmlInsertRecordString XML
DECLARE @iDoc INT

SET @xmlInsertRecordString = '<AllForcast>
<SESA>SESA99999</SESA>
<EmployeeName>Alex Bea</EmployeeName>
<HiringStatus>Full Time</HiringStatus>
<EmployeeGroup>HW</EmployeeGroup>
<EmployeeSub-Group>HW</EmployeeSub-Group>
<City>Burnaby</City>
<ProjectStatus>Active</ProjectStatus>
<ProjectName>AB-1</ProjectName>
<ProjectCode>411</ProjectCode>
<ProjectManager>John Doe</ProjectManager>
<Notes></Notes>
<Date>Jan 1 2016</Date>
<Effort>1</Effort>
<RecordBy>SESA123456</RecordBy>
<RecordID>4</RecordID>
</AllForcast>'


EXEC sp_xml_preparedocument @iDoc OUTPUT, @xmlInsertRecordString

SELECT
*
FROM
OPENXML( @iDoc, '//AllForcast')
WITH (EmpSubGroup VARCHAR( 50) 'EmployeeSub-Group',
SESA VARCHAR(50) 'SESA',
ProjectCode VARCHAR(50) 'ProjectCode'
) AS ox

EXEC sp_xml_removedocument @iDoc




- Craig Farrell

Never stop learning, even if it hurts. Ego bruises are practically mandatory as you learn unless you've never risked enough to make a mistake.

For better assistance in answering your questions | Forum Netiquette
For index/tuning help, follow these directions. |Tally Tables

Twitter: @AnyWayDBA
Carlo Clausius
Carlo Clausius
Valued Member
Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)Valued Member (61 reputation)

Group: General Forum Members
Points: 61 Visits: 234
Nice!!

Thank you.
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search