Try this
SELECT '001' AS "area",
(SELECT 'admin@company.com' AS "notify",
(SELECT 'TELRCM' AS "field/@table", 'COMPANY' AS "field/@field", Company AS "field", null,
'TELRCM' AS "field/@table", 'POSTCODE' AS "field/@field", postcode AS "field", null,
'TELRCM' AS "field/@table", 'TELEPHONE' AS "field/@field", telephone AS "field", null,
'TELRCM' AS "field/@table", 'CUSTOMERSTATUS' AS "field/@field", customerstatus AS "field", null,
'TELRCM' AS "field/@table", 'OWNER' AS "field/@field", owner AS "field", null,
'RCMANL' AS "field/@table", 'ANAL01' AS "field/@field", anal01 AS "field"
FOR XML PATH('account'),TYPE),
(SELECT 'CONT' AS "field/@table", 'CONTACT' AS "field/@field", contact1 AS "field", null,
'CONT' AS "field/@table", 'EMAIL' AS "field/@field", email1 AS "field", null
FOR XML PATH('contact'),TYPE),
(SELECT 'CONT' AS "field/@table", 'CONTACT' AS "field/@field", contact2 AS "field", null,
'CONT' AS "field/@table", 'EMAIL' AS "field/@field", email2 AS "field", null
FOR XML PATH('contact'),TYPE),
(SELECT 'CONT' AS "field/@table", 'CONTACT' AS "field/@field", contact3 AS "field", null,
'CONT' AS "field/@table", 'EMAIL' AS "field/@field", email3 AS "field", null
FOR XML PATH('contact'),TYPE)
FROM #testxmldata
FOR XML PATH('data'),TYPE)
FOR XML PATH('importdata'),TYPE;
____________________________________________________
Deja View - The strange feeling that somewhere, sometime you've optimised this query before
How to get the best help on a forum
http://www.sqlservercentral.com/articles/Best+Practices/61537Fantastic! Does exactly as needed.
Thanks very much!
If I needed to drop the notify from XML how would I achieve this?
bicky1980 - Friday, February 8, 2019 3:19 AM
Remove the part of the SQL that states "'admin@company.com' AS "notify",".
Your reply has the sound of that you don't understand how the answer that Mark has posted works. Do you? If not, it's important you take the time to understand it or ask questions about it. The person that needs to support the code above is you, not Mark, nor I, nor anyone else at the SSC community.
If you don't understand how some parts of the SQL don't work, which part(s) is it? We can help you understand then. You could also take some time to have a read of the documentation on FOR XML, which might fill in some onf the blanks.
Thom~
Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does.
Larnu.uk
This should do it
SELECT '001' AS "area",
(SELECT --'admin@company.com' AS "notify",
(SELECT 'TELRCM' AS "field/@table", 'COMPANY' AS "field/@field", Company AS "field", null,
'TELRCM' AS "field/@table", 'POSTCODE' AS "field/@field", postcode AS "field", null,
'TELRCM' AS "field/@table", 'TELEPHONE' AS "field/@field", telephone AS "field", null,
'TELRCM' AS "field/@table", 'CUSTOMERSTATUS' AS "field/@field", customerstatus AS "field", null,
'TELRCM' AS "field/@table", 'OWNER' AS "field/@field", owner AS "field", null,
'RCMANL' AS "field/@table", 'ANAL01' AS "field/@field", anal01 AS "field"
FOR XML PATH('account'),TYPE),
(SELECT 'CONT' AS "field/@table", 'CONTACT' AS "field/@field", contact1 AS "field", null,
'CONT' AS "field/@table", 'EMAIL' AS "field/@field", email1 AS "field", null
FOR XML PATH('contact'),TYPE),
(SELECT 'CONT' AS "field/@table", 'CONTACT' AS "field/@field", contact2 AS "field", null,
'CONT' AS "field/@table", 'EMAIL' AS "field/@field", email2 AS "field", null
FOR XML PATH('contact'),TYPE),
(SELECT 'CONT' AS "field/@table", 'CONTACT' AS "field/@field", contact3 AS "field", null,
'CONT' AS "field/@table", 'EMAIL' AS "field/@field", email3 AS "field", null
FOR XML PATH('contact'),TYPE)
FROM #testxmldata
FOR XML PATH('data'),TYPE)
FOR XML PATH('importdata'),TYPE;
____________________________________________________
Deja View - The strange feeling that somewhere, sometime you've optimised this query before
How to get the best help on a forum
http://www.sqlservercentral.com/articles/Best+Practices/61537Thom A - Friday, February 8, 2019 5:23 AM
I did try that Thorn to no avail. And I have looked through the documentation, which I obviously don't really understand hence my question here. But thanks for your advice...
Edit: Looking back at what I did try I also removed the Select directly before this, so that is why it didn't work for me.
Mark Cowne - Friday, February 8, 2019 5:27 AM
Thanks for this again Mark. Sorted the issue. I will be looking at the query as advised by Thorn and making sure I understand how it works. Thanks again
Viewing 8 posts - 1 through 8 (of 8 total)
You must be logged in to reply to this topic. Login to reply